feat(reporting): enhance reporting allocation and members controllers
- Added a helper method to build billable queries with custom table aliases in the ReportingAllocationController. - Updated the logic for filtering projects and categories in the ReportingAllocationController to improve data retrieval based on user selections. - Refactored the query structure in both ReportingAllocationController and ReportingMembersController to streamline data processing and enhance performance. - Improved handling of utilization calculations and added new filters for team members in the ReportingMembersController. - Enhanced Excel export functionality for member reports, ensuring accurate data representation and improved formatting.
This commit is contained in:
@@ -15,6 +15,25 @@ enum IToggleOptions {
|
||||
}
|
||||
|
||||
export default class ReportingAllocationController extends ReportingControllerBase {
|
||||
// Helper method to build billable query with custom table alias
|
||||
private static buildBillableQueryWithAlias(selectedStatuses: { billable: boolean; nonBillable: boolean }, tableAlias: string = 'tasks'): string {
|
||||
const { billable, nonBillable } = selectedStatuses;
|
||||
|
||||
if (billable && nonBillable) {
|
||||
// Both are enabled, no need to filter
|
||||
return "";
|
||||
} else if (billable && !nonBillable) {
|
||||
// Only billable is enabled - show only billable tasks
|
||||
return ` AND ${tableAlias}.billable IS TRUE`;
|
||||
} else if (!billable && nonBillable) {
|
||||
// Only non-billable is enabled - show only non-billable tasks
|
||||
return ` AND ${tableAlias}.billable IS FALSE`;
|
||||
} else {
|
||||
// Neither selected - this shouldn't happen in normal UI flow
|
||||
return "";
|
||||
}
|
||||
}
|
||||
|
||||
private static async getTimeLoggedByProjects(projects: string[], users: string[], key: string, dateRange: string[], archived = false, user_id = "", billable: { billable: boolean; nonBillable: boolean }): Promise<any> {
|
||||
try {
|
||||
const projectIds = projects.map(p => `'${p}'`).join(",");
|
||||
@@ -77,8 +96,8 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
sps.icon AS status_icon,
|
||||
(SELECT COUNT(*)
|
||||
FROM tasks
|
||||
WHERE CASE WHEN ($1 IS TRUE) THEN project_id IS NOT NULL ELSE archived = FALSE END ${billableQuery}
|
||||
AND project_id = projects.id) AS all_tasks_count,
|
||||
WHERE CASE WHEN ($1 IS TRUE) THEN project_id IS NOT NULL ELSE archived = FALSE END
|
||||
AND project_id = projects.id ${billableQuery}) AS all_tasks_count,
|
||||
(SELECT COUNT(*)
|
||||
FROM tasks
|
||||
WHERE CASE WHEN ($1 IS TRUE) THEN project_id IS NOT NULL ELSE archived = FALSE END
|
||||
@@ -94,10 +113,11 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
SELECT name,
|
||||
(SELECT COALESCE(SUM(time_spent), 0)
|
||||
FROM task_work_log
|
||||
LEFT JOIN tasks ON task_work_log.task_id = tasks.id
|
||||
WHERE user_id = users.id ${billableQuery}
|
||||
LEFT JOIN tasks ON task_work_log.task_id = tasks.id
|
||||
WHERE user_id = users.id
|
||||
AND CASE WHEN ($1 IS TRUE) THEN tasks.project_id IS NOT NULL ELSE tasks.archived = FALSE END
|
||||
AND tasks.project_id = projects.id
|
||||
${billableQuery}
|
||||
${duration}) AS time_logged
|
||||
FROM users
|
||||
WHERE id IN (${userIds})
|
||||
@@ -121,10 +141,11 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
const q = `(SELECT id,
|
||||
(SELECT COALESCE(SUM(time_spent), 0)
|
||||
FROM task_work_log
|
||||
LEFT JOIN tasks ON task_work_log.task_id = tasks.id ${billableQuery}
|
||||
LEFT JOIN tasks ON task_work_log.task_id = tasks.id
|
||||
WHERE user_id = users.id
|
||||
AND CASE WHEN ($1 IS TRUE) THEN tasks.project_id IS NOT NULL ELSE tasks.archived = FALSE END
|
||||
AND tasks.project_id IN (${projectIds})
|
||||
${billableQuery}
|
||||
${duration}) AS time_logged
|
||||
FROM users
|
||||
WHERE id IN (${userIds})
|
||||
@@ -346,6 +367,8 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
const projects = (req.body.projects || []) as string[];
|
||||
const projectIds = projects.map(p => `'${p}'`).join(",");
|
||||
|
||||
const categories = (req.body.categories || []) as string[];
|
||||
const noCategory = req.body.noCategory || false;
|
||||
const billable = req.body.billable;
|
||||
|
||||
if (!teamIds || !projectIds.length)
|
||||
@@ -361,6 +384,33 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
|
||||
const billableQuery = this.buildBillableQuery(billable);
|
||||
|
||||
// Prepare projects filter
|
||||
let projectsFilter = "";
|
||||
if (projectIds.length > 0) {
|
||||
projectsFilter = `AND p.id IN (${projectIds})`;
|
||||
} else {
|
||||
// If no projects are selected, don't show any data
|
||||
projectsFilter = `AND 1=0`; // This will match no rows
|
||||
}
|
||||
|
||||
// Prepare categories filter - updated logic
|
||||
let categoriesFilter = "";
|
||||
if (categories.length > 0 && noCategory) {
|
||||
// Both specific categories and "No Category" are selected
|
||||
const categoryIds = categories.map(id => `'${id}'`).join(",");
|
||||
categoriesFilter = `AND (p.category_id IS NULL OR p.category_id IN (${categoryIds}))`;
|
||||
} else if (categories.length === 0 && noCategory) {
|
||||
// Only "No Category" is selected
|
||||
categoriesFilter = `AND p.category_id IS NULL`;
|
||||
} else if (categories.length > 0 && !noCategory) {
|
||||
// Only specific categories are selected
|
||||
const categoryIds = categories.map(id => `'${id}'`).join(",");
|
||||
categoriesFilter = `AND p.category_id IN (${categoryIds})`;
|
||||
} else {
|
||||
// categories.length === 0 && !noCategory - no categories selected, show nothing
|
||||
categoriesFilter = `AND 1=0`; // This will match no rows
|
||||
}
|
||||
|
||||
const q = `
|
||||
SELECT p.id,
|
||||
p.name,
|
||||
@@ -368,13 +418,15 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
SUM(total_minutes) AS estimated,
|
||||
color_code
|
||||
FROM projects p
|
||||
LEFT JOIN tasks ON tasks.project_id = p.id ${billableQuery}
|
||||
LEFT JOIN tasks ON tasks.project_id = p.id
|
||||
LEFT JOIN task_work_log ON task_work_log.task_id = tasks.id
|
||||
WHERE p.id IN (${projectIds}) ${durationClause} ${archivedClause}
|
||||
WHERE p.id IN (${projectIds}) ${durationClause} ${archivedClause} ${categoriesFilter} ${billableQuery}
|
||||
GROUP BY p.id, p.name
|
||||
ORDER BY logged_time DESC;`;
|
||||
const result = await db.query(q, []);
|
||||
|
||||
const utilization = (req.body.utilization || []) as string[];
|
||||
|
||||
const data = [];
|
||||
|
||||
for (const project of result.rows) {
|
||||
@@ -401,10 +453,12 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
const projects = (req.body.projects || []) as string[];
|
||||
const projectIds = projects.map(p => `'${p}'`).join(",");
|
||||
|
||||
const categories = (req.body.categories || []) as string[];
|
||||
const noCategory = req.body.noCategory || false;
|
||||
const billable = req.body.billable;
|
||||
|
||||
if (!teamIds || !projectIds.length)
|
||||
return res.status(200).send(new ServerResponse(true, { users: [], projects: [] }));
|
||||
if (!teamIds)
|
||||
return res.status(200).send(new ServerResponse(true, { filteredRows: [], totals: { total_time_logs: "0", total_estimated_hours: "0", total_utilization: "0" } }));
|
||||
|
||||
const { duration, date_range } = req.body;
|
||||
|
||||
@@ -416,7 +470,9 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
endDate = moment(date_range[1]);
|
||||
} else if (duration === DATE_RANGES.ALL_TIME) {
|
||||
// Fetch the earliest start_date (or created_at if null) from selected projects
|
||||
const minDateQuery = `SELECT MIN(COALESCE(start_date, created_at)) as min_date FROM projects WHERE id IN (${projectIds})`;
|
||||
const minDateQuery = projectIds.length > 0
|
||||
? `SELECT MIN(COALESCE(start_date, created_at)) as min_date FROM projects WHERE id IN (${projectIds})`
|
||||
: `SELECT MIN(COALESCE(start_date, created_at)) as min_date FROM projects WHERE team_id IN (${teamIds})`;
|
||||
const minDateResult = await db.query(minDateQuery, []);
|
||||
const minDate = minDateResult.rows[0]?.min_date;
|
||||
startDate = minDate ? moment(minDate) : moment('2000-01-01');
|
||||
@@ -445,59 +501,257 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
}
|
||||
}
|
||||
|
||||
// Count only weekdays (Mon-Fri) in the period
|
||||
// Get organization working days
|
||||
const orgWorkingDaysQuery = `
|
||||
SELECT monday, tuesday, wednesday, thursday, friday, saturday, sunday
|
||||
FROM organization_working_days
|
||||
WHERE organization_id IN (
|
||||
SELECT t.organization_id
|
||||
FROM teams t
|
||||
WHERE t.id IN (${teamIds})
|
||||
LIMIT 1
|
||||
);
|
||||
`;
|
||||
const orgWorkingDaysResult = await db.query(orgWorkingDaysQuery, []);
|
||||
const workingDaysConfig = orgWorkingDaysResult.rows[0] || {
|
||||
monday: true,
|
||||
tuesday: true,
|
||||
wednesday: true,
|
||||
thursday: true,
|
||||
friday: true,
|
||||
saturday: false,
|
||||
sunday: false
|
||||
};
|
||||
|
||||
// Count working days based on organization settings
|
||||
let workingDays = 0;
|
||||
let current = startDate.clone();
|
||||
while (current.isSameOrBefore(endDate, 'day')) {
|
||||
const day = current.isoWeekday();
|
||||
if (day >= 1 && day <= 5) workingDays++;
|
||||
if (
|
||||
(day === 1 && workingDaysConfig.monday) ||
|
||||
(day === 2 && workingDaysConfig.tuesday) ||
|
||||
(day === 3 && workingDaysConfig.wednesday) ||
|
||||
(day === 4 && workingDaysConfig.thursday) ||
|
||||
(day === 5 && workingDaysConfig.friday) ||
|
||||
(day === 6 && workingDaysConfig.saturday) ||
|
||||
(day === 7 && workingDaysConfig.sunday)
|
||||
) {
|
||||
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];
|
||||
// Get organization working hours
|
||||
const orgWorkingHoursQuery = `SELECT hours_per_day FROM organizations WHERE id = (SELECT t.organization_id FROM teams t WHERE t.id IN (${teamIds}) LIMIT 1)`;
|
||||
const orgWorkingHoursResult = await db.query(orgWorkingHoursQuery, []);
|
||||
const orgWorkingHours = orgWorkingHoursResult.rows[0]?.hours_per_day || 8;
|
||||
|
||||
// Calculate total working hours with minimum baseline for non-working day scenarios
|
||||
let totalWorkingHours = workingDays * orgWorkingHours;
|
||||
let isNonWorkingPeriod = false;
|
||||
|
||||
// If no working days but there might be logged time, set minimum baseline
|
||||
// This ensures that time logged on non-working days is treated as over-utilization
|
||||
// Business Logic: If someone works on weekends/holidays when workingDays = 0,
|
||||
// we use a minimal baseline (1 hour) so any logged time results in >100% utilization
|
||||
if (totalWorkingHours === 0) {
|
||||
totalWorkingHours = 1; // Minimal baseline to ensure over-utilization
|
||||
isNonWorkingPeriod = true;
|
||||
}
|
||||
|
||||
const durationClause = this.getDateRangeClause(duration || DATE_RANGES.LAST_WEEK, date_range);
|
||||
const archivedClause = archived
|
||||
? ""
|
||||
: `AND p.id NOT IN (SELECT project_id FROM archived_projects WHERE project_id = p.id AND user_id = '${req.user?.id}') `;
|
||||
|
||||
const billableQuery = this.buildBillableQuery(billable);
|
||||
const billableQuery = this.buildBillableQueryWithAlias(billable, 't');
|
||||
const members = (req.body.members || []) as string[];
|
||||
|
||||
// Prepare members filter
|
||||
let membersFilter = "";
|
||||
if (members.length > 0) {
|
||||
const memberIds = members.map(id => `'${id}'`).join(",");
|
||||
membersFilter = `AND tmiv.team_member_id IN (${memberIds})`;
|
||||
} else {
|
||||
// If no members are selected, we should not show any data
|
||||
// This is different from other filters where no selection means "show all"
|
||||
// For members, no selection should mean "show none" to respect the UI filter state
|
||||
membersFilter = `AND 1=0`; // This will match no rows
|
||||
}
|
||||
// Note: Members filter works differently - when no members are selected, show nothing
|
||||
|
||||
const q = `
|
||||
SELECT tmiv.email, tmiv.name, SUM(time_spent) AS logged_time
|
||||
FROM team_member_info_view tmiv
|
||||
LEFT JOIN task_work_log ON task_work_log.user_id = tmiv.user_id
|
||||
LEFT JOIN tasks ON tasks.id = task_work_log.task_id ${billableQuery}
|
||||
LEFT JOIN projects p ON p.id = tasks.project_id AND p.team_id = tmiv.team_id
|
||||
WHERE p.id IN (${projectIds})
|
||||
${durationClause} ${archivedClause}
|
||||
GROUP BY tmiv.email, tmiv.name
|
||||
ORDER BY logged_time DESC;`;
|
||||
const result = await db.query(q, []);
|
||||
|
||||
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);
|
||||
// Create custom duration clause for twl table alias
|
||||
let customDurationClause = "";
|
||||
if (date_range && date_range.length === 2) {
|
||||
const start = moment(date_range[0]).format("YYYY-MM-DD");
|
||||
const end = moment(date_range[1]).format("YYYY-MM-DD");
|
||||
if (start === end) {
|
||||
customDurationClause = `AND twl.created_at::DATE = '${start}'::DATE`;
|
||||
} else {
|
||||
customDurationClause = `AND twl.created_at::DATE >= '${start}'::DATE AND twl.created_at < '${end}'::DATE + INTERVAL '1 day'`;
|
||||
}
|
||||
} else {
|
||||
const key = duration || DATE_RANGES.LAST_WEEK;
|
||||
if (key === DATE_RANGES.YESTERDAY)
|
||||
customDurationClause = "AND twl.created_at >= (CURRENT_DATE - INTERVAL '1 day')::DATE AND twl.created_at < CURRENT_DATE::DATE";
|
||||
else if (key === DATE_RANGES.LAST_WEEK)
|
||||
customDurationClause = "AND twl.created_at >= (CURRENT_DATE - INTERVAL '1 week')::DATE AND twl.created_at < CURRENT_DATE::DATE + INTERVAL '1 day'";
|
||||
else if (key === DATE_RANGES.LAST_MONTH)
|
||||
customDurationClause = "AND twl.created_at >= (CURRENT_DATE - INTERVAL '1 month')::DATE AND twl.created_at < CURRENT_DATE::DATE + INTERVAL '1 day'";
|
||||
else if (key === DATE_RANGES.LAST_QUARTER)
|
||||
customDurationClause = "AND twl.created_at >= (CURRENT_DATE - INTERVAL '3 months')::DATE AND twl.created_at < CURRENT_DATE::DATE + INTERVAL '1 day'";
|
||||
}
|
||||
|
||||
return res.status(200).send(new ServerResponse(true, result.rows));
|
||||
// Prepare conditional filters for the subquery - only apply if selections are made
|
||||
let conditionalProjectsFilter = "";
|
||||
let conditionalCategoriesFilter = "";
|
||||
|
||||
// Only apply project filter if projects are actually selected
|
||||
if (projectIds.length > 0) {
|
||||
conditionalProjectsFilter = `AND p.id IN (${projectIds})`;
|
||||
}
|
||||
|
||||
// Only apply category filter if categories are selected or noCategory is true
|
||||
if (categories.length > 0 && noCategory) {
|
||||
const categoryIds = categories.map(id => `'${id}'`).join(",");
|
||||
conditionalCategoriesFilter = `AND (p.category_id IS NULL OR p.category_id IN (${categoryIds}))`;
|
||||
} else if (categories.length === 0 && noCategory) {
|
||||
conditionalCategoriesFilter = `AND p.category_id IS NULL`;
|
||||
} else if (categories.length > 0 && !noCategory) {
|
||||
const categoryIds = categories.map(id => `'${id}'`).join(",");
|
||||
conditionalCategoriesFilter = `AND p.category_id IN (${categoryIds})`;
|
||||
}
|
||||
// If no categories and no noCategory, don't filter by category (show all)
|
||||
|
||||
// Check if all filters are unchecked (Clear All scenario) - return no data to avoid overwhelming UI
|
||||
const hasProjectFilter = projectIds.length > 0;
|
||||
const hasCategoryFilter = categories.length > 0 || noCategory;
|
||||
const hasMemberFilter = members.length > 0;
|
||||
// Note: We'll check utilization filter after the query since it's applied post-processing
|
||||
|
||||
if (!hasProjectFilter && !hasCategoryFilter && !hasMemberFilter) {
|
||||
// Still need to check utilization filter, but we'll do a quick check
|
||||
const utilization = (req.body.utilization || []) as string[];
|
||||
const hasUtilizationFilter = utilization.length > 0;
|
||||
|
||||
if (!hasUtilizationFilter) {
|
||||
return res.status(200).send(new ServerResponse(true, { filteredRows: [], totals: { total_time_logs: "0", total_estimated_hours: "0", total_utilization: "0" } }));
|
||||
}
|
||||
}
|
||||
|
||||
// Modified query to start from team members and calculate filtered time logs
|
||||
// This query ensures ALL active team members are included, even if they have no logged time
|
||||
const q = `
|
||||
SELECT
|
||||
tmiv.team_member_id,
|
||||
tmiv.email,
|
||||
tmiv.name,
|
||||
COALESCE(
|
||||
(SELECT SUM(twl.time_spent)
|
||||
FROM task_work_log twl
|
||||
LEFT JOIN tasks t ON t.id = twl.task_id
|
||||
LEFT JOIN projects p ON p.id = t.project_id
|
||||
WHERE twl.user_id = tmiv.user_id
|
||||
${customDurationClause}
|
||||
${conditionalProjectsFilter}
|
||||
${conditionalCategoriesFilter}
|
||||
${archivedClause}
|
||||
${billableQuery}
|
||||
AND p.team_id = tmiv.team_id
|
||||
), 0
|
||||
) AS logged_time
|
||||
FROM team_member_info_view tmiv
|
||||
WHERE tmiv.team_id IN (${teamIds})
|
||||
AND tmiv.active = TRUE
|
||||
${membersFilter}
|
||||
GROUP BY tmiv.email, tmiv.name, tmiv.team_member_id, tmiv.user_id, tmiv.team_id
|
||||
ORDER BY logged_time DESC;`;
|
||||
|
||||
const result = await db.query(q, []);
|
||||
const utilization = (req.body.utilization || []) as string[];
|
||||
|
||||
// Precompute totalWorkingHours * 3600 for efficiency
|
||||
const totalWorkingSeconds = totalWorkingHours * 3600;
|
||||
|
||||
// calculate utilization state
|
||||
for (let i = 0, len = result.rows.length; i < len; i++) {
|
||||
const member = result.rows[i];
|
||||
const loggedSeconds = member.logged_time ? parseFloat(member.logged_time) : 0;
|
||||
const utilizedHours = loggedSeconds / 3600;
|
||||
|
||||
// For individual members, use the same logic as total calculation
|
||||
let memberWorkingHours;
|
||||
let utilizationPercent;
|
||||
|
||||
if (isNonWorkingPeriod) {
|
||||
// Non-working period: each member's expected working hours is 0
|
||||
memberWorkingHours = 0;
|
||||
// Any time logged during non-working period is overtime
|
||||
utilizationPercent = loggedSeconds > 0 ? 100 : 0; // Show 100+ as numeric 100 for consistency
|
||||
} else {
|
||||
// Normal working period
|
||||
memberWorkingHours = totalWorkingHours;
|
||||
utilizationPercent = memberWorkingHours > 0 && loggedSeconds
|
||||
? ((loggedSeconds / (memberWorkingHours * 3600)) * 100)
|
||||
: 0;
|
||||
}
|
||||
const overUnder = utilizedHours - memberWorkingHours;
|
||||
|
||||
member.value = utilizedHours ? parseFloat(utilizedHours.toFixed(2)) : 0;
|
||||
member.color_code = getColor(member.name);
|
||||
member.total_working_hours = memberWorkingHours;
|
||||
member.utilization_percent = utilizationPercent.toFixed(2);
|
||||
member.utilized_hours = utilizedHours.toFixed(2);
|
||||
member.over_under_utilized_hours = overUnder.toFixed(2);
|
||||
|
||||
if (utilizationPercent < 90) {
|
||||
member.utilization_state = 'under';
|
||||
} else if (utilizationPercent <= 110) {
|
||||
member.utilization_state = 'optimal';
|
||||
} else {
|
||||
member.utilization_state = 'over';
|
||||
}
|
||||
}
|
||||
|
||||
// Apply utilization filter
|
||||
let filteredRows;
|
||||
if (utilization.length > 0) {
|
||||
// Filter to only show selected utilization states
|
||||
filteredRows = result.rows.filter(member => utilization.includes(member.utilization_state));
|
||||
} else {
|
||||
// No utilization states selected
|
||||
// If we reached here, it means at least one other filter was applied
|
||||
// so we show all members (don't filter by utilization)
|
||||
filteredRows = result.rows;
|
||||
}
|
||||
|
||||
// Calculate totals
|
||||
const total_time_logs = filteredRows.reduce((sum, member) => sum + parseFloat(member.logged_time || '0'), 0);
|
||||
|
||||
let total_estimated_hours;
|
||||
let total_utilization;
|
||||
|
||||
if (isNonWorkingPeriod) {
|
||||
// Non-working period: expected capacity is 0
|
||||
total_estimated_hours = 0;
|
||||
// Special handling for utilization on non-working days
|
||||
total_utilization = total_time_logs > 0 ? "100+" : "0";
|
||||
} else {
|
||||
// Normal working period calculation
|
||||
total_estimated_hours = totalWorkingHours * filteredRows.length;
|
||||
total_utilization = total_time_logs > 0 && total_estimated_hours > 0
|
||||
? ((total_time_logs / (total_estimated_hours * 3600)) * 100).toFixed(1)
|
||||
: '0';
|
||||
}
|
||||
|
||||
return res.status(200).send(new ServerResponse(true, {
|
||||
filteredRows,
|
||||
totals: {
|
||||
total_time_logs: ((total_time_logs / 3600).toFixed(2)).toString(),
|
||||
total_estimated_hours: total_estimated_hours.toString(),
|
||||
total_utilization: total_utilization.toString(),
|
||||
},
|
||||
}));
|
||||
}
|
||||
|
||||
@HandleExceptions()
|
||||
@@ -580,6 +834,9 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
|
||||
const projects = (req.body.projects || []) as string[];
|
||||
const projectIds = projects.map(p => `'${p}'`).join(",");
|
||||
|
||||
const categories = (req.body.categories || []) as string[];
|
||||
const noCategory = req.body.noCategory || false;
|
||||
const { type, billable } = req.body;
|
||||
|
||||
if (!teamIds || !projectIds.length)
|
||||
@@ -595,6 +852,33 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
|
||||
const billableQuery = this.buildBillableQuery(billable);
|
||||
|
||||
// Prepare projects filter
|
||||
let projectsFilter = "";
|
||||
if (projectIds.length > 0) {
|
||||
projectsFilter = `AND p.id IN (${projectIds})`;
|
||||
} else {
|
||||
// If no projects are selected, don't show any data
|
||||
projectsFilter = `AND 1=0`; // This will match no rows
|
||||
}
|
||||
|
||||
// Prepare categories filter - updated logic
|
||||
let categoriesFilter = "";
|
||||
if (categories.length > 0 && noCategory) {
|
||||
// Both specific categories and "No Category" are selected
|
||||
const categoryIds = categories.map(id => `'${id}'`).join(",");
|
||||
categoriesFilter = `AND (p.category_id IS NULL OR p.category_id IN (${categoryIds}))`;
|
||||
} else if (categories.length === 0 && noCategory) {
|
||||
// Only "No Category" is selected
|
||||
categoriesFilter = `AND p.category_id IS NULL`;
|
||||
} else if (categories.length > 0 && !noCategory) {
|
||||
// Only specific categories are selected
|
||||
const categoryIds = categories.map(id => `'${id}'`).join(",");
|
||||
categoriesFilter = `AND p.category_id IN (${categoryIds})`;
|
||||
} else {
|
||||
// categories.length === 0 && !noCategory - no categories selected, show nothing
|
||||
categoriesFilter = `AND 1=0`; // This will match no rows
|
||||
}
|
||||
|
||||
const q = `
|
||||
SELECT p.id,
|
||||
p.name,
|
||||
@@ -608,9 +892,9 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
WHERE project_id = p.id) AS estimated,
|
||||
color_code
|
||||
FROM projects p
|
||||
LEFT JOIN tasks ON tasks.project_id = p.id ${billableQuery}
|
||||
LEFT JOIN tasks ON tasks.project_id = p.id
|
||||
LEFT JOIN task_work_log ON task_work_log.task_id = tasks.id
|
||||
WHERE p.id IN (${projectIds}) ${durationClause} ${archivedClause}
|
||||
WHERE p.id IN (${projectIds}) ${durationClause} ${archivedClause} ${categoriesFilter} ${billableQuery}
|
||||
GROUP BY p.id, p.name
|
||||
ORDER BY logged_time DESC;`;
|
||||
const result = await db.query(q, []);
|
||||
@@ -636,4 +920,4 @@ export default class ReportingAllocationController extends ReportingControllerBa
|
||||
|
||||
return res.status(200).send(new ServerResponse(true, data));
|
||||
}
|
||||
}
|
||||
}
|
||||
File diff suppressed because it is too large
Load Diff
Reference in New Issue
Block a user