-- Migration: Update time-based progress mode to work for all tasks -- Date: 2025-04-25 -- Version: 1.0.0 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; BEGIN -- Check if manual progress is set for this task SELECT manual_progress, progress_value, project_id FROM tasks WHERE id = _task_id INTO _is_manual, _manual_value, _project_id; -- 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; -- Always respect manual progress value if set 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; -- 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 EXISTS( SELECT 1 FROM tasks_with_status_view WHERE tasks_with_status_view.task_id = _task_id AND is_done 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) 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 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 FROM tasks t WHERE t.parent_task_id = _task_id AND t.archived IS FALSE ) SELECT COALESCE(AVG(progress_value), 0) FROM subtask_progress 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 FROM tasks t WHERE t.parent_task_id = _task_id AND t.archived IS FALSE ) SELECT COALESCE( SUM(progress_value * weight) / NULLIF(SUM(weight), 0), 0 ) FROM subtask_progress 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 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_progress 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) 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;