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, schedule_id,
progress_value, progress_value,
weight, 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 FROM tasks
WHERE id = _task_id) rec; 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_weighted_progress BOOLEAN DEFAULT FALSE,
ADD COLUMN IF NOT EXISTS use_time_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 -- 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 CREATE OR REPLACE FUNCTION reset_parent_task_manual_progress() RETURNS TRIGGER AS
$$ $$
@@ -677,6 +761,22 @@ BEGIN
END; END;
$$ LANGUAGE plpgsql; $$ 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 -- Create the trigger on the tasks table
DROP TRIGGER IF EXISTS reset_parent_manual_progress_trigger ON tasks; DROP TRIGGER IF EXISTS reset_parent_manual_progress_trigger ON tasks;
CREATE TRIGGER reset_parent_manual_progress_trigger CREATE TRIGGER reset_parent_manual_progress_trigger
@@ -684,4 +784,35 @@ AFTER INSERT OR UPDATE OF parent_task_id ON tasks
FOR EACH ROW FOR EACH ROW
EXECUTE FUNCTION reset_parent_task_manual_progress(); 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; COMMIT;

View File

@@ -0,0 +1,77 @@
-- Fix task hierarchy and reset parent estimations
-- This script ensures proper parent-child relationships and resets parent estimations
-- First, let's see the current task hierarchy
SELECT
t.id,
t.name,
t.parent_task_id,
t.total_minutes,
(SELECT name FROM tasks WHERE id = t.parent_task_id) as parent_name,
(SELECT COUNT(*) FROM tasks WHERE parent_task_id = t.id AND archived = false) as actual_subtask_count,
t.archived
FROM tasks t
WHERE (t.name LIKE '%sub%' OR t.name LIKE '%test task%')
ORDER BY t.name, t.created_at;
-- Reset all parent task estimations to 0
-- This ensures parent tasks don't have their own estimation when they have subtasks
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 archived = false;
-- Verify the results after the update
SELECT
t.id,
t.name,
t.parent_task_id,
t.total_minutes as current_estimation,
(SELECT name FROM tasks WHERE id = t.parent_task_id) as parent_name,
(SELECT COUNT(*) FROM tasks WHERE parent_task_id = t.id AND archived = false) as subtask_count,
get_task_recursive_estimation(t.id) as recursive_estimation
FROM tasks t
WHERE (t.name LIKE '%sub%' OR t.name LIKE '%test task%')
AND t.archived = false
ORDER BY t.name;
-- Show the hierarchy in tree format
WITH RECURSIVE task_hierarchy AS (
-- Top level tasks (no parent)
SELECT
id,
name,
parent_task_id,
total_minutes,
0 as level,
name as path
FROM tasks
WHERE parent_task_id IS NULL
AND (name LIKE '%sub%' OR name LIKE '%test task%')
AND archived = false
UNION ALL
-- Child tasks
SELECT
t.id,
t.name,
t.parent_task_id,
t.total_minutes,
th.level + 1,
th.path || ' > ' || t.name
FROM tasks t
INNER JOIN task_hierarchy th ON t.parent_task_id = th.id
WHERE t.archived = false
)
SELECT
REPEAT(' ', level) || name as indented_name,
total_minutes,
get_task_recursive_estimation(id) as recursive_estimation
FROM task_hierarchy
ORDER BY path;

View File

@@ -0,0 +1,29 @@
-- Reset all existing parent task estimations to 0
-- This script updates 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;
-- Show the results
SELECT
t.id,
t.name,
t.total_minutes as current_estimation,
(SELECT COUNT(*) FROM tasks WHERE parent_task_id = t.id AND archived = false) as subtask_count
FROM tasks t
WHERE id IN (
SELECT DISTINCT parent_task_id
FROM tasks
WHERE parent_task_id IS NOT NULL
AND archived = false
)
AND archived = false
ORDER BY t.name;

View File

@@ -605,9 +605,10 @@ export default class ProjectfinanceController extends WorklenzControllerBase {
billableCondition = "AND t.billable = false"; billableCondition = "AND t.billable = false";
} }
// Get subtasks with their financial data // Get subtasks with their financial data, including recursive aggregation for sub-subtasks
const q = ` const q = `
WITH task_costs AS ( WITH RECURSIVE task_tree AS (
-- Get the requested subtasks
SELECT SELECT
t.id, t.id,
t.name, t.name,
@@ -621,22 +622,47 @@ export default class ProjectfinanceController extends WorklenzControllerBase {
COALESCE(t.fixed_cost, 0) as fixed_cost, COALESCE(t.fixed_cost, 0) as fixed_cost,
COALESCE(t.total_minutes * 60, 0) as estimated_seconds, COALESCE(t.total_minutes * 60, 0) as estimated_seconds,
COALESCE((SELECT SUM(time_spent) FROM task_work_log WHERE task_id = t.id), 0) as total_time_logged_seconds, COALESCE((SELECT SUM(time_spent) FROM task_work_log WHERE task_id = t.id), 0) as total_time_logged_seconds,
(SELECT COUNT(*) FROM tasks WHERE parent_task_id = t.id AND archived = false) as sub_tasks_count (SELECT COUNT(*) FROM tasks WHERE parent_task_id = t.id AND archived = false) as sub_tasks_count,
0 as level,
t.id as root_id
FROM tasks t FROM tasks t
WHERE t.project_id = $1 WHERE t.project_id = $1
AND t.archived = false AND t.archived = false
AND t.parent_task_id = $2 AND t.parent_task_id = $2
${billableCondition} ${billableCondition}
),
task_estimated_costs AS ( UNION ALL
-- Get all descendant tasks for aggregation
SELECT SELECT
tc.*, t.id,
t.name,
t.parent_task_id,
t.project_id,
t.status_id,
t.priority_id,
(SELECT phase_id FROM task_phase WHERE task_id = t.id) as phase_id,
(SELECT get_task_assignees(t.id)) as assignees,
t.billable,
COALESCE(t.fixed_cost, 0) as fixed_cost,
COALESCE(t.total_minutes * 60, 0) as estimated_seconds,
COALESCE((SELECT SUM(time_spent) FROM task_work_log WHERE task_id = t.id), 0) as total_time_logged_seconds,
0 as sub_tasks_count,
tt.level + 1 as level,
tt.root_id
FROM tasks t
INNER JOIN task_tree tt ON t.parent_task_id = tt.id
WHERE t.archived = false
),
task_costs AS (
SELECT
tt.*,
-- Calculate estimated cost based on estimated hours and assignee rates -- Calculate estimated cost based on estimated hours and assignee rates
COALESCE(( COALESCE((
SELECT SUM((tc.estimated_seconds / 3600.0) * COALESCE(fprr.rate, 0)) SELECT SUM((tt.estimated_seconds / 3600.0) * COALESCE(fprr.rate, 0))
FROM json_array_elements(tc.assignees) AS assignee_json FROM json_array_elements(tt.assignees) AS assignee_json
LEFT JOIN project_members pm ON pm.team_member_id = (assignee_json->>'team_member_id')::uuid LEFT JOIN project_members pm ON pm.team_member_id = (assignee_json->>'team_member_id')::uuid
AND pm.project_id = tc.project_id AND pm.project_id = tt.project_id
LEFT JOIN finance_project_rate_card_roles fprr ON fprr.id = pm.project_rate_card_role_id LEFT JOIN finance_project_rate_card_roles fprr ON fprr.id = pm.project_rate_card_role_id
WHERE assignee_json->>'team_member_id' IS NOT NULL WHERE assignee_json->>'team_member_id' IS NOT NULL
), 0) as estimated_cost, ), 0) as estimated_cost,
@@ -646,18 +672,66 @@ export default class ProjectfinanceController extends WorklenzControllerBase {
FROM task_work_log twl FROM task_work_log twl
LEFT JOIN users u ON twl.user_id = u.id LEFT JOIN users u ON twl.user_id = u.id
LEFT JOIN team_members tm ON u.id = tm.user_id LEFT JOIN team_members tm ON u.id = tm.user_id
LEFT JOIN project_members pm ON pm.team_member_id = tm.id AND pm.project_id = tc.project_id LEFT JOIN project_members pm ON pm.team_member_id = tm.id AND pm.project_id = tt.project_id
LEFT JOIN finance_project_rate_card_roles fprr ON fprr.id = pm.project_rate_card_role_id LEFT JOIN finance_project_rate_card_roles fprr ON fprr.id = pm.project_rate_card_role_id
WHERE twl.task_id = tc.id WHERE twl.task_id = tt.id
), 0) as actual_cost_from_logs ), 0) as actual_cost_from_logs
FROM task_tree tt
),
aggregated_tasks AS (
SELECT
tc.id,
tc.name,
tc.parent_task_id,
tc.status_id,
tc.priority_id,
tc.phase_id,
tc.assignees,
tc.billable,
tc.fixed_cost,
tc.sub_tasks_count,
-- For subtasks that have their own sub-subtasks, sum values from descendants only
CASE
WHEN tc.level = 0 AND tc.sub_tasks_count > 0 THEN (
SELECT SUM(sub_tc.estimated_seconds)
FROM task_costs sub_tc
WHERE sub_tc.root_id = tc.id AND sub_tc.id != tc.id
)
ELSE tc.estimated_seconds
END as estimated_seconds,
CASE
WHEN tc.level = 0 AND tc.sub_tasks_count > 0 THEN (
SELECT SUM(sub_tc.total_time_logged_seconds)
FROM task_costs sub_tc
WHERE sub_tc.root_id = tc.id AND sub_tc.id != tc.id
)
ELSE tc.total_time_logged_seconds
END as total_time_logged_seconds,
CASE
WHEN tc.level = 0 AND tc.sub_tasks_count > 0 THEN (
SELECT SUM(sub_tc.estimated_cost)
FROM task_costs sub_tc
WHERE sub_tc.root_id = tc.id AND sub_tc.id != tc.id
)
ELSE tc.estimated_cost
END as estimated_cost,
CASE
WHEN tc.level = 0 AND tc.sub_tasks_count > 0 THEN (
SELECT SUM(sub_tc.actual_cost_from_logs)
FROM task_costs sub_tc
WHERE sub_tc.root_id = tc.id AND sub_tc.id != tc.id
)
ELSE tc.actual_cost_from_logs
END as actual_cost_from_logs
FROM task_costs tc FROM task_costs tc
WHERE tc.level = 0 -- Only return the requested level (subtasks)
) )
SELECT SELECT
tec.*, at.*,
(tec.estimated_cost + tec.fixed_cost) as total_budget, (at.estimated_cost + at.fixed_cost) as total_budget,
(tec.actual_cost_from_logs + tec.fixed_cost) as total_actual, (at.actual_cost_from_logs + at.fixed_cost) as total_actual,
((tec.actual_cost_from_logs + tec.fixed_cost) - (tec.estimated_cost + tec.fixed_cost)) as variance ((at.actual_cost_from_logs + at.fixed_cost) - (at.estimated_cost + at.fixed_cost)) as variance
FROM task_estimated_costs tec; FROM aggregated_tasks at;
`; `;
const result = await db.query(q, [projectId, parentTaskId]); const result = await db.query(q, [projectId, parentTaskId]);

View File

@@ -50,14 +50,17 @@ export default class TasksControllerBase extends WorklenzControllerBase {
task.progress = parseInt(task.progress_value); task.progress = parseInt(task.progress_value);
task.complete_ratio = parseInt(task.progress_value); task.complete_ratio = parseInt(task.progress_value);
} }
// For tasks with no subtasks and no manual progress, calculate based on time // For tasks with no subtasks and no manual progress
else { else {
task.progress = task.total_minutes_spent && task.total_minutes // Only calculate time-based progress if time-based calculation is enabled for the project
? ~~(task.total_minutes_spent / task.total_minutes * 100) if (task.project_use_time_progress && task.total_minutes_spent && task.total_minutes) {
: 0; task.progress = ~~(task.total_minutes_spent / task.total_minutes * 100);
task.complete_ratio = task.progress;
// Set complete_ratio to match progress } else {
task.complete_ratio = task.progress; // Default to 0% progress for incomplete tasks when time-based calculation is not enabled
task.progress = 0;
task.complete_ratio = 0;
}
} }
// Ensure numeric values // Ensure numeric values
@@ -76,7 +79,31 @@ export default class TasksControllerBase extends WorklenzControllerBase {
task.is_sub_task = !!task.parent_task_id; task.is_sub_task = !!task.parent_task_id;
task.time_spent_string = `${task.time_spent.hours}h ${(task.time_spent.minutes)}m`; task.time_spent_string = `${task.time_spent.hours}h ${(task.time_spent.minutes)}m`;
task.total_time_string = `${~~(task.total_minutes / 60)}h ${(task.total_minutes % 60)}m`;
// Use recursive estimation for parent tasks, own estimation for leaf tasks
const recursiveEstimation = task.recursive_estimation || {};
const hasSubtasks = (task.sub_tasks_count || 0) > 0;
let displayMinutes;
if (hasSubtasks) {
// For parent tasks, use recursive estimation (sum of all subtasks)
displayMinutes = recursiveEstimation.recursive_total_minutes || 0;
} else {
// For leaf tasks, use their own estimation
displayMinutes = task.total_minutes || 0;
}
// Format time string - show "0h" for zero time instead of "0h 0m"
const hours = ~~(displayMinutes / 60);
const minutes = displayMinutes % 60;
if (displayMinutes === 0) {
task.total_time_string = "0h";
} else if (minutes === 0) {
task.total_time_string = `${hours}h`;
} else {
task.total_time_string = `${hours}h ${minutes}m`;
}
task.name_color = getColor(task.name); task.name_color = getColor(task.name);
task.priority_color = PriorityColorCodes[task.priority_value] || PriorityColorCodes["0"]; task.priority_color = PriorityColorCodes[task.priority_value] || PriorityColorCodes["0"];

View File

@@ -258,6 +258,7 @@ export default class TasksControllerV2 extends TasksControllerBase {
(SELECT id FROM task_priorities WHERE id = t.priority_id) AS priority, (SELECT id FROM task_priorities WHERE id = t.priority_id) AS priority,
(SELECT value FROM task_priorities WHERE id = t.priority_id) AS priority_value, (SELECT value FROM task_priorities WHERE id = t.priority_id) AS priority_value,
total_minutes, total_minutes,
(SELECT get_task_recursive_estimation(t.id)) AS recursive_estimation,
(SELECT SUM(time_spent) FROM task_work_log WHERE task_id = t.id) AS total_minutes_spent, (SELECT SUM(time_spent) FROM task_work_log WHERE task_id = t.id) AS total_minutes_spent,
created_at, created_at,
updated_at, updated_at,

View File

@@ -427,9 +427,24 @@ export default class TasksController extends TasksControllerBase {
task.names = WorklenzControllerBase.createTagList(task.assignees); task.names = WorklenzControllerBase.createTagList(task.assignees);
const totalMinutes = task.total_minutes; // Use recursive estimation if task has subtasks, otherwise use own estimation
const hours = Math.floor(totalMinutes / 60); const recursiveEstimation = task.recursive_estimation || {};
const minutes = totalMinutes % 60; // Check both the recursive estimation count and the actual database count
const hasSubtasks = (task.sub_tasks_count || 0) > 0;
let totalMinutes, hours, minutes;
if (hasSubtasks) {
// For parent tasks, use the sum of all subtasks' estimation (excluding parent's own estimation)
totalMinutes = recursiveEstimation.recursive_total_minutes || 0;
hours = recursiveEstimation.recursive_total_hours || 0;
minutes = recursiveEstimation.recursive_remaining_minutes || 0;
} else {
// For tasks without subtasks, use their own estimation
totalMinutes = task.total_minutes || 0;
hours = Math.floor(totalMinutes / 60);
minutes = totalMinutes % 60;
}
task.total_hours = hours; task.total_hours = hours;
task.total_minutes = minutes; task.total_minutes = minutes;
@@ -608,6 +623,18 @@ export default class TasksController extends TasksControllerBase {
return res.status(200).send(new ServerResponse(true, null)); return res.status(200).send(new ServerResponse(true, null));
} }
@HandleExceptions()
public static async resetParentTaskEstimations(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
const q = `SELECT reset_all_parent_task_estimations() AS updated_count;`;
const result = await db.query(q);
const [data] = result.rows;
return res.status(200).send(new ServerResponse(true, {
message: `Reset estimation for ${data.updated_count} parent tasks`,
updated_count: data.updated_count
}));
}
@HandleExceptions() @HandleExceptions()
public static async bulkAssignMembers(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> { public static async bulkAssignMembers(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
const { tasks, members, project_id } = req.body; const { tasks, members, project_id } = req.body;

View File

@@ -69,4 +69,7 @@ tasksApiRouter.put("/labels/:id", idParamValidator, safeControllerFunction(Tasks
// Add custom column value update route // Add custom column value update route
tasksApiRouter.put("/:taskId/custom-column", TasksControllerV2.updateCustomColumnValue); tasksApiRouter.put("/:taskId/custom-column", TasksControllerV2.updateCustomColumnValue);
// Add route to reset parent task estimations
tasksApiRouter.post("/reset-parent-estimations", safeControllerFunction(TasksController.resetParentTaskEstimations));
export default tasksApiRouter; export default tasksApiRouter;

View File

@@ -82,14 +82,9 @@ const TaskDetailsForm = ({ taskFormViewModel = null, subTasks = [] }: TaskDetail
const [form] = Form.useForm(); const [form] = Form.useForm();
const { project } = useAppSelector(state => state.projectReducer); const { project } = useAppSelector(state => state.projectReducer);
// Calculate sum of subtasks estimation // No need to calculate subtask estimation on frontend anymore
const subTasksEstimation = subTasks.reduce( // The backend now provides recursive estimation directly in the task data
(acc, subTask) => ({ const subTasksEstimation: { hours: number; minutes: number } | undefined = undefined;
hours: acc.hours + (subTask.total_hours || 0),
minutes: acc.minutes + (subTask.total_minutes || 0)
}),
{ hours: 0, minutes: 0 }
);
useEffect(() => { useEffect(() => {
if (!taskFormViewModel) { if (!taskFormViewModel) {

View File

@@ -43,9 +43,11 @@ const FinanceDrawer = () => {
const themeMode = useAppSelector((state) => state.themeReducer.mode); const themeMode = useAppSelector((state) => state.themeReducer.mode);
const dispatch = useAppDispatch(); const dispatch = useAppDispatch();
const currency = useAppSelector(
(state) => state.financeReducer.currency // Get project currency from project finances, fallback to finance reducer currency
).toUpperCase(); const projectCurrency = useAppSelector((state) => state.projectFinances.project?.currency);
const fallbackCurrency = useAppSelector((state) => state.financeReducer.currency);
const currency = (projectCurrency || fallbackCurrency || 'USD').toUpperCase();
// function handle drawer close // function handle drawer close
const handleClose = () => { const handleClose = () => {

View File

@@ -22,9 +22,10 @@ const ImportRatecardsDrawer: React.FC = () => {
const isDrawerOpen = useAppSelector( const isDrawerOpen = useAppSelector(
(state) => state.financeReducer.isImportRatecardsDrawerOpen (state) => state.financeReducer.isImportRatecardsDrawerOpen
); );
const currency = useAppSelector( // Get project currency from project finances, fallback to finance reducer currency
(state) => state.financeReducer.currency const projectCurrency = useAppSelector((state) => state.projectFinances.project?.currency);
).toUpperCase(); const fallbackCurrency = useAppSelector((state) => state.financeReducer.currency);
const currency = (projectCurrency || fallbackCurrency || 'USD').toUpperCase();
const rolesRedux = useAppSelector((state) => state.projectFinanceRateCard.rateCardRoles) || []; const rolesRedux = useAppSelector((state) => state.projectFinanceRateCard.rateCardRoles) || [];