refactor: enhance task completion ratio calculation and reporting

- Updated the `get_task_complete_ratio` function to improve handling of manual, weighted, and time-based progress calculations.
- Added logic to ensure accurate task completion ratios, including checks for subtasks and project settings.
- Enhanced error logging in the `refreshProjectTaskProgressValues` method for better debugging.
- Introduced new fields in the reporting allocation controller to calculate and display total working hours and utilization metrics for team members.
- Updated the frontend time sheet component to display utilization and over/under utilized hours in tooltips for better user insights.
This commit is contained in:
chamikaJ
2025-05-19 12:11:32 +05:30
parent 82155cab8d
commit c19e06d902
5 changed files with 329 additions and 84 deletions

View File

@@ -23,7 +23,7 @@ ALTER TABLE projects
ADD COLUMN IF NOT EXISTS use_time_progress BOOLEAN DEFAULT FALSE;
-- Update function to consider manual progress
CREATE OR REPLACE FUNCTION get_task_complete_ratio(_task_id UUID) RETURNS JSON
CREATE OR REPLACE FUNCTION get_task_complete_ratio(_task_id uuid) RETURNS json
LANGUAGE plpgsql
AS
$$
@@ -40,16 +40,23 @@ DECLARE
_use_manual_progress BOOLEAN = FALSE;
_use_weighted_progress BOOLEAN = FALSE;
_use_time_progress BOOLEAN = FALSE;
_task_complete BOOLEAN = FALSE;
_progress_mode VARCHAR(20) = NULL;
BEGIN
-- Check if manual progress is set
SELECT manual_progress, progress_value, project_id
-- Check if manual progress is set for this task
SELECT manual_progress, progress_value, project_id, progress_mode,
EXISTS(
SELECT 1
FROM tasks_with_status_view
WHERE tasks_with_status_view.task_id = tasks.id
AND is_done IS TRUE
) AS is_complete
FROM tasks
WHERE id = _task_id
INTO _is_manual, _manual_value, _project_id;
INTO _is_manual, _manual_value, _project_id, _progress_mode, _task_complete;
-- Check if the project uses manual progress
IF _project_id IS NOT NULL
THEN
IF _project_id IS NOT NULL THEN
SELECT COALESCE(use_manual_progress, FALSE),
COALESCE(use_weighted_progress, FALSE),
COALESCE(use_time_progress, FALSE)
@@ -58,9 +65,38 @@ BEGIN
INTO _use_manual_progress, _use_weighted_progress, _use_time_progress;
END IF;
-- If manual progress is enabled and has a value, use it directly
IF _is_manual IS TRUE AND _manual_value IS NOT NULL
THEN
-- Get all subtasks
SELECT COUNT(*)
FROM tasks
WHERE parent_task_id = _task_id AND archived IS FALSE
INTO _sub_tasks_count;
-- If task is complete, always return 100%
IF _task_complete IS TRUE THEN
RETURN JSON_BUILD_OBJECT(
'ratio', 100,
'total_completed', 1,
'total_tasks', 1,
'is_manual', FALSE
);
END IF;
-- Determine current active mode
DECLARE
_current_mode VARCHAR(20) = CASE
WHEN _use_manual_progress IS TRUE THEN 'manual'
WHEN _use_weighted_progress IS TRUE THEN 'weighted'
WHEN _use_time_progress IS TRUE THEN 'time'
ELSE 'default'
END;
BEGIN
-- Only use manual progress value if it was set in the current active mode
-- and time progress is not enabled
IF _use_time_progress IS FALSE AND
((_is_manual IS TRUE AND _manual_value IS NOT NULL AND
(_progress_mode IS NULL OR _progress_mode = _current_mode)) OR
(_use_manual_progress IS TRUE AND _manual_value IS NOT NULL AND
(_progress_mode IS NULL OR _progress_mode = 'manual'))) THEN
RETURN JSON_BUILD_OBJECT(
'ratio', _manual_value,
'total_completed', 0,
@@ -68,16 +104,142 @@ BEGIN
'is_manual', TRUE
);
END IF;
END;
-- Otherwise calculate automatically as before
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)
-- If there are no subtasks, calculate based on the task itself
IF _sub_tasks_count = 0 THEN
-- Use time-based estimation if enabled
IF _use_time_progress IS TRUE THEN
-- Calculate progress based on logged time vs estimated time
WITH task_time_info AS (
SELECT
COALESCE(t.total_minutes, 0) as estimated_minutes,
COALESCE((
SELECT SUM(time_spent)
FROM task_work_log
WHERE task_id = t.id
), 0) as logged_minutes
FROM tasks t
WHERE t.id = _task_id
)
SELECT
CASE
WHEN _task_complete IS TRUE THEN 100
WHEN estimated_minutes > 0 THEN
LEAST((logged_minutes / estimated_minutes) * 100, 100)
ELSE 0
END
INTO _ratio
FROM task_time_info;
ELSE
-- Traditional calculation for non-time-based tasks
SELECT (CASE WHEN _task_complete 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 AND _use_time_progress IS FALSE THEN
WITH subtask_progress AS (
SELECT
t.id,
t.manual_progress,
t.progress_value,
t.progress_mode,
EXISTS(
SELECT 1
FROM tasks_with_status_view
WHERE tasks_with_status_view.task_id = t.id
AND is_done IS TRUE
) AS is_complete
FROM tasks t
WHERE t.parent_task_id = _task_id
AND t.archived IS FALSE
),
subtask_with_values AS (
SELECT
CASE
WHEN is_complete IS TRUE THEN 100
WHEN progress_value IS NOT NULL AND (progress_mode = 'manual' OR progress_mode IS NULL) THEN progress_value
ELSE 0
END AS progress_value
FROM subtask_progress
)
SELECT COALESCE(AVG(progress_value), 0)
FROM subtask_with_values
INTO _ratio;
-- If project uses weighted progress, calculate based on subtask weights
ELSIF _use_weighted_progress IS TRUE AND _use_time_progress IS FALSE THEN
WITH subtask_progress AS (
SELECT
t.id,
t.manual_progress,
t.progress_value,
t.progress_mode,
EXISTS(
SELECT 1
FROM tasks_with_status_view
WHERE tasks_with_status_view.task_id = t.id
AND is_done IS TRUE
) AS is_complete,
COALESCE(t.weight, 100) AS weight
FROM tasks t
WHERE t.parent_task_id = _task_id
AND t.archived IS FALSE
),
subtask_with_values AS (
SELECT
CASE
WHEN is_complete IS TRUE THEN 100
WHEN progress_value IS NOT NULL AND (progress_mode = 'weighted' OR progress_mode IS NULL) THEN progress_value
ELSE 0
END AS progress_value,
weight
FROM subtask_progress
)
SELECT COALESCE(
SUM(progress_value * weight) / NULLIF(SUM(weight), 0),
0
)
FROM subtask_with_values
INTO _ratio;
-- If project uses time-based progress, calculate based on actual logged time
ELSIF _use_time_progress IS TRUE THEN
WITH task_time_info AS (
SELECT
t.id,
COALESCE(t.total_minutes, 0) as estimated_minutes,
COALESCE((
SELECT SUM(time_spent)
FROM task_work_log
WHERE task_id = t.id
), 0) as logged_minutes,
EXISTS(
SELECT 1
FROM tasks_with_status_view
WHERE tasks_with_status_view.task_id = t.id
AND is_done IS TRUE
) AS is_complete
FROM tasks t
WHERE t.parent_task_id = _task_id
AND t.archived IS FALSE
)
SELECT COALESCE(
SUM(
CASE
WHEN is_complete IS TRUE THEN estimated_minutes
ELSE LEAST(logged_minutes, estimated_minutes)
END
) / NULLIF(SUM(estimated_minutes), 0) * 100,
0
)
FROM task_time_info
INTO _ratio;
ELSE
-- Traditional calculation based on completion status
SELECT (CASE WHEN _task_complete IS TRUE THEN 1 ELSE 0 END)
INTO _parent_task_done;
SELECT COUNT(*) FROM tasks WHERE parent_task_id = _task_id AND archived IS FALSE INTO _sub_tasks_count;
SELECT COUNT(*)
FROM tasks_with_status_view
@@ -86,20 +248,28 @@ BEGIN
INTO _sub_tasks_done;
_total_completed = _parent_task_done + _sub_tasks_done;
_total_tasks = _sub_tasks_count; -- +1 for the parent task
_total_tasks = _sub_tasks_count + 1; -- +1 for the parent task
IF _total_tasks > 0
THEN
_ratio = (_total_completed / _total_tasks) * 100;
IF _total_tasks = 0 THEN
_ratio = 0;
ELSE
_ratio = _parent_task_done * 100;
_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', FALSE
'is_manual', _is_manual
);
END
$$;
@@ -615,38 +785,38 @@ BEGIN
)
FROM subtask_with_values
INTO _ratio;
-- If project uses time-based progress, calculate based on estimated time
-- If project uses time-based progress, calculate based on actual logged time
ELSIF _use_time_progress IS TRUE
THEN
WITH subtask_progress AS (SELECT t.id,
t.manual_progress,
t.progress_value,
t.progress_mode,
EXISTS(SELECT 1
WITH task_time_info AS (
SELECT
t.id,
COALESCE(t.total_minutes, 0) as estimated_minutes,
COALESCE((
SELECT SUM(time_spent)
FROM task_work_log
WHERE task_id = t.id
), 0) as logged_minutes,
EXISTS(
SELECT 1
FROM tasks_with_status_view
WHERE tasks_with_status_view.task_id = t.id
AND is_done IS TRUE) AS is_complete,
COALESCE(t.total_minutes, 0) AS estimated_minutes
AND is_done IS TRUE
) AS is_complete
FROM tasks t
WHERE t.parent_task_id = _task_id
AND t.archived IS FALSE),
subtask_with_values AS (SELECT CASE
-- For completed tasks, always use 100%
WHEN is_complete IS TRUE THEN 100
-- For tasks with progress value set in the correct mode, use it
WHEN progress_value IS NOT NULL AND
(progress_mode = 'time' OR progress_mode IS NULL)
THEN progress_value
-- Default to 0 for incomplete tasks with no progress value or wrong mode
ELSE 0
END AS progress_value,
estimated_minutes
FROM subtask_progress)
AND t.archived IS FALSE
)
SELECT COALESCE(
SUM(progress_value * estimated_minutes) / NULLIF(SUM(estimated_minutes), 0),
SUM(
CASE
WHEN is_complete IS TRUE THEN estimated_minutes
ELSE LEAST(logged_minutes, estimated_minutes)
END
) / NULLIF(SUM(estimated_minutes), 0) * 100,
0
)
FROM subtask_with_values
FROM task_time_info
INTO _ratio;
ELSE
-- Traditional calculation based on completion status

View File

@@ -408,6 +408,58 @@ export default class ReportingAllocationController extends ReportingControllerBa
const { duration, date_range } = req.body;
// Calculate the date range (start and end)
let startDate: moment.Moment;
let endDate: moment.Moment;
if (date_range && date_range.length === 2) {
startDate = moment(date_range[0]);
endDate = moment(date_range[1]);
} else {
switch (duration) {
case DATE_RANGES.YESTERDAY:
startDate = moment().subtract(1, "day");
endDate = moment().subtract(1, "day");
break;
case DATE_RANGES.LAST_WEEK:
startDate = moment().subtract(1, "week").startOf("isoWeek");
endDate = moment().subtract(1, "week").endOf("isoWeek");
break;
case DATE_RANGES.LAST_MONTH:
startDate = moment().subtract(1, "month").startOf("month");
endDate = moment().subtract(1, "month").endOf("month");
break;
case DATE_RANGES.LAST_QUARTER:
startDate = moment().subtract(3, "months").startOf("quarter");
endDate = moment().subtract(1, "quarter").endOf("quarter");
break;
default:
startDate = moment().startOf("day");
endDate = moment().endOf("day");
}
}
// Count only weekdays (Mon-Fri) in the period
let workingDays = 0;
let current = startDate.clone();
while (current.isSameOrBefore(endDate, 'day')) {
const day = current.isoWeekday();
if (day >= 1 && day <= 5) workingDays++;
current.add(1, 'day');
}
// Get hours_per_day for all selected projects
const projectHoursQuery = `SELECT id, hours_per_day FROM projects WHERE id IN (${projectIds})`;
const projectHoursResult = await db.query(projectHoursQuery, []);
const projectHoursMap: Record<string, number> = {};
for (const row of projectHoursResult.rows) {
projectHoursMap[row.id] = row.hours_per_day || 8;
}
// Sum total working hours for all selected projects
let totalWorkingHours = 0;
for (const pid of Object.keys(projectHoursMap)) {
totalWorkingHours += workingDays * projectHoursMap[pid];
}
const durationClause = this.getDateRangeClause(duration || DATE_RANGES.LAST_WEEK, date_range);
const archivedClause = archived
? ""
@@ -430,6 +482,12 @@ export default class ReportingAllocationController extends ReportingControllerBa
for (const member of result.rows) {
member.value = member.logged_time ? parseFloat(moment.duration(member.logged_time, "seconds").asHours().toFixed(2)) : 0;
member.color_code = getColor(member.name);
member.total_working_hours = totalWorkingHours;
member.utilization_percent = (totalWorkingHours > 0 && member.logged_time) ? ((parseFloat(member.logged_time) / (totalWorkingHours * 3600)) * 100).toFixed(2) : '0.00';
member.utilized_hours = member.logged_time ? (parseFloat(member.logged_time) / 3600).toFixed(2) : '0.00';
// Over/under utilized hours: utilized_hours - total_working_hours
const overUnder = member.utilized_hours && member.total_working_hours ? (parseFloat(member.utilized_hours) - member.total_working_hours) : 0;
member.over_under_utilized_hours = overUnder.toFixed(2);
}
return res.status(200).send(new ServerResponse(true, result.rows));

View File

@@ -834,8 +834,6 @@ export default class TasksControllerV2 extends TasksControllerBase {
public static async refreshProjectTaskProgressValues(projectId: string): Promise<void> {
try {
console.log(`Refreshing progress values for project ${projectId}`);
// Run the recalculate_all_task_progress function only for tasks in this project
const query = `
DO $$
@@ -893,10 +891,10 @@ export default class TasksControllerV2 extends TasksControllerBase {
END $$;
`;
const result = await db.query(query);
await db.query(query);
console.log(`Finished refreshing progress values for project ${projectId}`);
} catch (error) {
log_error('Error refreshing project task progress values', error);
log_error("Error refreshing project task progress values", error);
}
}

View File

@@ -81,6 +81,22 @@ const MembersTimeSheet = forwardRef<MembersTimeSheetRef>((_, ref) => {
display: false,
position: 'top' as const,
},
tooltip: {
callbacks: {
label: function(context: any) {
const idx = context.dataIndex;
const member = jsonData[idx];
const hours = member?.utilized_hours || '0.00';
const percent = member?.utilization_percent || '0.00';
const overUnder = member?.over_under_utilized_hours || '0.00';
return [
`${context.dataset.label}: ${hours} h`,
`Utilization: ${percent}%`,
`Over/Under Utilized: ${overUnder} h`
];
}
}
}
},
backgroundColor: 'black',
indexAxis: 'y' as const,

View File

@@ -406,6 +406,9 @@ export interface IRPTTimeMember {
value?: number;
color_code: string;
logged_time?: string;
utilized_hours?: string;
utilization_percent?: string;
over_under_utilized_hours?: string;
}
export interface IMemberTaskStatGroupResonse {