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:
@@ -605,9 +605,10 @@ export default class ProjectfinanceController extends WorklenzControllerBase {
|
||||
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 = `
|
||||
WITH task_costs AS (
|
||||
WITH RECURSIVE task_tree AS (
|
||||
-- Get the requested subtasks
|
||||
SELECT
|
||||
t.id,
|
||||
t.name,
|
||||
@@ -621,22 +622,47 @@ export default class ProjectfinanceController extends WorklenzControllerBase {
|
||||
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,
|
||||
(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
|
||||
WHERE t.project_id = $1
|
||||
AND t.archived = false
|
||||
AND t.parent_task_id = $2
|
||||
${billableCondition}
|
||||
),
|
||||
task_estimated_costs AS (
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- Get all descendant tasks for aggregation
|
||||
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
|
||||
COALESCE((
|
||||
SELECT SUM((tc.estimated_seconds / 3600.0) * COALESCE(fprr.rate, 0))
|
||||
FROM json_array_elements(tc.assignees) AS assignee_json
|
||||
SELECT SUM((tt.estimated_seconds / 3600.0) * COALESCE(fprr.rate, 0))
|
||||
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
|
||||
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
|
||||
WHERE assignee_json->>'team_member_id' IS NOT NULL
|
||||
), 0) as estimated_cost,
|
||||
@@ -646,18 +672,66 @@ export default class ProjectfinanceController extends WorklenzControllerBase {
|
||||
FROM task_work_log twl
|
||||
LEFT JOIN users u ON twl.user_id = u.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
|
||||
WHERE twl.task_id = tc.id
|
||||
WHERE twl.task_id = tt.id
|
||||
), 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
|
||||
WHERE tc.level = 0 -- Only return the requested level (subtasks)
|
||||
)
|
||||
SELECT
|
||||
tec.*,
|
||||
(tec.estimated_cost + tec.fixed_cost) as total_budget,
|
||||
(tec.actual_cost_from_logs + tec.fixed_cost) as total_actual,
|
||||
((tec.actual_cost_from_logs + tec.fixed_cost) - (tec.estimated_cost + tec.fixed_cost)) as variance
|
||||
FROM task_estimated_costs tec;
|
||||
at.*,
|
||||
(at.estimated_cost + at.fixed_cost) as total_budget,
|
||||
(at.actual_cost_from_logs + at.fixed_cost) as total_actual,
|
||||
((at.actual_cost_from_logs + at.fixed_cost) - (at.estimated_cost + at.fixed_cost)) as variance
|
||||
FROM aggregated_tasks at;
|
||||
`;
|
||||
|
||||
const result = await db.query(q, [projectId, parentTaskId]);
|
||||
|
||||
@@ -50,14 +50,17 @@ export default class TasksControllerBase extends WorklenzControllerBase {
|
||||
task.progress = 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 {
|
||||
task.progress = task.total_minutes_spent && task.total_minutes
|
||||
? ~~(task.total_minutes_spent / task.total_minutes * 100)
|
||||
: 0;
|
||||
|
||||
// Set complete_ratio to match progress
|
||||
task.complete_ratio = task.progress;
|
||||
// Only calculate time-based progress if time-based calculation is enabled for the project
|
||||
if (task.project_use_time_progress && task.total_minutes_spent && task.total_minutes) {
|
||||
task.progress = ~~(task.total_minutes_spent / task.total_minutes * 100);
|
||||
task.complete_ratio = task.progress;
|
||||
} else {
|
||||
// Default to 0% progress for incomplete tasks when time-based calculation is not enabled
|
||||
task.progress = 0;
|
||||
task.complete_ratio = 0;
|
||||
}
|
||||
}
|
||||
|
||||
// Ensure numeric values
|
||||
@@ -76,7 +79,31 @@ export default class TasksControllerBase extends WorklenzControllerBase {
|
||||
task.is_sub_task = !!task.parent_task_id;
|
||||
|
||||
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.priority_color = PriorityColorCodes[task.priority_value] || PriorityColorCodes["0"];
|
||||
|
||||
@@ -258,6 +258,7 @@ export default class TasksControllerV2 extends TasksControllerBase {
|
||||
(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,
|
||||
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,
|
||||
created_at,
|
||||
updated_at,
|
||||
|
||||
@@ -427,9 +427,24 @@ export default class TasksController extends TasksControllerBase {
|
||||
|
||||
task.names = WorklenzControllerBase.createTagList(task.assignees);
|
||||
|
||||
const totalMinutes = task.total_minutes;
|
||||
const hours = Math.floor(totalMinutes / 60);
|
||||
const minutes = totalMinutes % 60;
|
||||
// Use recursive estimation if task has subtasks, otherwise use own estimation
|
||||
const recursiveEstimation = task.recursive_estimation || {};
|
||||
// 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_minutes = minutes;
|
||||
@@ -608,6 +623,18 @@ export default class TasksController extends TasksControllerBase {
|
||||
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()
|
||||
public static async bulkAssignMembers(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
|
||||
const { tasks, members, project_id } = req.body;
|
||||
|
||||
@@ -69,4 +69,7 @@ tasksApiRouter.put("/labels/:id", idParamValidator, safeControllerFunction(Tasks
|
||||
// Add custom column value update route
|
||||
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;
|
||||
|
||||
Reference in New Issue
Block a user