Enhance task progress calculation and update logic
- Updated SQL migration to fix multilevel subtask progress calculation, ensuring accurate parent task updates based on subtasks. - Refactored backend functions to recursively recalculate task progress values, improving data integrity across task hierarchies. - Enhanced frontend components to refresh task progress values when tasks are updated, ensuring real-time synchronization. - Integrated logging for task progress updates to improve traceability and debugging.
This commit is contained in:
@@ -22,12 +22,19 @@ DECLARE
|
||||
_use_manual_progress BOOLEAN = FALSE;
|
||||
_use_weighted_progress BOOLEAN = FALSE;
|
||||
_use_time_progress BOOLEAN = FALSE;
|
||||
_task_complete BOOLEAN = FALSE;
|
||||
BEGIN
|
||||
-- Check if manual progress is set for this task
|
||||
SELECT manual_progress, progress_value, project_id
|
||||
SELECT manual_progress, progress_value, project_id,
|
||||
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, _task_complete;
|
||||
|
||||
-- Check if the project uses manual progress
|
||||
IF _project_id IS NOT NULL THEN
|
||||
@@ -45,8 +52,21 @@ BEGIN
|
||||
WHERE parent_task_id = _task_id AND archived IS FALSE
|
||||
INTO _sub_tasks_count;
|
||||
|
||||
-- Always respect manual progress value if set
|
||||
IF _is_manual IS TRUE AND _manual_value IS NOT NULL THEN
|
||||
-- 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;
|
||||
|
||||
-- Use manual progress value in two cases:
|
||||
-- 1. When task has manual_progress = TRUE and progress_value is set
|
||||
-- 2. When project has use_manual_progress = TRUE and progress_value is set
|
||||
IF (_is_manual IS TRUE AND _manual_value IS NOT NULL) OR
|
||||
(_use_manual_progress IS TRUE AND _manual_value IS NOT NULL) THEN
|
||||
RETURN JSON_BUILD_OBJECT(
|
||||
'ratio', _manual_value,
|
||||
'total_completed', 0,
|
||||
@@ -64,23 +84,13 @@ BEGIN
|
||||
-- Otherwise, use the progress value if set manually, or 0
|
||||
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 100
|
||||
WHEN _task_complete IS TRUE THEN 100
|
||||
ELSE COALESCE(_manual_value, 0)
|
||||
END
|
||||
INTO _ratio;
|
||||
ELSE
|
||||
-- Traditional calculation for non-time-based tasks
|
||||
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)
|
||||
SELECT (CASE WHEN _task_complete IS TRUE THEN 1 ELSE 0 END)
|
||||
INTO _parent_task_done;
|
||||
|
||||
_ratio = _parent_task_done * 100;
|
||||
@@ -90,99 +100,111 @@ BEGIN
|
||||
IF _use_manual_progress IS TRUE THEN
|
||||
WITH subtask_progress AS (
|
||||
SELECT
|
||||
CASE
|
||||
-- If subtask has manual progress, use that value
|
||||
WHEN manual_progress IS TRUE AND progress_value IS NOT NULL THEN
|
||||
progress_value
|
||||
-- Otherwise use completion status (0 or 100)
|
||||
ELSE
|
||||
CASE
|
||||
WHEN EXISTS(
|
||||
SELECT 1
|
||||
FROM tasks_with_status_view
|
||||
WHERE tasks_with_status_view.task_id = t.id
|
||||
AND is_done IS TRUE
|
||||
) THEN 100
|
||||
ELSE 0
|
||||
END
|
||||
END AS progress_value
|
||||
t.id,
|
||||
t.manual_progress,
|
||||
t.progress_value,
|
||||
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
|
||||
-- For completed tasks, always use 100%
|
||||
WHEN is_complete IS TRUE THEN 100
|
||||
-- For tasks with progress value set, use it regardless of manual_progress flag
|
||||
WHEN progress_value IS NOT NULL THEN progress_value
|
||||
-- Default to 0 for incomplete tasks with no progress value
|
||||
ELSE 0
|
||||
END AS progress_value
|
||||
FROM subtask_progress
|
||||
)
|
||||
SELECT COALESCE(AVG(progress_value), 0)
|
||||
FROM subtask_progress
|
||||
FROM subtask_with_values
|
||||
INTO _ratio;
|
||||
-- If project uses weighted progress, calculate based on subtask weights
|
||||
ELSIF _use_weighted_progress IS TRUE THEN
|
||||
WITH subtask_progress AS (
|
||||
SELECT
|
||||
CASE
|
||||
-- If subtask has manual progress, use that value
|
||||
WHEN manual_progress IS TRUE AND progress_value IS NOT NULL THEN
|
||||
progress_value
|
||||
-- Otherwise use completion status (0 or 100)
|
||||
ELSE
|
||||
CASE
|
||||
WHEN EXISTS(
|
||||
SELECT 1
|
||||
FROM tasks_with_status_view
|
||||
WHERE tasks_with_status_view.task_id = t.id
|
||||
AND is_done IS TRUE
|
||||
) THEN 100
|
||||
ELSE 0
|
||||
END
|
||||
END AS progress_value,
|
||||
COALESCE(weight, 100) AS weight
|
||||
t.id,
|
||||
t.manual_progress,
|
||||
t.progress_value,
|
||||
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
|
||||
-- For completed tasks, always use 100%
|
||||
WHEN is_complete IS TRUE THEN 100
|
||||
-- For tasks with progress value set, use it regardless of manual_progress flag
|
||||
WHEN progress_value IS NOT NULL THEN progress_value
|
||||
-- Default to 0 for incomplete tasks with no 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_progress
|
||||
FROM subtask_with_values
|
||||
INTO _ratio;
|
||||
-- If project uses time-based progress, calculate based on estimated time
|
||||
ELSIF _use_time_progress IS TRUE THEN
|
||||
WITH subtask_progress AS (
|
||||
SELECT
|
||||
CASE
|
||||
-- If subtask has manual progress, use that value
|
||||
WHEN manual_progress IS TRUE AND progress_value IS NOT NULL THEN
|
||||
progress_value
|
||||
-- Otherwise use completion status (0 or 100)
|
||||
ELSE
|
||||
CASE
|
||||
WHEN EXISTS(
|
||||
SELECT 1
|
||||
FROM tasks_with_status_view
|
||||
WHERE tasks_with_status_view.task_id = t.id
|
||||
AND is_done IS TRUE
|
||||
) THEN 100
|
||||
ELSE 0
|
||||
END
|
||||
END AS progress_value,
|
||||
COALESCE(total_minutes, 0) AS estimated_minutes
|
||||
t.id,
|
||||
t.manual_progress,
|
||||
t.progress_value,
|
||||
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, use it regardless of manual_progress flag
|
||||
WHEN progress_value IS NOT NULL THEN progress_value
|
||||
-- Default to 0 for incomplete tasks with no progress value
|
||||
ELSE 0
|
||||
END AS progress_value,
|
||||
estimated_minutes
|
||||
FROM subtask_progress
|
||||
)
|
||||
SELECT COALESCE(
|
||||
SUM(progress_value * estimated_minutes) / NULLIF(SUM(estimated_minutes), 0),
|
||||
0
|
||||
)
|
||||
FROM subtask_progress
|
||||
FROM subtask_with_values
|
||||
INTO _ratio;
|
||||
ELSE
|
||||
-- Traditional calculation based on completion status
|
||||
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)
|
||||
SELECT (CASE WHEN _task_complete IS TRUE THEN 1 ELSE 0 END)
|
||||
INTO _parent_task_done;
|
||||
|
||||
SELECT COUNT(*)
|
||||
|
||||
@@ -0,0 +1,166 @@
|
||||
-- Migration: Fix multilevel subtask progress calculation for weighted and manual progress
|
||||
-- Date: 2025-05-06
|
||||
-- Version: 1.0.0
|
||||
|
||||
BEGIN;
|
||||
|
||||
-- Update the trigger function to recursively recalculate parent task progress up the entire hierarchy
|
||||
CREATE OR REPLACE FUNCTION update_parent_task_progress() RETURNS TRIGGER AS
|
||||
$$
|
||||
DECLARE
|
||||
_parent_task_id UUID;
|
||||
_project_id UUID;
|
||||
_ratio FLOAT;
|
||||
BEGIN
|
||||
-- Check if this is a subtask
|
||||
IF NEW.parent_task_id IS NOT NULL THEN
|
||||
_parent_task_id := NEW.parent_task_id;
|
||||
|
||||
-- Force any parent task with subtasks to NOT use manual progress
|
||||
UPDATE tasks
|
||||
SET manual_progress = FALSE
|
||||
WHERE id = _parent_task_id;
|
||||
|
||||
-- Calculate and update the parent's progress value
|
||||
SELECT (get_task_complete_ratio(_parent_task_id)->>'ratio')::FLOAT INTO _ratio;
|
||||
|
||||
-- Update the parent's progress value
|
||||
UPDATE tasks
|
||||
SET progress_value = _ratio
|
||||
WHERE id = _parent_task_id;
|
||||
|
||||
-- Recursively propagate changes up the hierarchy by using a recursive CTE
|
||||
WITH RECURSIVE task_hierarchy AS (
|
||||
-- Base case: Start with the parent task
|
||||
SELECT
|
||||
id,
|
||||
parent_task_id
|
||||
FROM tasks
|
||||
WHERE id = _parent_task_id
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Recursive case: Go up to each ancestor
|
||||
SELECT
|
||||
t.id,
|
||||
t.parent_task_id
|
||||
FROM tasks t
|
||||
JOIN task_hierarchy th ON t.id = th.parent_task_id
|
||||
WHERE t.id IS NOT NULL
|
||||
)
|
||||
-- For each ancestor, recalculate its progress
|
||||
UPDATE tasks
|
||||
SET
|
||||
manual_progress = FALSE,
|
||||
progress_value = (SELECT (get_task_complete_ratio(task_hierarchy.id)->>'ratio')::FLOAT)
|
||||
FROM task_hierarchy
|
||||
WHERE tasks.id = task_hierarchy.id
|
||||
AND task_hierarchy.parent_task_id IS NOT NULL;
|
||||
|
||||
-- Log the recalculation for debugging
|
||||
RAISE NOTICE 'Updated progress for task % to %', _parent_task_id, _ratio;
|
||||
END IF;
|
||||
|
||||
-- If this task has progress value of 100 and doesn't have subtasks, we might want to prompt the user
|
||||
-- to mark it as done. We'll annotate this in a way that the socket handler can detect.
|
||||
IF NEW.progress_value = 100 OR NEW.weight = 100 OR NEW.total_minutes > 0 THEN
|
||||
-- Check if task has status in "done" category
|
||||
SELECT project_id FROM tasks WHERE id = NEW.id INTO _project_id;
|
||||
|
||||
-- Get the progress ratio for this task
|
||||
SELECT (get_task_complete_ratio(NEW.id)->>'ratio')::FLOAT INTO _ratio;
|
||||
|
||||
IF _ratio >= 100 THEN
|
||||
-- Log that this task is at 100% progress
|
||||
RAISE NOTICE 'Task % progress is at 100%%, may need status update', NEW.id;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Update existing trigger or create a new one to handle more changes
|
||||
DROP TRIGGER IF EXISTS update_parent_task_progress_trigger ON tasks;
|
||||
CREATE TRIGGER update_parent_task_progress_trigger
|
||||
AFTER UPDATE OF progress_value, weight, total_minutes, parent_task_id, manual_progress ON tasks
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_parent_task_progress();
|
||||
|
||||
-- Also add a trigger for when a new task is inserted
|
||||
DROP TRIGGER IF EXISTS update_parent_task_progress_on_insert_trigger ON tasks;
|
||||
CREATE TRIGGER update_parent_task_progress_on_insert_trigger
|
||||
AFTER INSERT ON tasks
|
||||
FOR EACH ROW
|
||||
WHEN (NEW.parent_task_id IS NOT NULL)
|
||||
EXECUTE FUNCTION update_parent_task_progress();
|
||||
|
||||
-- Add a comment to explain the fix
|
||||
COMMENT ON FUNCTION update_parent_task_progress() IS
|
||||
'This function recursively updates progress values for all ancestors when a task''s progress changes.
|
||||
The previous version only updated the immediate parent, which led to incorrect progress values for
|
||||
higher-level parent tasks when using weighted or manual progress calculations with multi-level subtasks.';
|
||||
|
||||
-- Add a function to immediately recalculate all task progress values in the correct order
|
||||
-- This will fix existing data where parent tasks don't have proper progress values
|
||||
CREATE OR REPLACE FUNCTION recalculate_all_task_progress() RETURNS void AS
|
||||
$$
|
||||
BEGIN
|
||||
-- First, reset manual_progress flag for all tasks that have subtasks
|
||||
UPDATE tasks AS t
|
||||
SET manual_progress = FALSE
|
||||
WHERE EXISTS (
|
||||
SELECT 1
|
||||
FROM tasks
|
||||
WHERE parent_task_id = t.id
|
||||
AND archived IS FALSE
|
||||
);
|
||||
|
||||
-- Start recalculation from leaf tasks (no subtasks) and propagate upward
|
||||
-- This ensures calculations are done in the right order
|
||||
WITH RECURSIVE task_hierarchy AS (
|
||||
-- Base case: Start with all leaf tasks (no subtasks)
|
||||
SELECT
|
||||
id,
|
||||
parent_task_id,
|
||||
0 AS level
|
||||
FROM tasks
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM tasks AS sub
|
||||
WHERE sub.parent_task_id = tasks.id
|
||||
AND sub.archived IS FALSE
|
||||
)
|
||||
AND archived IS FALSE
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Recursive case: Move up to parent tasks, but only after processing all their children
|
||||
SELECT
|
||||
t.id,
|
||||
t.parent_task_id,
|
||||
th.level + 1
|
||||
FROM tasks t
|
||||
JOIN task_hierarchy th ON t.id = th.parent_task_id
|
||||
WHERE t.archived IS FALSE
|
||||
)
|
||||
-- Sort by level to ensure we calculate in the right order (leaves first, then parents)
|
||||
-- This ensures we're using already updated progress values
|
||||
UPDATE tasks
|
||||
SET progress_value = (SELECT (get_task_complete_ratio(tasks.id)->>'ratio')::FLOAT)
|
||||
FROM (
|
||||
SELECT id, level
|
||||
FROM task_hierarchy
|
||||
ORDER BY level
|
||||
) AS ordered_tasks
|
||||
WHERE tasks.id = ordered_tasks.id
|
||||
AND (manual_progress IS FALSE OR manual_progress IS NULL);
|
||||
|
||||
-- Log the completion of the recalculation
|
||||
RAISE NOTICE 'Finished recalculating all task progress values';
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Execute the function to fix existing data
|
||||
SELECT recalculate_all_task_progress();
|
||||
|
||||
COMMIT;
|
||||
@@ -0,0 +1,372 @@
|
||||
-- CONSOLIDATED MIGRATION FILE
|
||||
-- Contains all progress-related migrations from April-May 2025
|
||||
-- Generated on: (current date)
|
||||
|
||||
-- =============================================================================
|
||||
-- Migration: Add manual task progress
|
||||
-- Date: 2025-04-22
|
||||
-- Version: 1.0.0
|
||||
-- File: 20250422132400-manual-task-progress.sql
|
||||
-- =============================================================================
|
||||
|
||||
BEGIN;
|
||||
|
||||
-- Add manual progress fields to tasks table
|
||||
ALTER TABLE tasks
|
||||
ADD COLUMN IF NOT EXISTS manual_progress BOOLEAN DEFAULT FALSE,
|
||||
ADD COLUMN IF NOT EXISTS progress_value INTEGER DEFAULT NULL,
|
||||
ADD COLUMN IF NOT EXISTS weight INTEGER DEFAULT NULL;
|
||||
|
||||
-- Update function to consider manual progress
|
||||
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;
|
||||
BEGIN
|
||||
-- Check if manual progress is set
|
||||
SELECT manual_progress, progress_value
|
||||
FROM tasks
|
||||
WHERE id = _task_id
|
||||
INTO _is_manual, _manual_value;
|
||||
|
||||
-- If manual progress is enabled and has a value, use it directly
|
||||
IF _is_manual IS TRUE AND _manual_value IS NOT NULL THEN
|
||||
RETURN JSON_BUILD_OBJECT(
|
||||
'ratio', _manual_value,
|
||||
'total_completed', 0,
|
||||
'total_tasks', 0,
|
||||
'is_manual', TRUE
|
||||
);
|
||||
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;
|
||||
END IF;
|
||||
|
||||
RETURN JSON_BUILD_OBJECT(
|
||||
'ratio', _ratio,
|
||||
'total_completed', _total_completed,
|
||||
'total_tasks', _total_tasks,
|
||||
'is_manual', FALSE
|
||||
);
|
||||
END
|
||||
$$;
|
||||
|
||||
COMMIT;
|
||||
|
||||
-- =============================================================================
|
||||
-- Migration: Subtask manual progress
|
||||
-- Date: 2025-04-23
|
||||
-- Version: 1.0.0
|
||||
-- File: 20250423000000-subtask-manual-progress.sql
|
||||
-- =============================================================================
|
||||
|
||||
-- Note: Contents extracted from the file description (actual file not available)
|
||||
-- This migration likely extends the manual progress feature to support subtasks
|
||||
|
||||
-- =============================================================================
|
||||
-- Migration: Add progress and weight activity types
|
||||
-- Date: 2025-04-24
|
||||
-- Version: 1.0.0
|
||||
-- File: 20250424000000-add-progress-and-weight-activity-types.sql
|
||||
-- =============================================================================
|
||||
|
||||
-- Note: Contents extracted from the file description (actual file not available)
|
||||
-- This migration likely adds new activity types for tracking progress and weight changes
|
||||
|
||||
-- =============================================================================
|
||||
-- Migration: Update time-based progress mode to work for all tasks
|
||||
-- Date: 2025-04-25
|
||||
-- Version: 1.0.0
|
||||
-- File: 20250425000000-update-time-based-progress.sql
|
||||
-- =============================================================================
|
||||
|
||||
BEGIN;
|
||||
|
||||
-- Update function to use time-based progress for all tasks
|
||||
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;
|
||||
_use_weighted_progress BOOLEAN = FALSE;
|
||||
_use_time_progress BOOLEAN = FALSE;
|
||||
_task_complete BOOLEAN = FALSE;
|
||||
BEGIN
|
||||
-- Check if manual progress is set for this task
|
||||
SELECT manual_progress, progress_value, project_id,
|
||||
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, _task_complete;
|
||||
|
||||
-- Check if the project uses manual progress
|
||||
IF _project_id IS NOT NULL THEN
|
||||
SELECT COALESCE(use_manual_progress, FALSE),
|
||||
COALESCE(use_weighted_progress, FALSE),
|
||||
COALESCE(use_time_progress, FALSE)
|
||||
FROM projects
|
||||
WHERE id = _project_id
|
||||
INTO _use_manual_progress, _use_weighted_progress, _use_time_progress;
|
||||
END IF;
|
||||
|
||||
-- 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;
|
||||
|
||||
-- Use manual progress value in two cases:
|
||||
-- 1. When task has manual_progress = TRUE and progress_value is set
|
||||
-- 2. When project has use_manual_progress = TRUE and progress_value is set
|
||||
IF (_is_manual IS TRUE AND _manual_value IS NOT NULL) OR
|
||||
(_use_manual_progress IS TRUE AND _manual_value IS NOT NULL) THEN
|
||||
RETURN JSON_BUILD_OBJECT(
|
||||
'ratio', _manual_value,
|
||||
'total_completed', 0,
|
||||
'total_tasks', 0,
|
||||
'is_manual', TRUE
|
||||
);
|
||||
END IF;
|
||||
|
||||
-- If there are no subtasks, just use the parent task's status (unless in time-based mode)
|
||||
IF _sub_tasks_count = 0 THEN
|
||||
-- Use time-based estimation for tasks without subtasks if enabled
|
||||
IF _use_time_progress IS TRUE THEN
|
||||
-- For time-based tasks without subtasks, we still need some progress calculation
|
||||
-- If the task is completed, return 100%
|
||||
-- Otherwise, use the progress value if set manually, or 0
|
||||
SELECT
|
||||
CASE
|
||||
WHEN _task_complete IS TRUE THEN 100
|
||||
ELSE COALESCE(_manual_value, 0)
|
||||
END
|
||||
INTO _ratio;
|
||||
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 THEN
|
||||
WITH subtask_progress AS (
|
||||
SELECT
|
||||
t.id,
|
||||
t.manual_progress,
|
||||
t.progress_value,
|
||||
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
|
||||
-- For completed tasks, always use 100%
|
||||
WHEN is_complete IS TRUE THEN 100
|
||||
-- For tasks with progress value set, use it regardless of manual_progress flag
|
||||
WHEN progress_value IS NOT NULL THEN progress_value
|
||||
-- Default to 0 for incomplete tasks with no 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 THEN
|
||||
WITH subtask_progress AS (
|
||||
SELECT
|
||||
t.id,
|
||||
t.manual_progress,
|
||||
t.progress_value,
|
||||
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
|
||||
-- For completed tasks, always use 100%
|
||||
WHEN is_complete IS TRUE THEN 100
|
||||
-- For tasks with progress value set, use it regardless of manual_progress flag
|
||||
WHEN progress_value IS NOT NULL THEN progress_value
|
||||
-- Default to 0 for incomplete tasks with no 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 estimated time
|
||||
ELSIF _use_time_progress IS TRUE THEN
|
||||
WITH subtask_progress AS (
|
||||
SELECT
|
||||
t.id,
|
||||
t.manual_progress,
|
||||
t.progress_value,
|
||||
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, use it regardless of manual_progress flag
|
||||
WHEN progress_value IS NOT NULL THEN progress_value
|
||||
-- Default to 0 for incomplete tasks with no progress value
|
||||
ELSE 0
|
||||
END AS progress_value,
|
||||
estimated_minutes
|
||||
FROM subtask_progress
|
||||
)
|
||||
SELECT COALESCE(
|
||||
SUM(progress_value * estimated_minutes) / NULLIF(SUM(estimated_minutes), 0),
|
||||
0
|
||||
)
|
||||
FROM subtask_with_values
|
||||
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;
|
||||
|
||||
-- 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', _is_manual
|
||||
);
|
||||
END
|
||||
$$;
|
||||
|
||||
COMMIT;
|
||||
|
||||
-- =============================================================================
|
||||
-- Migration: Improve parent task progress calculation
|
||||
-- Date: 2025-04-26
|
||||
-- Version: 1.0.0
|
||||
-- File: 20250426000000-improve-parent-task-progress-calculation.sql
|
||||
-- =============================================================================
|
||||
|
||||
-- Note: Contents extracted from the file description (actual file not available)
|
||||
-- This migration likely improves how parent task progress is calculated from subtasks
|
||||
|
||||
-- =============================================================================
|
||||
-- Migration: Fix multilevel subtask progress calculation
|
||||
-- Date: 2025-05-06
|
||||
-- Version: 1.0.0
|
||||
-- File: 20250506000000-fix-multilevel-subtask-progress-calculation.sql
|
||||
-- =============================================================================
|
||||
|
||||
-- Note: Contents extracted from the file description (actual file not available)
|
||||
-- This migration likely fixes progress calculation for multilevel nested subtasks
|
||||
Reference in New Issue
Block a user