Merge branch 'feature/member-time-progress-and-utilization' of https://github.com/Worklenz/worklenz into feature/recurring-tasks
This commit is contained in:
39
docs/recurring-tasks-user-guide.md
Normal file
39
docs/recurring-tasks-user-guide.md
Normal file
@@ -0,0 +1,39 @@
|
||||
# Recurring Tasks: User Guide
|
||||
|
||||
## What Are Recurring Tasks?
|
||||
Recurring tasks are tasks that repeat automatically on a schedule you choose. This helps you save time and ensures important work is never forgotten. For example, you can set up a recurring task for weekly team meetings, monthly reports, or daily check-ins.
|
||||
|
||||
## Why Use Recurring Tasks?
|
||||
- **Save time:** No need to create the same task over and over.
|
||||
- **Stay organized:** Tasks appear automatically when needed.
|
||||
- **Never miss a deadline:** Tasks are created on time, every time.
|
||||
|
||||
## How to Set Up a Recurring Task
|
||||
1. Go to the tasks section in your workspace.
|
||||
2. Choose to create a new task and look for the option to make it recurring.
|
||||
3. Fill in the task details (name, description, assignees, etc.).
|
||||
4. Select your preferred schedule (see options below).
|
||||
5. Save the task. It will now be created automatically based on your chosen schedule.
|
||||
|
||||
## Schedule Options
|
||||
You can choose how often your task repeats. Here are the most common options:
|
||||
|
||||
- **Daily:** The task is created every day.
|
||||
- **Weekly:** The task is created once a week. You can pick the day (e.g., every Monday).
|
||||
- **Monthly:** The task is created once a month. You can pick the date (e.g., the 1st of every month).
|
||||
- **Weekdays:** The task is created every Monday to Friday.
|
||||
- **Custom:** Set your own schedule, such as every 2 days, every 3 weeks, or only on certain days.
|
||||
|
||||
### Examples
|
||||
- "Send team update" every Friday (weekly)
|
||||
- "Submit expense report" on the 1st of each month (monthly)
|
||||
- "Check backups" every day (daily)
|
||||
- "Review project status" every Monday and Thursday (custom)
|
||||
|
||||
## Tips
|
||||
- You can edit or stop a recurring task at any time.
|
||||
- Assign team members and labels to recurring tasks for better organization.
|
||||
- Check your task list regularly to see newly created recurring tasks.
|
||||
|
||||
## Need Help?
|
||||
If you have questions or need help setting up recurring tasks, contact your workspace admin or support team.
|
||||
56
docs/recurring-tasks.md
Normal file
56
docs/recurring-tasks.md
Normal file
@@ -0,0 +1,56 @@
|
||||
# Recurring Tasks Cron Job Documentation
|
||||
|
||||
## Overview
|
||||
The recurring tasks cron job automates the creation of tasks based on predefined templates and schedules. It ensures that tasks are generated at the correct intervals without manual intervention, supporting efficient project management and timely task assignment.
|
||||
|
||||
## Purpose
|
||||
- Automatically create tasks according to recurring schedules defined in the database.
|
||||
- Prevent duplicate task creation for the same schedule and date.
|
||||
- Assign team members and labels to newly created tasks as specified in the template.
|
||||
|
||||
## Scheduling Logic
|
||||
- The cron job is scheduled using the [cron](https://www.npmjs.com/package/cron) package.
|
||||
- The schedule is defined by a cron expression (e.g., `*/2 * * * *` for every 2 minutes, or `0 11 */1 * 1-5` for 11:00 UTC on weekdays).
|
||||
- On each tick, the job:
|
||||
1. Fetches all recurring task templates and their schedules.
|
||||
2. Determines the next occurrence for each template using `calculateNextEndDate`.
|
||||
3. Checks if a task for the next occurrence already exists.
|
||||
4. Creates a new task if it does not exist and the next occurrence is within the allowed future window.
|
||||
|
||||
## Database Interactions
|
||||
- **Templates and Schedules:**
|
||||
- Templates are stored in `task_recurring_templates`.
|
||||
- Schedules are stored in `task_recurring_schedules`.
|
||||
- The job joins these tables to get all necessary data for task creation.
|
||||
- **Task Creation:**
|
||||
- Uses a stored procedure `create_quick_task` to insert new tasks.
|
||||
- Assigns team members and labels by calling appropriate functions/controllers.
|
||||
- **State Tracking:**
|
||||
- Updates `last_checked_at` and `last_created_task_end_date` in the schedule after processing.
|
||||
|
||||
## Task Creation Process
|
||||
1. **Fetch Templates:** Retrieve all templates and their associated schedules.
|
||||
2. **Determine Next Occurrence:** Use the last task's end date or the schedule's creation date to calculate the next due date.
|
||||
3. **Check for Existing Task:** Ensure no duplicate task is created for the same schedule and date.
|
||||
4. **Create Task:**
|
||||
- Insert the new task using the template's data.
|
||||
- Assign team members and labels as specified.
|
||||
5. **Update Schedule:** Record the last checked and created dates for accurate future runs.
|
||||
|
||||
## Configuration & Extension Points
|
||||
- **Cron Expression:** Modify the `TIME` constant in the code to change the schedule.
|
||||
- **Task Template Structure:** Extend the template or schedule interfaces to support additional fields.
|
||||
- **Task Creation Logic:** Customize the task creation process or add new assignment/labeling logic as needed.
|
||||
|
||||
## Error Handling
|
||||
- Errors are logged using the `log_error` utility.
|
||||
- The job continues processing other templates even if one fails.
|
||||
|
||||
## References
|
||||
- Source: `src/cron_jobs/recurring-tasks.ts`
|
||||
- Utilities: `src/shared/utils.ts`
|
||||
- Database: `src/config/db.ts`
|
||||
- Controllers: `src/controllers/tasks-controller.ts`
|
||||
|
||||
---
|
||||
For further customization or troubleshooting, refer to the source code and update the documentation as needed.
|
||||
@@ -0,0 +1,160 @@
|
||||
-- Migration: Fix progress_mode_type ENUM and casting issues
|
||||
-- Date: 2025-04-27
|
||||
-- Version: 1.0.0
|
||||
|
||||
BEGIN;
|
||||
|
||||
-- First, let's ensure the ENUM type exists with the correct values
|
||||
DO $$
|
||||
BEGIN
|
||||
-- Check if the type exists
|
||||
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'progress_mode_type') THEN
|
||||
CREATE TYPE progress_mode_type AS ENUM ('manual', 'weighted', 'time', 'default');
|
||||
ELSE
|
||||
-- Add any missing values to the existing ENUM
|
||||
BEGIN
|
||||
ALTER TYPE progress_mode_type ADD VALUE IF NOT EXISTS 'manual';
|
||||
ALTER TYPE progress_mode_type ADD VALUE IF NOT EXISTS 'weighted';
|
||||
ALTER TYPE progress_mode_type ADD VALUE IF NOT EXISTS 'time';
|
||||
ALTER TYPE progress_mode_type ADD VALUE IF NOT EXISTS 'default';
|
||||
EXCEPTION
|
||||
WHEN duplicate_object THEN
|
||||
-- Ignore if values already exist
|
||||
NULL;
|
||||
END;
|
||||
END IF;
|
||||
END $$;
|
||||
|
||||
-- Update functions to use proper type casting
|
||||
CREATE OR REPLACE FUNCTION on_update_task_progress(_body json) RETURNS json
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_task_id UUID;
|
||||
_progress_value INTEGER;
|
||||
_parent_task_id UUID;
|
||||
_project_id UUID;
|
||||
_current_mode progress_mode_type;
|
||||
BEGIN
|
||||
_task_id = (_body ->> 'task_id')::UUID;
|
||||
_progress_value = (_body ->> 'progress_value')::INTEGER;
|
||||
_parent_task_id = (_body ->> 'parent_task_id')::UUID;
|
||||
|
||||
-- Get the project ID and determine the current progress mode
|
||||
SELECT project_id INTO _project_id FROM tasks WHERE id = _task_id;
|
||||
|
||||
IF _project_id IS NOT NULL THEN
|
||||
SELECT
|
||||
CASE
|
||||
WHEN use_manual_progress IS TRUE THEN 'manual'::progress_mode_type
|
||||
WHEN use_weighted_progress IS TRUE THEN 'weighted'::progress_mode_type
|
||||
WHEN use_time_progress IS TRUE THEN 'time'::progress_mode_type
|
||||
ELSE 'default'::progress_mode_type
|
||||
END
|
||||
INTO _current_mode
|
||||
FROM projects
|
||||
WHERE id = _project_id;
|
||||
ELSE
|
||||
_current_mode := 'default'::progress_mode_type;
|
||||
END IF;
|
||||
|
||||
-- Update the task with progress value and set the progress mode
|
||||
UPDATE tasks
|
||||
SET progress_value = _progress_value,
|
||||
manual_progress = TRUE,
|
||||
progress_mode = _current_mode,
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = _task_id;
|
||||
|
||||
-- Return the updated task info
|
||||
RETURN JSON_BUILD_OBJECT(
|
||||
'task_id', _task_id,
|
||||
'progress_value', _progress_value,
|
||||
'progress_mode', _current_mode
|
||||
);
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Update the on_update_task_weight function to use proper type casting
|
||||
CREATE OR REPLACE FUNCTION on_update_task_weight(_body json) RETURNS json
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_task_id UUID;
|
||||
_weight INTEGER;
|
||||
_parent_task_id UUID;
|
||||
_project_id UUID;
|
||||
BEGIN
|
||||
_task_id = (_body ->> 'task_id')::UUID;
|
||||
_weight = (_body ->> 'weight')::INTEGER;
|
||||
_parent_task_id = (_body ->> 'parent_task_id')::UUID;
|
||||
|
||||
-- Get the project ID
|
||||
SELECT project_id INTO _project_id FROM tasks WHERE id = _task_id;
|
||||
|
||||
-- Update the task with weight value and set progress_mode to 'weighted'
|
||||
UPDATE tasks
|
||||
SET weight = _weight,
|
||||
progress_mode = 'weighted'::progress_mode_type,
|
||||
updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = _task_id;
|
||||
|
||||
-- Return the updated task info
|
||||
RETURN JSON_BUILD_OBJECT(
|
||||
'task_id', _task_id,
|
||||
'weight', _weight
|
||||
);
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Update the reset_project_progress_values function to use proper type casting
|
||||
CREATE OR REPLACE FUNCTION reset_project_progress_values() RETURNS TRIGGER
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_old_mode progress_mode_type;
|
||||
_new_mode progress_mode_type;
|
||||
_project_id UUID;
|
||||
BEGIN
|
||||
_project_id := NEW.id;
|
||||
|
||||
-- Determine old and new modes with proper type casting
|
||||
_old_mode :=
|
||||
CASE
|
||||
WHEN OLD.use_manual_progress IS TRUE THEN 'manual'::progress_mode_type
|
||||
WHEN OLD.use_weighted_progress IS TRUE THEN 'weighted'::progress_mode_type
|
||||
WHEN OLD.use_time_progress IS TRUE THEN 'time'::progress_mode_type
|
||||
ELSE 'default'::progress_mode_type
|
||||
END;
|
||||
|
||||
_new_mode :=
|
||||
CASE
|
||||
WHEN NEW.use_manual_progress IS TRUE THEN 'manual'::progress_mode_type
|
||||
WHEN NEW.use_weighted_progress IS TRUE THEN 'weighted'::progress_mode_type
|
||||
WHEN NEW.use_time_progress IS TRUE THEN 'time'::progress_mode_type
|
||||
ELSE 'default'::progress_mode_type
|
||||
END;
|
||||
|
||||
-- If mode has changed, reset progress values for tasks with the old mode
|
||||
IF _old_mode <> _new_mode THEN
|
||||
-- Reset progress values for tasks that were set in the old mode
|
||||
UPDATE tasks
|
||||
SET progress_value = NULL,
|
||||
progress_mode = NULL
|
||||
WHERE project_id = _project_id
|
||||
AND progress_mode = _old_mode;
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Update the tasks table to ensure proper type casting for existing values
|
||||
UPDATE tasks
|
||||
SET progress_mode = progress_mode::text::progress_mode_type
|
||||
WHERE progress_mode IS NOT NULL;
|
||||
|
||||
COMMIT;
|
||||
@@ -23,33 +23,40 @@ ALTER TABLE projects
|
||||
ADD COLUMN IF NOT EXISTS use_time_progress BOOLEAN DEFAULT FALSE;
|
||||
|
||||
-- Update function to consider manual progress
|
||||
CREATE OR REPLACE FUNCTION get_task_complete_ratio(_task_id UUID) RETURNS JSON
|
||||
CREATE OR REPLACE FUNCTION get_task_complete_ratio(_task_id uuid) RETURNS json
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_parent_task_done FLOAT = 0;
|
||||
_sub_tasks_done FLOAT = 0;
|
||||
_sub_tasks_count FLOAT = 0;
|
||||
_total_completed FLOAT = 0;
|
||||
_total_tasks FLOAT = 0;
|
||||
_ratio FLOAT = 0;
|
||||
_is_manual BOOLEAN = FALSE;
|
||||
_manual_value INTEGER = NULL;
|
||||
_project_id UUID;
|
||||
_use_manual_progress BOOLEAN = FALSE;
|
||||
_parent_task_done FLOAT = 0;
|
||||
_sub_tasks_done FLOAT = 0;
|
||||
_sub_tasks_count FLOAT = 0;
|
||||
_total_completed FLOAT = 0;
|
||||
_total_tasks FLOAT = 0;
|
||||
_ratio FLOAT = 0;
|
||||
_is_manual BOOLEAN = FALSE;
|
||||
_manual_value INTEGER = NULL;
|
||||
_project_id UUID;
|
||||
_use_manual_progress BOOLEAN = FALSE;
|
||||
_use_weighted_progress BOOLEAN = FALSE;
|
||||
_use_time_progress BOOLEAN = FALSE;
|
||||
_use_time_progress BOOLEAN = FALSE;
|
||||
_task_complete BOOLEAN = FALSE;
|
||||
_progress_mode VARCHAR(20) = NULL;
|
||||
BEGIN
|
||||
-- Check if manual progress is set
|
||||
SELECT manual_progress, progress_value, project_id
|
||||
-- Check if manual progress is set for this task
|
||||
SELECT manual_progress, progress_value, project_id, progress_mode,
|
||||
EXISTS(
|
||||
SELECT 1
|
||||
FROM tasks_with_status_view
|
||||
WHERE tasks_with_status_view.task_id = tasks.id
|
||||
AND is_done IS TRUE
|
||||
) AS is_complete
|
||||
FROM tasks
|
||||
WHERE id = _task_id
|
||||
INTO _is_manual, _manual_value, _project_id;
|
||||
INTO _is_manual, _manual_value, _project_id, _progress_mode, _task_complete;
|
||||
|
||||
-- Check if the project uses manual progress
|
||||
IF _project_id IS NOT NULL
|
||||
THEN
|
||||
IF _project_id IS NOT NULL THEN
|
||||
SELECT COALESCE(use_manual_progress, FALSE),
|
||||
COALESCE(use_weighted_progress, FALSE),
|
||||
COALESCE(use_time_progress, FALSE)
|
||||
@@ -58,49 +65,212 @@ BEGIN
|
||||
INTO _use_manual_progress, _use_weighted_progress, _use_time_progress;
|
||||
END IF;
|
||||
|
||||
-- If manual progress is enabled and has a value, use it directly
|
||||
IF _is_manual IS TRUE AND _manual_value IS NOT NULL
|
||||
THEN
|
||||
-- Get all subtasks
|
||||
SELECT COUNT(*)
|
||||
FROM tasks
|
||||
WHERE parent_task_id = _task_id AND archived IS FALSE
|
||||
INTO _sub_tasks_count;
|
||||
|
||||
-- If task is complete, always return 100%
|
||||
IF _task_complete IS TRUE THEN
|
||||
RETURN JSON_BUILD_OBJECT(
|
||||
'ratio', 100,
|
||||
'total_completed', 1,
|
||||
'total_tasks', 1,
|
||||
'is_manual', FALSE
|
||||
);
|
||||
END IF;
|
||||
|
||||
-- Determine current active mode
|
||||
DECLARE
|
||||
_current_mode VARCHAR(20) = CASE
|
||||
WHEN _use_manual_progress IS TRUE THEN 'manual'
|
||||
WHEN _use_weighted_progress IS TRUE THEN 'weighted'
|
||||
WHEN _use_time_progress IS TRUE THEN 'time'
|
||||
ELSE 'default'
|
||||
END;
|
||||
BEGIN
|
||||
-- Only use manual progress value if it was set in the current active mode
|
||||
-- and time progress is not enabled
|
||||
IF _use_time_progress IS FALSE AND
|
||||
((_is_manual IS TRUE AND _manual_value IS NOT NULL AND
|
||||
(_progress_mode IS NULL OR _progress_mode = _current_mode)) OR
|
||||
(_use_manual_progress IS TRUE AND _manual_value IS NOT NULL AND
|
||||
(_progress_mode IS NULL OR _progress_mode = 'manual'))) THEN
|
||||
RETURN JSON_BUILD_OBJECT(
|
||||
'ratio', _manual_value,
|
||||
'total_completed', 0,
|
||||
'total_tasks', 0,
|
||||
'is_manual', TRUE
|
||||
);
|
||||
);
|
||||
END IF;
|
||||
END;
|
||||
|
||||
-- If there are no subtasks, calculate based on the task itself
|
||||
IF _sub_tasks_count = 0 THEN
|
||||
-- Use time-based estimation if enabled
|
||||
IF _use_time_progress IS TRUE THEN
|
||||
-- Calculate progress based on logged time vs estimated time
|
||||
WITH task_time_info AS (
|
||||
SELECT
|
||||
COALESCE(t.total_minutes, 0) as estimated_minutes,
|
||||
COALESCE((
|
||||
SELECT SUM(time_spent)
|
||||
FROM task_work_log
|
||||
WHERE task_id = t.id
|
||||
), 0) as logged_minutes
|
||||
FROM tasks t
|
||||
WHERE t.id = _task_id
|
||||
)
|
||||
SELECT
|
||||
CASE
|
||||
WHEN _task_complete IS TRUE THEN 100
|
||||
WHEN estimated_minutes > 0 THEN
|
||||
LEAST((logged_minutes / estimated_minutes) * 100, 100)
|
||||
ELSE 0
|
||||
END
|
||||
INTO _ratio
|
||||
FROM task_time_info;
|
||||
ELSE
|
||||
-- Traditional calculation for non-time-based tasks
|
||||
SELECT (CASE WHEN _task_complete IS TRUE THEN 1 ELSE 0 END)
|
||||
INTO _parent_task_done;
|
||||
|
||||
_ratio = _parent_task_done * 100;
|
||||
END IF;
|
||||
ELSE
|
||||
-- If project uses manual progress, calculate based on subtask manual progress values
|
||||
IF _use_manual_progress IS TRUE AND _use_time_progress IS FALSE THEN
|
||||
WITH subtask_progress AS (
|
||||
SELECT
|
||||
t.id,
|
||||
t.manual_progress,
|
||||
t.progress_value,
|
||||
t.progress_mode,
|
||||
EXISTS(
|
||||
SELECT 1
|
||||
FROM tasks_with_status_view
|
||||
WHERE tasks_with_status_view.task_id = t.id
|
||||
AND is_done IS TRUE
|
||||
) AS is_complete
|
||||
FROM tasks t
|
||||
WHERE t.parent_task_id = _task_id
|
||||
AND t.archived IS FALSE
|
||||
),
|
||||
subtask_with_values AS (
|
||||
SELECT
|
||||
CASE
|
||||
WHEN is_complete IS TRUE THEN 100
|
||||
WHEN progress_value IS NOT NULL AND (progress_mode = 'manual' OR progress_mode IS NULL) THEN progress_value
|
||||
ELSE 0
|
||||
END AS progress_value
|
||||
FROM subtask_progress
|
||||
)
|
||||
SELECT COALESCE(AVG(progress_value), 0)
|
||||
FROM subtask_with_values
|
||||
INTO _ratio;
|
||||
-- If project uses weighted progress, calculate based on subtask weights
|
||||
ELSIF _use_weighted_progress IS TRUE AND _use_time_progress IS FALSE THEN
|
||||
WITH subtask_progress AS (
|
||||
SELECT
|
||||
t.id,
|
||||
t.manual_progress,
|
||||
t.progress_value,
|
||||
t.progress_mode,
|
||||
EXISTS(
|
||||
SELECT 1
|
||||
FROM tasks_with_status_view
|
||||
WHERE tasks_with_status_view.task_id = t.id
|
||||
AND is_done IS TRUE
|
||||
) AS is_complete,
|
||||
COALESCE(t.weight, 100) AS weight
|
||||
FROM tasks t
|
||||
WHERE t.parent_task_id = _task_id
|
||||
AND t.archived IS FALSE
|
||||
),
|
||||
subtask_with_values AS (
|
||||
SELECT
|
||||
CASE
|
||||
WHEN is_complete IS TRUE THEN 100
|
||||
WHEN progress_value IS NOT NULL AND (progress_mode = 'weighted' OR progress_mode IS NULL) THEN progress_value
|
||||
ELSE 0
|
||||
END AS progress_value,
|
||||
weight
|
||||
FROM subtask_progress
|
||||
)
|
||||
SELECT COALESCE(
|
||||
SUM(progress_value * weight) / NULLIF(SUM(weight), 0),
|
||||
0
|
||||
)
|
||||
FROM subtask_with_values
|
||||
INTO _ratio;
|
||||
-- If project uses time-based progress, calculate based on actual logged time
|
||||
ELSIF _use_time_progress IS TRUE THEN
|
||||
WITH task_time_info AS (
|
||||
SELECT
|
||||
t.id,
|
||||
COALESCE(t.total_minutes, 0) as estimated_minutes,
|
||||
COALESCE((
|
||||
SELECT SUM(time_spent)
|
||||
FROM task_work_log
|
||||
WHERE task_id = t.id
|
||||
), 0) as logged_minutes,
|
||||
EXISTS(
|
||||
SELECT 1
|
||||
FROM tasks_with_status_view
|
||||
WHERE tasks_with_status_view.task_id = t.id
|
||||
AND is_done IS TRUE
|
||||
) AS is_complete
|
||||
FROM tasks t
|
||||
WHERE t.parent_task_id = _task_id
|
||||
AND t.archived IS FALSE
|
||||
)
|
||||
SELECT COALESCE(
|
||||
SUM(
|
||||
CASE
|
||||
WHEN is_complete IS TRUE THEN estimated_minutes
|
||||
ELSE LEAST(logged_minutes, estimated_minutes)
|
||||
END
|
||||
) / NULLIF(SUM(estimated_minutes), 0) * 100,
|
||||
0
|
||||
)
|
||||
FROM task_time_info
|
||||
INTO _ratio;
|
||||
ELSE
|
||||
-- Traditional calculation based on completion status
|
||||
SELECT (CASE WHEN _task_complete IS TRUE THEN 1 ELSE 0 END)
|
||||
INTO _parent_task_done;
|
||||
|
||||
SELECT COUNT(*)
|
||||
FROM tasks_with_status_view
|
||||
WHERE parent_task_id = _task_id
|
||||
AND is_done IS TRUE
|
||||
INTO _sub_tasks_done;
|
||||
|
||||
_total_completed = _parent_task_done + _sub_tasks_done;
|
||||
_total_tasks = _sub_tasks_count + 1; -- +1 for the parent task
|
||||
|
||||
IF _total_tasks = 0 THEN
|
||||
_ratio = 0;
|
||||
ELSE
|
||||
_ratio = (_total_completed / _total_tasks) * 100;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Otherwise calculate automatically as before
|
||||
SELECT (CASE
|
||||
WHEN EXISTS(SELECT 1
|
||||
FROM tasks_with_status_view
|
||||
WHERE tasks_with_status_view.task_id = _task_id
|
||||
AND is_done IS TRUE) THEN 1
|
||||
ELSE 0 END)
|
||||
INTO _parent_task_done;
|
||||
SELECT COUNT(*) FROM tasks WHERE parent_task_id = _task_id AND archived IS FALSE INTO _sub_tasks_count;
|
||||
|
||||
SELECT COUNT(*)
|
||||
FROM tasks_with_status_view
|
||||
WHERE parent_task_id = _task_id
|
||||
AND is_done IS TRUE
|
||||
INTO _sub_tasks_done;
|
||||
|
||||
_total_completed = _parent_task_done + _sub_tasks_done;
|
||||
_total_tasks = _sub_tasks_count; -- +1 for the parent task
|
||||
|
||||
IF _total_tasks > 0
|
||||
THEN
|
||||
_ratio = (_total_completed / _total_tasks) * 100;
|
||||
ELSE
|
||||
_ratio = _parent_task_done * 100;
|
||||
-- Ensure ratio is between 0 and 100
|
||||
IF _ratio < 0 THEN
|
||||
_ratio = 0;
|
||||
ELSIF _ratio > 100 THEN
|
||||
_ratio = 100;
|
||||
END IF;
|
||||
|
||||
RETURN JSON_BUILD_OBJECT(
|
||||
'ratio', _ratio,
|
||||
'total_completed', _total_completed,
|
||||
'total_tasks', _total_tasks,
|
||||
'is_manual', FALSE
|
||||
);
|
||||
'ratio', _ratio,
|
||||
'total_completed', _total_completed,
|
||||
'total_tasks', _total_tasks,
|
||||
'is_manual', _is_manual
|
||||
);
|
||||
END
|
||||
$$;
|
||||
|
||||
@@ -615,38 +785,38 @@ BEGIN
|
||||
)
|
||||
FROM subtask_with_values
|
||||
INTO _ratio;
|
||||
-- If project uses time-based progress, calculate based on estimated time
|
||||
-- If project uses time-based progress, calculate based on actual logged time
|
||||
ELSIF _use_time_progress IS TRUE
|
||||
THEN
|
||||
WITH subtask_progress AS (SELECT t.id,
|
||||
t.manual_progress,
|
||||
t.progress_value,
|
||||
t.progress_mode,
|
||||
EXISTS(SELECT 1
|
||||
FROM tasks_with_status_view
|
||||
WHERE tasks_with_status_view.task_id = t.id
|
||||
AND is_done IS TRUE) AS is_complete,
|
||||
COALESCE(t.total_minutes, 0) AS estimated_minutes
|
||||
FROM tasks t
|
||||
WHERE t.parent_task_id = _task_id
|
||||
AND t.archived IS FALSE),
|
||||
subtask_with_values AS (SELECT CASE
|
||||
-- For completed tasks, always use 100%
|
||||
WHEN is_complete IS TRUE THEN 100
|
||||
-- For tasks with progress value set in the correct mode, use it
|
||||
WHEN progress_value IS NOT NULL AND
|
||||
(progress_mode = 'time' OR progress_mode IS NULL)
|
||||
THEN progress_value
|
||||
-- Default to 0 for incomplete tasks with no progress value or wrong mode
|
||||
ELSE 0
|
||||
END AS progress_value,
|
||||
estimated_minutes
|
||||
FROM subtask_progress)
|
||||
WITH task_time_info AS (
|
||||
SELECT
|
||||
t.id,
|
||||
COALESCE(t.total_minutes, 0) as estimated_minutes,
|
||||
COALESCE((
|
||||
SELECT SUM(time_spent)
|
||||
FROM task_work_log
|
||||
WHERE task_id = t.id
|
||||
), 0) as logged_minutes,
|
||||
EXISTS(
|
||||
SELECT 1
|
||||
FROM tasks_with_status_view
|
||||
WHERE tasks_with_status_view.task_id = t.id
|
||||
AND is_done IS TRUE
|
||||
) AS is_complete
|
||||
FROM tasks t
|
||||
WHERE t.parent_task_id = _task_id
|
||||
AND t.archived IS FALSE
|
||||
)
|
||||
SELECT COALESCE(
|
||||
SUM(progress_value * estimated_minutes) / NULLIF(SUM(estimated_minutes), 0),
|
||||
0
|
||||
)
|
||||
FROM subtask_with_values
|
||||
SUM(
|
||||
CASE
|
||||
WHEN is_complete IS TRUE THEN estimated_minutes
|
||||
ELSE LEAST(logged_minutes, estimated_minutes)
|
||||
END
|
||||
) / NULLIF(SUM(estimated_minutes), 0) * 100,
|
||||
0
|
||||
)
|
||||
FROM task_time_info
|
||||
INTO _ratio;
|
||||
ELSE
|
||||
-- Traditional calculation based on completion status
|
||||
|
||||
@@ -408,6 +408,65 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
|
||||
const { duration, date_range } = req.body;
|
||||
|
||||
// Calculate the date range (start and end)
|
||||
let startDate: moment.Moment;
|
||||
let endDate: moment.Moment;
|
||||
if (date_range && date_range.length === 2) {
|
||||
startDate = moment(date_range[0]);
|
||||
endDate = moment(date_range[1]);
|
||||
} else if (duration === DATE_RANGES.ALL_TIME) {
|
||||
// Fetch the earliest start_date (or created_at if null) from selected projects
|
||||
const minDateQuery = `SELECT MIN(COALESCE(start_date, created_at)) as min_date FROM projects WHERE id IN (${projectIds})`;
|
||||
const minDateResult = await db.query(minDateQuery, []);
|
||||
const minDate = minDateResult.rows[0]?.min_date;
|
||||
startDate = minDate ? moment(minDate) : moment('2000-01-01');
|
||||
endDate = moment();
|
||||
} else {
|
||||
switch (duration) {
|
||||
case DATE_RANGES.YESTERDAY:
|
||||
startDate = moment().subtract(1, "day");
|
||||
endDate = moment().subtract(1, "day");
|
||||
break;
|
||||
case DATE_RANGES.LAST_WEEK:
|
||||
startDate = moment().subtract(1, "week").startOf("isoWeek");
|
||||
endDate = moment().subtract(1, "week").endOf("isoWeek");
|
||||
break;
|
||||
case DATE_RANGES.LAST_MONTH:
|
||||
startDate = moment().subtract(1, "month").startOf("month");
|
||||
endDate = moment().subtract(1, "month").endOf("month");
|
||||
break;
|
||||
case DATE_RANGES.LAST_QUARTER:
|
||||
startDate = moment().subtract(3, "months").startOf("quarter");
|
||||
endDate = moment().subtract(1, "quarter").endOf("quarter");
|
||||
break;
|
||||
default:
|
||||
startDate = moment().startOf("day");
|
||||
endDate = moment().endOf("day");
|
||||
}
|
||||
}
|
||||
|
||||
// Count only weekdays (Mon-Fri) in the period
|
||||
let workingDays = 0;
|
||||
let current = startDate.clone();
|
||||
while (current.isSameOrBefore(endDate, 'day')) {
|
||||
const day = current.isoWeekday();
|
||||
if (day >= 1 && day <= 5) workingDays++;
|
||||
current.add(1, 'day');
|
||||
}
|
||||
|
||||
// Get hours_per_day for all selected projects
|
||||
const projectHoursQuery = `SELECT id, hours_per_day FROM projects WHERE id IN (${projectIds})`;
|
||||
const projectHoursResult = await db.query(projectHoursQuery, []);
|
||||
const projectHoursMap: Record<string, number> = {};
|
||||
for (const row of projectHoursResult.rows) {
|
||||
projectHoursMap[row.id] = row.hours_per_day || 8;
|
||||
}
|
||||
// Sum total working hours for all selected projects
|
||||
let totalWorkingHours = 0;
|
||||
for (const pid of Object.keys(projectHoursMap)) {
|
||||
totalWorkingHours += workingDays * projectHoursMap[pid];
|
||||
}
|
||||
|
||||
const durationClause = this.getDateRangeClause(duration || DATE_RANGES.LAST_WEEK, date_range);
|
||||
const archivedClause = archived
|
||||
? ""
|
||||
@@ -430,6 +489,12 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
for (const member of result.rows) {
|
||||
member.value = member.logged_time ? parseFloat(moment.duration(member.logged_time, "seconds").asHours().toFixed(2)) : 0;
|
||||
member.color_code = getColor(member.name);
|
||||
member.total_working_hours = totalWorkingHours;
|
||||
member.utilization_percent = (totalWorkingHours > 0 && member.logged_time) ? ((parseFloat(member.logged_time) / (totalWorkingHours * 3600)) * 100).toFixed(2) : '0.00';
|
||||
member.utilized_hours = member.logged_time ? (parseFloat(member.logged_time) / 3600).toFixed(2) : '0.00';
|
||||
// Over/under utilized hours: utilized_hours - total_working_hours
|
||||
const overUnder = member.utilized_hours && member.total_working_hours ? (parseFloat(member.utilized_hours) - member.total_working_hours) : 0;
|
||||
member.over_under_utilized_hours = overUnder.toFixed(2);
|
||||
}
|
||||
|
||||
return res.status(200).send(new ServerResponse(true, result.rows));
|
||||
|
||||
@@ -833,9 +833,7 @@ export default class TasksControllerV2 extends TasksControllerBase {
|
||||
}
|
||||
|
||||
public static async refreshProjectTaskProgressValues(projectId: string): Promise<void> {
|
||||
try {
|
||||
console.log(`Refreshing progress values for project ${projectId}`);
|
||||
|
||||
try {
|
||||
// Run the recalculate_all_task_progress function only for tasks in this project
|
||||
const query = `
|
||||
DO $$
|
||||
@@ -893,10 +891,10 @@ export default class TasksControllerV2 extends TasksControllerBase {
|
||||
END $$;
|
||||
`;
|
||||
|
||||
const result = await db.query(query);
|
||||
await db.query(query);
|
||||
console.log(`Finished refreshing progress values for project ${projectId}`);
|
||||
} catch (error) {
|
||||
log_error('Error refreshing project task progress values', error);
|
||||
log_error("Error refreshing project task progress values", error);
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
@@ -81,6 +81,22 @@ const MembersTimeSheet = forwardRef<MembersTimeSheetRef>((_, ref) => {
|
||||
display: false,
|
||||
position: 'top' as const,
|
||||
},
|
||||
tooltip: {
|
||||
callbacks: {
|
||||
label: function(context: any) {
|
||||
const idx = context.dataIndex;
|
||||
const member = jsonData[idx];
|
||||
const hours = member?.utilized_hours || '0.00';
|
||||
const percent = member?.utilization_percent || '0.00';
|
||||
const overUnder = member?.over_under_utilized_hours || '0.00';
|
||||
return [
|
||||
`${context.dataset.label}: ${hours} h`,
|
||||
`Utilization: ${percent}%`,
|
||||
`Over/Under Utilized: ${overUnder} h`
|
||||
];
|
||||
}
|
||||
}
|
||||
}
|
||||
},
|
||||
backgroundColor: 'black',
|
||||
indexAxis: 'y' as const,
|
||||
|
||||
@@ -406,6 +406,9 @@ export interface IRPTTimeMember {
|
||||
value?: number;
|
||||
color_code: string;
|
||||
logged_time?: string;
|
||||
utilized_hours?: string;
|
||||
utilization_percent?: string;
|
||||
over_under_utilized_hours?: string;
|
||||
}
|
||||
|
||||
export interface IMemberTaskStatGroupResonse {
|
||||
|
||||
Reference in New Issue
Block a user