feat(task-hierarchy): implement recursive task estimation and reset functionality

- Added SQL scripts to fix task hierarchy and reset parent task estimations to zero, ensuring accurate estimation calculations.
- Introduced a migration for a recursive task estimation function that aggregates estimations from subtasks, enhancing task management.
- Updated controllers to utilize recursive estimations for displaying task data, improving accuracy in task progress representation.
- Implemented a new API route to reset parent task estimations, allowing for better task management and data integrity.
This commit is contained in:
chamikaJ
2025-06-09 12:33:23 +05:30
parent 509fcc8f64
commit 6e188899ed
12 changed files with 637 additions and 42 deletions

View File

@@ -0,0 +1,228 @@
-- Migration: Add recursive task estimation functionality
-- This migration adds a function to calculate recursive task estimation including all subtasks
-- and modifies the get_task_form_view_model function to include this data
BEGIN;
-- Function to calculate recursive task estimation (including all subtasks)
CREATE OR REPLACE FUNCTION get_task_recursive_estimation(_task_id UUID) RETURNS JSON
LANGUAGE plpgsql
AS
$$
DECLARE
_result JSON;
_has_subtasks BOOLEAN;
BEGIN
-- First check if this task has any subtasks
SELECT EXISTS(
SELECT 1 FROM tasks
WHERE parent_task_id = _task_id
AND archived = false
) INTO _has_subtasks;
-- If task has subtasks, calculate recursive estimation excluding parent's own estimation
IF _has_subtasks THEN
WITH RECURSIVE task_tree AS (
-- Start with direct subtasks only (exclude the parent task itself)
SELECT
id,
parent_task_id,
COALESCE(total_minutes, 0) as total_minutes,
1 as level -- Start at level 1 (subtasks)
FROM tasks
WHERE parent_task_id = _task_id
AND archived = false
UNION ALL
-- Recursive case: Get all descendant tasks
SELECT
t.id,
t.parent_task_id,
COALESCE(t.total_minutes, 0) as total_minutes,
tt.level + 1 as level
FROM tasks t
INNER JOIN task_tree tt ON t.parent_task_id = tt.id
WHERE t.archived = false
),
task_counts AS (
SELECT
COUNT(*) as sub_tasks_count,
SUM(total_minutes) as subtasks_total_minutes -- Sum all subtask estimations
FROM task_tree
)
SELECT JSON_BUILD_OBJECT(
'sub_tasks_count', COALESCE(tc.sub_tasks_count, 0),
'own_total_minutes', 0, -- Always 0 for parent tasks
'subtasks_total_minutes', COALESCE(tc.subtasks_total_minutes, 0),
'recursive_total_minutes', COALESCE(tc.subtasks_total_minutes, 0), -- Only subtasks total
'recursive_total_hours', FLOOR(COALESCE(tc.subtasks_total_minutes, 0) / 60),
'recursive_remaining_minutes', COALESCE(tc.subtasks_total_minutes, 0) % 60
)
INTO _result
FROM task_counts tc;
ELSE
-- If task has no subtasks, use its own estimation
SELECT JSON_BUILD_OBJECT(
'sub_tasks_count', 0,
'own_total_minutes', COALESCE(total_minutes, 0),
'subtasks_total_minutes', 0,
'recursive_total_minutes', COALESCE(total_minutes, 0), -- Use own estimation
'recursive_total_hours', FLOOR(COALESCE(total_minutes, 0) / 60),
'recursive_remaining_minutes', COALESCE(total_minutes, 0) % 60
)
INTO _result
FROM tasks
WHERE id = _task_id;
END IF;
RETURN COALESCE(_result, JSON_BUILD_OBJECT(
'sub_tasks_count', 0,
'own_total_minutes', 0,
'subtasks_total_minutes', 0,
'recursive_total_minutes', 0,
'recursive_total_hours', 0,
'recursive_remaining_minutes', 0
));
END;
$$;
-- Update the get_task_form_view_model function to include recursive estimation
CREATE OR REPLACE FUNCTION public.get_task_form_view_model(_user_id UUID, _team_id UUID, _task_id UUID, _project_id UUID) RETURNS JSON
LANGUAGE plpgsql
AS
$$
DECLARE
_task JSON;
_priorities JSON;
_projects JSON;
_statuses JSON;
_team_members JSON;
_assignees JSON;
_phases JSON;
BEGIN
-- Select task info
SELECT COALESCE(ROW_TO_JSON(rec), '{}'::JSON)
INTO _task
FROM (WITH RECURSIVE task_hierarchy AS (
-- Base case: Start with the given task
SELECT id,
parent_task_id,
0 AS level
FROM tasks
WHERE id = _task_id
UNION ALL
-- Recursive case: Traverse up to parent tasks
SELECT t.id,
t.parent_task_id,
th.level + 1 AS level
FROM tasks t
INNER JOIN task_hierarchy th ON t.id = th.parent_task_id
WHERE th.parent_task_id IS NOT NULL)
SELECT id,
name,
description,
start_date,
end_date,
done,
total_minutes,
priority_id,
project_id,
created_at,
updated_at,
status_id,
parent_task_id,
sort_order,
(SELECT phase_id FROM task_phase WHERE task_id = tasks.id) AS phase_id,
CONCAT((SELECT key FROM projects WHERE id = tasks.project_id), '-', task_no) AS task_key,
(SELECT start_time
FROM task_timers
WHERE task_id = tasks.id
AND user_id = _user_id) AS timer_start_time,
parent_task_id IS NOT NULL AS is_sub_task,
(SELECT COUNT('*')
FROM tasks
WHERE parent_task_id = tasks.id
AND archived IS FALSE) AS sub_tasks_count,
(SELECT COUNT(*)
FROM tasks_with_status_view tt
WHERE (tt.parent_task_id = tasks.id OR tt.task_id = tasks.id)
AND tt.is_done IS TRUE)
AS completed_count,
(SELECT COUNT(*) FROM task_attachments WHERE task_id = tasks.id) AS attachments_count,
(SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(ROW_TO_JSON(r))), '[]'::JSON)
FROM (SELECT task_labels.label_id AS id,
(SELECT name FROM team_labels WHERE id = task_labels.label_id),
(SELECT color_code FROM team_labels WHERE id = task_labels.label_id)
FROM task_labels
WHERE task_id = tasks.id
ORDER BY name) r) AS labels,
(SELECT color_code
FROM sys_task_status_categories
WHERE id = (SELECT category_id FROM task_statuses WHERE id = tasks.status_id)) AS status_color,
(SELECT COUNT(*) FROM tasks WHERE parent_task_id = _task_id) AS sub_tasks_count,
(SELECT name FROM users WHERE id = tasks.reporter_id) AS reporter,
(SELECT get_task_assignees(tasks.id)) AS assignees,
(SELECT id FROM team_members WHERE user_id = _user_id AND team_id = _team_id) AS team_member_id,
billable,
schedule_id,
progress_value,
weight,
(SELECT MAX(level) FROM task_hierarchy) AS task_level,
(SELECT get_task_recursive_estimation(tasks.id)) AS recursive_estimation
FROM tasks
WHERE id = _task_id) rec;
SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(ROW_TO_JSON(rec))), '[]'::JSON)
INTO _priorities
FROM (SELECT id, name FROM task_priorities ORDER BY value) rec;
SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(ROW_TO_JSON(rec))), '[]'::JSON)
INTO _phases
FROM (SELECT id, name FROM project_phases WHERE project_id = _project_id ORDER BY name) rec;
SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(ROW_TO_JSON(rec))), '[]'::JSON)
INTO _projects
FROM (SELECT id, name
FROM projects
WHERE team_id = _team_id
AND (CASE
WHEN (is_owner(_user_id, _team_id) OR is_admin(_user_id, _team_id) IS TRUE) THEN TRUE
ELSE is_member_of_project(projects.id, _user_id, _team_id) END)
ORDER BY name) rec;
SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(ROW_TO_JSON(rec))), '[]'::JSON)
INTO _statuses
FROM (SELECT id, name FROM task_statuses WHERE project_id = _project_id) rec;
SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(ROW_TO_JSON(rec))), '[]'::JSON)
INTO _team_members
FROM (SELECT team_members.id,
(SELECT name FROM team_member_info_view WHERE team_member_info_view.team_member_id = team_members.id),
(SELECT email FROM team_member_info_view WHERE team_member_info_view.team_member_id = team_members.id),
(SELECT avatar_url
FROM team_member_info_view
WHERE team_member_info_view.team_member_id = team_members.id)
FROM team_members
LEFT JOIN users u ON team_members.user_id = u.id
WHERE team_id = _team_id
AND team_members.active IS TRUE) rec;
SELECT get_task_assignees(_task_id) INTO _assignees;
RETURN JSON_BUILD_OBJECT(
'task', _task,
'priorities', _priorities,
'projects', _projects,
'statuses', _statuses,
'team_members', _team_members,
'assignees', _assignees,
'phases', _phases
);
END;
$$;
COMMIT;

View File

@@ -603,7 +603,8 @@ BEGIN
schedule_id,
progress_value,
weight,
(SELECT MAX(level) FROM task_hierarchy) AS task_level
(SELECT MAX(level) FROM task_hierarchy) AS task_level,
(SELECT get_task_recursive_estimation(tasks.id)) AS recursive_estimation
FROM tasks
WHERE id = _task_id) rec;
@@ -662,6 +663,89 @@ ADD COLUMN IF NOT EXISTS use_manual_progress BOOLEAN DEFAULT FALSE,
ADD COLUMN IF NOT EXISTS use_weighted_progress BOOLEAN DEFAULT FALSE,
ADD COLUMN IF NOT EXISTS use_time_progress BOOLEAN DEFAULT FALSE;
-- Function to calculate recursive task estimation (including all subtasks)
CREATE OR REPLACE FUNCTION get_task_recursive_estimation(_task_id UUID) RETURNS JSON
LANGUAGE plpgsql
AS
$$
DECLARE
_result JSON;
_has_subtasks BOOLEAN;
BEGIN
-- First check if this task has any subtasks
SELECT EXISTS(
SELECT 1 FROM tasks
WHERE parent_task_id = _task_id
AND archived = false
) INTO _has_subtasks;
-- If task has subtasks, calculate recursive estimation excluding parent's own estimation
IF _has_subtasks THEN
WITH RECURSIVE task_tree AS (
-- Start with direct subtasks only (exclude the parent task itself)
SELECT
id,
parent_task_id,
COALESCE(total_minutes, 0) as total_minutes,
1 as level -- Start at level 1 (subtasks)
FROM tasks
WHERE parent_task_id = _task_id
AND archived = false
UNION ALL
-- Recursive case: Get all descendant tasks
SELECT
t.id,
t.parent_task_id,
COALESCE(t.total_minutes, 0) as total_minutes,
tt.level + 1 as level
FROM tasks t
INNER JOIN task_tree tt ON t.parent_task_id = tt.id
WHERE t.archived = false
),
task_counts AS (
SELECT
COUNT(*) as sub_tasks_count,
SUM(total_minutes) as subtasks_total_minutes -- Sum all subtask estimations
FROM task_tree
)
SELECT JSON_BUILD_OBJECT(
'sub_tasks_count', COALESCE(tc.sub_tasks_count, 0),
'own_total_minutes', 0, -- Always 0 for parent tasks
'subtasks_total_minutes', COALESCE(tc.subtasks_total_minutes, 0),
'recursive_total_minutes', COALESCE(tc.subtasks_total_minutes, 0), -- Only subtasks total
'recursive_total_hours', FLOOR(COALESCE(tc.subtasks_total_minutes, 0) / 60),
'recursive_remaining_minutes', COALESCE(tc.subtasks_total_minutes, 0) % 60
)
INTO _result
FROM task_counts tc;
ELSE
-- If task has no subtasks, use its own estimation
SELECT JSON_BUILD_OBJECT(
'sub_tasks_count', 0,
'own_total_minutes', COALESCE(total_minutes, 0),
'subtasks_total_minutes', 0,
'recursive_total_minutes', COALESCE(total_minutes, 0), -- Use own estimation
'recursive_total_hours', FLOOR(COALESCE(total_minutes, 0) / 60),
'recursive_remaining_minutes', COALESCE(total_minutes, 0) % 60
)
INTO _result
FROM tasks
WHERE id = _task_id;
END IF;
RETURN COALESCE(_result, JSON_BUILD_OBJECT(
'sub_tasks_count', 0,
'own_total_minutes', 0,
'subtasks_total_minutes', 0,
'recursive_total_minutes', 0,
'recursive_total_hours', 0,
'recursive_remaining_minutes', 0
));
END;
$$;
-- Add a trigger to reset manual progress when a task gets a new subtask
CREATE OR REPLACE FUNCTION reset_parent_task_manual_progress() RETURNS TRIGGER AS
$$
@@ -677,6 +761,22 @@ BEGIN
END;
$$ LANGUAGE plpgsql;
-- Add a trigger to reset parent task estimation when it gets subtasks
CREATE OR REPLACE FUNCTION reset_parent_task_estimation() RETURNS TRIGGER AS
$$
BEGIN
-- When a task gets a new subtask (parent_task_id is set), reset the parent's total_minutes to 0
-- This ensures parent tasks don't have their own estimation when they have subtasks
IF NEW.parent_task_id IS NOT NULL THEN
UPDATE tasks
SET total_minutes = 0
WHERE id = NEW.parent_task_id
AND total_minutes > 0;
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Create the trigger on the tasks table
DROP TRIGGER IF EXISTS reset_parent_manual_progress_trigger ON tasks;
CREATE TRIGGER reset_parent_manual_progress_trigger
@@ -684,4 +784,35 @@ AFTER INSERT OR UPDATE OF parent_task_id ON tasks
FOR EACH ROW
EXECUTE FUNCTION reset_parent_task_manual_progress();
-- Create the trigger to reset parent task estimation
DROP TRIGGER IF EXISTS reset_parent_estimation_trigger ON tasks;
CREATE TRIGGER reset_parent_estimation_trigger
AFTER INSERT OR UPDATE OF parent_task_id ON tasks
FOR EACH ROW
EXECUTE FUNCTION reset_parent_task_estimation();
-- Function to reset all existing parent tasks' estimations to 0
CREATE OR REPLACE FUNCTION reset_all_parent_task_estimations() RETURNS INTEGER AS
$$
DECLARE
_updated_count INTEGER;
BEGIN
-- Update all tasks that have subtasks to have 0 estimation
UPDATE tasks
SET total_minutes = 0
WHERE id IN (
SELECT DISTINCT parent_task_id
FROM tasks
WHERE parent_task_id IS NOT NULL
AND archived = false
)
AND total_minutes > 0
AND archived = false;
GET DIAGNOSTICS _updated_count = ROW_COUNT;
RETURN _updated_count;
END;
$$ LANGUAGE plpgsql;
COMMIT;