feat(project-finance): enhance project finance view and calculations
- Added a new SQL view `project_finance_view` to aggregate project financial data. - Updated `project-finance-controller.ts` to fetch and group tasks by status, priority, or phases, including financial calculations for estimated costs, actual costs, and variances. - Enhanced frontend components to display total time logged, estimated costs, and fixed costs in the finance table. - Introduced new utility functions for formatting hours and calculating totals. - Updated localization files to include new financial columns in English, Spanish, and Portuguese. - Implemented Redux slice for managing project finance state and actions for updating task costs.
This commit is contained in:
@@ -6372,3 +6372,44 @@ BEGIN
|
||||
);
|
||||
END;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE VIEW project_finance_view AS
|
||||
SELECT
|
||||
t.id,
|
||||
t.name,
|
||||
t.total_minutes / 3600.0 as estimated_hours,
|
||||
COALESCE((SELECT SUM(time_spent) FROM task_work_log WHERE task_id = t.id), 0) / 3600.0 as total_time_logged,
|
||||
COALESCE((SELECT SUM(rate * (time_spent / 3600.0))
|
||||
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 tm.id = pm.team_member_id
|
||||
LEFT JOIN finance_project_rate_card_roles pmr ON pm.project_rate_card_role_id = pmr.id
|
||||
WHERE twl.task_id = t.id), 0) as estimated_cost,
|
||||
0 as fixed_cost, -- Default to 0 since the column doesn't exist
|
||||
COALESCE(t.total_minutes / 3600.0 *
|
||||
(SELECT rate FROM finance_project_rate_card_roles
|
||||
WHERE project_id = t.project_id
|
||||
AND id = (SELECT project_rate_card_role_id FROM project_members WHERE team_member_id = t.reporter_id LIMIT 1)
|
||||
LIMIT 1), 0) as total_budgeted_cost,
|
||||
COALESCE((SELECT SUM(rate * (time_spent / 3600.0))
|
||||
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 tm.id = pm.team_member_id
|
||||
LEFT JOIN finance_project_rate_card_roles pmr ON pm.project_rate_card_role_id = pmr.id
|
||||
WHERE twl.task_id = t.id), 0) as total_actual_cost,
|
||||
COALESCE((SELECT SUM(rate * (time_spent / 3600.0))
|
||||
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 tm.id = pm.team_member_id
|
||||
LEFT JOIN finance_project_rate_card_roles pmr ON pm.project_rate_card_role_id = pmr.id
|
||||
WHERE twl.task_id = t.id), 0) -
|
||||
COALESCE(t.total_minutes / 3600.0 *
|
||||
(SELECT rate FROM finance_project_rate_card_roles
|
||||
WHERE project_id = t.project_id
|
||||
AND id = (SELECT project_rate_card_role_id FROM project_members WHERE team_member_id = t.reporter_id LIMIT 1)
|
||||
LIMIT 1), 0) as variance,
|
||||
t.project_id
|
||||
FROM tasks t;
|
||||
|
||||
@@ -5,6 +5,8 @@ import db from "../config/db";
|
||||
import { ServerResponse } from "../models/server-response";
|
||||
import WorklenzControllerBase from "./worklenz-controller-base";
|
||||
import HandleExceptions from "../decorators/handle-exceptions";
|
||||
import { TASK_STATUS_COLOR_ALPHA } from "../shared/constants";
|
||||
import { getColor } from "../shared/utils";
|
||||
|
||||
export default class ProjectfinanceController extends WorklenzControllerBase {
|
||||
@HandleExceptions()
|
||||
@@ -12,124 +14,143 @@ export default class ProjectfinanceController extends WorklenzControllerBase {
|
||||
req: IWorkLenzRequest,
|
||||
res: IWorkLenzResponse
|
||||
): Promise<IWorkLenzResponse> {
|
||||
const { project_id } = req.params;
|
||||
const { group_by = "status" } = req.query;
|
||||
const projectId = req.params.project_id;
|
||||
const groupBy = req.query.group || "status";
|
||||
|
||||
// Get all tasks with their financial data
|
||||
const q = `
|
||||
WITH task_data AS (
|
||||
WITH task_costs AS (
|
||||
SELECT
|
||||
t.id,
|
||||
t.name,
|
||||
COALESCE(t.total_minutes, 0)::float as estimated_hours,
|
||||
COALESCE((SELECT SUM(time_spent) FROM task_work_log WHERE task_id = t.id), 0) / 3600.0::float as total_time_logged,
|
||||
COALESCE((SELECT SUM(rate * (time_spent / 3600.0))
|
||||
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 tm.id = pm.team_member_id
|
||||
LEFT JOIN finance_project_rate_card_roles pmr ON pm.project_rate_card_role_id = pmr.id
|
||||
WHERE twl.task_id = t.id), 0)::float as estimated_cost,
|
||||
COALESCE(t.fixed_cost, 0)::float as fixed_cost,
|
||||
t.project_id,
|
||||
t.status_id,
|
||||
t.priority_id,
|
||||
tp.phase_id,
|
||||
(t.total_minutes / 3600.0) as estimated_hours,
|
||||
(COALESCE((SELECT SUM(time_spent) FROM task_work_log WHERE task_id = t.id), 0) / 3600.0) as actual_hours,
|
||||
t.completed_at,
|
||||
t.created_at,
|
||||
t.updated_at,
|
||||
t.billable,
|
||||
s.name as status_name,
|
||||
p.name as priority_name,
|
||||
ph.name as phase_name,
|
||||
(SELECT color_code FROM sys_task_status_categories WHERE id = s.category_id) as status_color,
|
||||
(SELECT color_code_dark FROM sys_task_status_categories WHERE id = s.category_id) as status_color_dark,
|
||||
(SELECT color_code FROM task_priorities WHERE id = t.priority_id) as priority_color,
|
||||
(SELECT color_code FROM project_phases WHERE id = tp.phase_id) as phase_color,
|
||||
(SELECT phase_id FROM task_phase WHERE task_id = t.id) as phase_id,
|
||||
(SELECT get_task_assignees(t.id)) as assignees,
|
||||
json_agg(
|
||||
json_build_object(
|
||||
'name', u.name,
|
||||
'avatar_url', u.avatar_url,
|
||||
'team_member_id', tm.id,
|
||||
'color_code', '#1890ff'
|
||||
)
|
||||
) FILTER (WHERE u.id IS NOT NULL) as members
|
||||
t.billable
|
||||
FROM tasks t
|
||||
LEFT JOIN task_statuses s ON t.status_id = s.id
|
||||
LEFT JOIN task_priorities p ON t.priority_id = p.id
|
||||
LEFT JOIN task_phase tp ON t.id = tp.task_id
|
||||
LEFT JOIN project_phases ph ON tp.phase_id = ph.id
|
||||
LEFT JOIN tasks_assignees ta ON t.id = ta.task_id
|
||||
LEFT JOIN project_members pm ON ta.project_member_id = pm.id
|
||||
LEFT JOIN team_members tm ON pm.team_member_id = tm.id
|
||||
LEFT JOIN finance_project_rate_card_roles pmr ON pm.project_rate_card_role_id = pmr.id
|
||||
LEFT JOIN users u ON tm.user_id = u.id
|
||||
LEFT JOIN job_titles jt ON tm.job_title_id = jt.id
|
||||
WHERE t.project_id = $1
|
||||
GROUP BY
|
||||
t.id,
|
||||
s.name,
|
||||
p.name,
|
||||
ph.name,
|
||||
tp.phase_id,
|
||||
s.category_id,
|
||||
t.priority_id
|
||||
WHERE t.project_id = $1 AND t.archived = false
|
||||
)
|
||||
SELECT
|
||||
CASE
|
||||
WHEN $2 = 'status' THEN status_id
|
||||
WHEN $2 = 'priority' THEN priority_id
|
||||
WHEN $2 = 'phases' THEN phase_id
|
||||
END as group_id,
|
||||
CASE
|
||||
WHEN $2 = 'status' THEN status_name
|
||||
WHEN $2 = 'priority' THEN priority_name
|
||||
WHEN $2 = 'phases' THEN phase_name
|
||||
END as group_name,
|
||||
CASE
|
||||
WHEN $2 = 'status' THEN status_color
|
||||
WHEN $2 = 'priority' THEN priority_color
|
||||
WHEN $2 = 'phases' THEN phase_color
|
||||
END as color_code,
|
||||
CASE
|
||||
WHEN $2 = 'status' THEN status_color_dark
|
||||
WHEN $2 = 'priority' THEN priority_color
|
||||
WHEN $2 = 'phases' THEN phase_color
|
||||
END as color_code_dark,
|
||||
json_agg(
|
||||
json_build_object(
|
||||
'id', id,
|
||||
'name', name,
|
||||
'status_id', status_id,
|
||||
'priority_id', priority_id,
|
||||
'phase_id', phase_id,
|
||||
'estimated_hours', estimated_hours,
|
||||
'actual_hours', actual_hours,
|
||||
'completed_at', completed_at,
|
||||
'created_at', created_at,
|
||||
'updated_at', updated_at,
|
||||
'billable', billable,
|
||||
'assignees', assignees,
|
||||
'members', members
|
||||
)
|
||||
) as tasks
|
||||
FROM task_data
|
||||
GROUP BY
|
||||
CASE
|
||||
WHEN $2 = 'status' THEN status_id
|
||||
WHEN $2 = 'priority' THEN priority_id
|
||||
WHEN $2 = 'phases' THEN phase_id
|
||||
END,
|
||||
CASE
|
||||
WHEN $2 = 'status' THEN status_name
|
||||
WHEN $2 = 'priority' THEN priority_name
|
||||
WHEN $2 = 'phases' THEN phase_name
|
||||
END,
|
||||
CASE
|
||||
WHEN $2 = 'status' THEN status_color
|
||||
WHEN $2 = 'priority' THEN priority_color
|
||||
WHEN $2 = 'phases' THEN phase_color
|
||||
END,
|
||||
CASE
|
||||
WHEN $2 = 'status' THEN status_color_dark
|
||||
WHEN $2 = 'priority' THEN priority_color
|
||||
WHEN $2 = 'phases' THEN phase_color
|
||||
END
|
||||
ORDER BY group_name;
|
||||
tc.*,
|
||||
(tc.estimated_cost + tc.fixed_cost)::float as total_budget,
|
||||
COALESCE((SELECT SUM(rate * (time_spent / 3600.0))
|
||||
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 tm.id = pm.team_member_id
|
||||
LEFT JOIN finance_project_rate_card_roles pmr ON pm.project_rate_card_role_id = pmr.id
|
||||
WHERE twl.task_id = tc.id), 0)::float + tc.fixed_cost as total_actual,
|
||||
(COALESCE((SELECT SUM(rate * (time_spent / 3600.0))
|
||||
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 tm.id = pm.team_member_id
|
||||
LEFT JOIN finance_project_rate_card_roles pmr ON pm.project_rate_card_role_id = pmr.id
|
||||
WHERE twl.task_id = tc.id), 0)::float + tc.fixed_cost) - (tc.estimated_cost + tc.fixed_cost)::float as variance
|
||||
FROM task_costs tc;
|
||||
`;
|
||||
|
||||
const result = await db.query(q, [project_id, group_by]);
|
||||
return res.status(200).send(new ServerResponse(true, result.rows));
|
||||
const result = await db.query(q, [projectId]);
|
||||
const tasks = result.rows;
|
||||
|
||||
// Add color_code to each assignee
|
||||
for (const task of tasks) {
|
||||
if (Array.isArray(task.assignees)) {
|
||||
for (const assignee of task.assignees) {
|
||||
assignee.color_code = getColor(assignee.name);
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
// Get groups based on groupBy parameter
|
||||
let groups: Array<{ id: string; group_name: string; color_code: string; color_code_dark: string }> = [];
|
||||
|
||||
if (groupBy === "status") {
|
||||
const q = `
|
||||
SELECT
|
||||
ts.id,
|
||||
ts.name as group_name,
|
||||
stsc.color_code::text,
|
||||
stsc.color_code_dark::text
|
||||
FROM task_statuses ts
|
||||
INNER JOIN sys_task_status_categories stsc ON ts.category_id = stsc.id
|
||||
WHERE ts.project_id = $1
|
||||
ORDER BY ts.sort_order;
|
||||
`;
|
||||
groups = (await db.query(q, [projectId])).rows;
|
||||
} else if (groupBy === "priority") {
|
||||
const q = `
|
||||
SELECT
|
||||
id,
|
||||
name as group_name,
|
||||
color_code::text,
|
||||
color_code_dark::text
|
||||
FROM task_priorities
|
||||
ORDER BY value;
|
||||
`;
|
||||
groups = (await db.query(q)).rows;
|
||||
} else if (groupBy === "phases") {
|
||||
const q = `
|
||||
SELECT
|
||||
id,
|
||||
name as group_name,
|
||||
color_code::text,
|
||||
color_code::text as color_code_dark
|
||||
FROM project_phases
|
||||
WHERE project_id = $1
|
||||
ORDER BY sort_index;
|
||||
`;
|
||||
groups = (await db.query(q, [projectId])).rows;
|
||||
|
||||
// Add TASK_STATUS_COLOR_ALPHA to color codes
|
||||
for (const group of groups) {
|
||||
group.color_code = group.color_code + TASK_STATUS_COLOR_ALPHA;
|
||||
group.color_code_dark = group.color_code_dark + TASK_STATUS_COLOR_ALPHA;
|
||||
}
|
||||
}
|
||||
|
||||
// Group tasks by the selected criteria
|
||||
const groupedTasks = groups.map(group => {
|
||||
const groupTasks = tasks.filter(task => {
|
||||
if (groupBy === "status") return task.status_id === group.id;
|
||||
if (groupBy === "priority") return task.priority_id === group.id;
|
||||
if (groupBy === "phases") return task.phase_id === group.id;
|
||||
return false;
|
||||
});
|
||||
|
||||
return {
|
||||
group_id: group.id,
|
||||
group_name: group.group_name,
|
||||
color_code: group.color_code,
|
||||
color_code_dark: group.color_code_dark,
|
||||
tasks: groupTasks.map(task => ({
|
||||
id: task.id,
|
||||
name: task.name,
|
||||
estimated_hours: Number(task.estimated_hours) || 0,
|
||||
total_time_logged: Number(task.total_time_logged) || 0,
|
||||
estimated_cost: Number(task.estimated_cost) || 0,
|
||||
fixed_cost: Number(task.fixed_cost) || 0,
|
||||
total_budget: Number(task.total_budget) || 0,
|
||||
total_actual: Number(task.total_actual) || 0,
|
||||
variance: Number(task.variance) || 0,
|
||||
members: task.assignees,
|
||||
billable: task.billable
|
||||
}))
|
||||
};
|
||||
});
|
||||
|
||||
return res.status(200).send(new ServerResponse(true, groupedTasks));
|
||||
}
|
||||
}
|
||||
|
||||
Reference in New Issue
Block a user