Merge branch 'release-v2.1.4' into chore/added-sign-up-survey

This commit is contained in:
Chamika J
2025-07-25 13:03:03 +05:30
committed by GitHub
63 changed files with 6926 additions and 371 deletions

View File

@@ -71,7 +71,7 @@ export default class ProjectsController extends WorklenzControllerBase {
return res.status(200).send(new ServerResponse(false, [], `Sorry, the free plan cannot have more than ${projectsLimit} projects.`));
}
}
const q = `SELECT create_project($1) AS project`;
req.body.team_id = req.user?.team_id || null;
@@ -317,65 +317,58 @@ export default class ProjectsController extends WorklenzControllerBase {
@HandleExceptions()
public static async getMembersByProjectId(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
const {sortField, sortOrder, size, offset} = this.toPaginationOptions(req.query, "name");
const search = (req.query.search || "").toString().trim();
let searchFilter = "";
const params = [req.params.id, req.user?.team_id ?? null, size, offset];
if (search) {
searchFilter = `
AND (
(SELECT name FROM team_member_info_view WHERE team_member_info_view.team_member_id = tm.id) ILIKE '%' || $5 || '%'
OR (SELECT email FROM team_member_info_view WHERE team_member_info_view.team_member_id = tm.id) ILIKE '%' || $5 || '%'
)
`;
params.push(search);
}
const q = `
SELECT ROW_TO_JSON(rec) AS members
FROM (SELECT COUNT(*) AS total,
(SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(ROW_TO_JSON(t))), '[]'::JSON)
FROM (SELECT project_members.id,
team_member_id,
(SELECT name
FROM team_member_info_view
WHERE team_member_info_view.team_member_id = tm.id),
(SELECT email
FROM team_member_info_view
WHERE team_member_info_view.team_member_id = tm.id) AS email,
u.avatar_url,
(SELECT COUNT(*)
FROM tasks
WHERE archived IS FALSE
AND project_id = project_members.project_id
AND id IN (SELECT task_id
FROM tasks_assignees
WHERE tasks_assignees.project_member_id = project_members.id)) AS all_tasks_count,
(SELECT COUNT(*)
FROM tasks
WHERE archived IS FALSE
AND project_id = project_members.project_id
AND id IN (SELECT task_id
FROM tasks_assignees
WHERE tasks_assignees.project_member_id = project_members.id)
AND status_id IN (SELECT id
FROM task_statuses
WHERE category_id = (SELECT id
FROM sys_task_status_categories
WHERE is_done IS TRUE))) AS completed_tasks_count,
EXISTS(SELECT email
FROM email_invitations
WHERE team_member_id = project_members.team_member_id
AND email_invitations.team_id = $2) AS pending_invitation,
(SELECT project_access_levels.name
FROM project_access_levels
WHERE project_access_levels.id = project_members.project_access_level_id) AS access,
(SELECT name FROM job_titles WHERE id = tm.job_title_id) AS job_title
FROM project_members
INNER JOIN team_members tm ON project_members.team_member_id = tm.id
LEFT JOIN users u ON tm.user_id = u.id
WHERE project_id = $1
ORDER BY ${sortField} ${sortOrder}
LIMIT $3 OFFSET $4) t) AS data
FROM project_members
WHERE project_id = $1) rec;
WITH filtered_members AS (
SELECT project_members.id,
team_member_id,
(SELECT name FROM team_member_info_view WHERE team_member_info_view.team_member_id = tm.id) AS name,
(SELECT email FROM team_member_info_view WHERE team_member_info_view.team_member_id = tm.id) AS email,
u.avatar_url,
(SELECT COUNT(*) FROM tasks WHERE archived IS FALSE AND project_id = project_members.project_id AND id IN (SELECT task_id FROM tasks_assignees WHERE tasks_assignees.project_member_id = project_members.id)) AS all_tasks_count,
(SELECT COUNT(*) FROM tasks WHERE archived IS FALSE AND project_id = project_members.project_id AND id IN (SELECT task_id FROM tasks_assignees WHERE tasks_assignees.project_member_id = project_members.id) AND status_id IN (SELECT id FROM task_statuses WHERE category_id = (SELECT id FROM sys_task_status_categories WHERE is_done IS TRUE))) AS completed_tasks_count,
EXISTS(SELECT email FROM email_invitations WHERE team_member_id = project_members.team_member_id AND email_invitations.team_id = $2) AS pending_invitation,
(SELECT project_access_levels.name FROM project_access_levels WHERE project_access_levels.id = project_members.project_access_level_id) AS access,
(SELECT name FROM job_titles WHERE id = tm.job_title_id) AS job_title
FROM project_members
INNER JOIN team_members tm ON project_members.team_member_id = tm.id
LEFT JOIN users u ON tm.user_id = u.id
WHERE project_id = $1
${search ? searchFilter : ""}
)
SELECT
(SELECT COUNT(*) FROM filtered_members) AS total,
(SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(ROW_TO_JSON(t))), '[]'::JSON)
FROM (
SELECT * FROM filtered_members
ORDER BY ${sortField} ${sortOrder}
LIMIT $3 OFFSET $4
) t
) AS data
`;
const result = await db.query(q, [req.params.id, req.user?.team_id ?? null, size, offset]);
const result = await db.query(q, params);
const [data] = result.rows;
for (const member of data?.members.data || []) {
for (const member of data?.data || []) {
member.progress = member.all_tasks_count > 0
? ((member.completed_tasks_count / member.all_tasks_count) * 100).toFixed(0) : 0;
}
return res.status(200).send(new ServerResponse(true, data?.members || this.paginatedDatasetDefaultStruct));
return res.status(200).send(new ServerResponse(true, data || this.paginatedDatasetDefaultStruct));
}
@HandleExceptions()
@@ -779,7 +772,7 @@ export default class ProjectsController extends WorklenzControllerBase {
let groupJoin = "";
let groupByFields = "";
let groupOrderBy = "";
switch (groupBy) {
case "client":
groupField = "COALESCE(projects.client_id::text, 'no-client')";
@@ -888,13 +881,13 @@ export default class ProjectsController extends WorklenzControllerBase {
ELSE p2.updated_at END) AS updated_at
FROM projects p2
${groupJoin.replace("projects.", "p2.")}
WHERE p2.team_id = $1
WHERE p2.team_id = $1
AND ${groupField.replace("projects.", "p2.")} = ${groupField}
${categories.replace("projects.", "p2.")}
${statuses.replace("projects.", "p2.")}
${isArchived.replace("projects.", "p2.")}
${isFavorites.replace("projects.", "p2.")}
${filterByMember.replace("projects.", "p2.")}
${categories.replace("projects.", "p2.")}
${statuses.replace("projects.", "p2.")}
${isArchived.replace("projects.", "p2.")}
${isFavorites.replace("projects.", "p2.")}
${filterByMember.replace("projects.", "p2.")}
${searchQuery.replace("projects.", "p2.")}
ORDER BY ${innerSortField} ${sortOrder}
) project_data

View File

@@ -0,0 +1,179 @@
// Example of updated getMemberTimeSheets method with timezone support
// This shows the key changes needed to handle timezones properly
import moment from "moment-timezone";
import db from "../../config/db";
import { IWorkLenzRequest } from "../../interfaces/worklenz-request";
import { IWorkLenzResponse } from "../../interfaces/worklenz-response";
import { ServerResponse } from "../../models/server-response";
import { DATE_RANGES } from "../../shared/constants";
export async function getMemberTimeSheets(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
const archived = req.query.archived === "true";
const teams = (req.body.teams || []) as string[];
const teamIds = teams.map(id => `'${id}'`).join(",");
const projects = (req.body.projects || []) as string[];
const projectIds = projects.map(p => `'${p}'`).join(",");
const {billable} = req.body;
// Get user timezone from request or database
const userTimezone = req.body.timezone || await getUserTimezone(req.user?.id || "");
if (!teamIds || !projectIds.length)
return res.status(200).send(new ServerResponse(true, { users: [], projects: [] }));
const { duration, date_range } = req.body;
// Calculate date range with timezone support
let startDate: moment.Moment;
let endDate: moment.Moment;
if (date_range && date_range.length === 2) {
// Convert user's local dates to their timezone's start/end of day
startDate = moment.tz(date_range[0], userTimezone).startOf("day");
endDate = moment.tz(date_range[1], userTimezone).endOf("day");
} else if (duration === DATE_RANGES.ALL_TIME) {
const minDateQuery = `SELECT MIN(COALESCE(start_date, created_at)) as min_date FROM projects WHERE id IN (${projectIds})`;
const minDateResult = await db.query(minDateQuery, []);
const minDate = minDateResult.rows[0]?.min_date;
startDate = minDate ? moment.tz(minDate, userTimezone) : moment.tz("2000-01-01", userTimezone);
endDate = moment.tz(userTimezone);
} else {
// Calculate ranges based on user's timezone
const now = moment.tz(userTimezone);
switch (duration) {
case DATE_RANGES.YESTERDAY:
startDate = now.clone().subtract(1, "day").startOf("day");
endDate = now.clone().subtract(1, "day").endOf("day");
break;
case DATE_RANGES.LAST_WEEK:
startDate = now.clone().subtract(1, "week").startOf("isoWeek");
endDate = now.clone().subtract(1, "week").endOf("isoWeek");
break;
case DATE_RANGES.LAST_MONTH:
startDate = now.clone().subtract(1, "month").startOf("month");
endDate = now.clone().subtract(1, "month").endOf("month");
break;
case DATE_RANGES.LAST_QUARTER:
startDate = now.clone().subtract(3, "months").startOf("day");
endDate = now.clone().endOf("day");
break;
default:
startDate = now.clone().startOf("day");
endDate = now.clone().endOf("day");
}
}
// Convert to UTC for database queries
const startUtc = startDate.utc().format("YYYY-MM-DD HH:mm:ss");
const endUtc = endDate.utc().format("YYYY-MM-DD HH:mm:ss");
// Calculate working days in user's timezone
const totalDays = endDate.diff(startDate, "days") + 1;
let workingDays = 0;
const current = startDate.clone();
while (current.isSameOrBefore(endDate, "day")) {
if (current.isoWeekday() >= 1 && current.isoWeekday() <= 5) {
workingDays++;
}
current.add(1, "day");
}
// Updated SQL query with proper timezone handling
const billableQuery = buildBillableQuery(billable);
const archivedClause = archived ? "" : `AND projects.id NOT IN (SELECT project_id FROM archived_projects WHERE project_id = projects.id AND user_id = '${req.user?.id}')`;
const q = `
WITH project_hours AS (
SELECT
id,
COALESCE(hours_per_day, 8) as hours_per_day
FROM projects
WHERE id IN (${projectIds})
),
total_working_hours AS (
SELECT
SUM(hours_per_day) * ${workingDays} as total_hours
FROM project_hours
)
SELECT
u.id,
u.email,
tm.name,
tm.color_code,
COALESCE(SUM(twl.time_spent), 0) as logged_time,
COALESCE(SUM(twl.time_spent), 0) / 3600.0 as value,
(SELECT total_hours FROM total_working_hours) as total_working_hours,
CASE
WHEN (SELECT total_hours FROM total_working_hours) > 0
THEN ROUND((COALESCE(SUM(twl.time_spent), 0) / 3600.0) / (SELECT total_hours FROM total_working_hours) * 100, 2)
ELSE 0
END as utilization_percent,
ROUND(COALESCE(SUM(twl.time_spent), 0) / 3600.0, 2) as utilized_hours,
ROUND(COALESCE(SUM(twl.time_spent), 0) / 3600.0 - (SELECT total_hours FROM total_working_hours), 2) as over_under_utilized_hours,
'${userTimezone}' as user_timezone,
'${startDate.format("YYYY-MM-DD")}' as report_start_date,
'${endDate.format("YYYY-MM-DD")}' as report_end_date
FROM team_members tm
LEFT JOIN users u ON tm.user_id = u.id
LEFT JOIN task_work_log twl ON twl.user_id = u.id
LEFT JOIN tasks t ON twl.task_id = t.id ${billableQuery}
LEFT JOIN projects p ON t.project_id = p.id
WHERE tm.team_id IN (${teamIds})
AND (
twl.id IS NULL
OR (
p.id IN (${projectIds})
AND twl.created_at >= '${startUtc}'::TIMESTAMP
AND twl.created_at <= '${endUtc}'::TIMESTAMP
${archivedClause}
)
)
GROUP BY u.id, u.email, tm.name, tm.color_code
ORDER BY logged_time DESC`;
const result = await db.query(q, []);
// Add timezone context to response
const response = {
data: result.rows,
timezone_info: {
user_timezone: userTimezone,
report_period: {
start: startDate.format("YYYY-MM-DD HH:mm:ss z"),
end: endDate.format("YYYY-MM-DD HH:mm:ss z"),
working_days: workingDays,
total_days: totalDays
}
}
};
return res.status(200).send(new ServerResponse(true, response));
}
async function getUserTimezone(userId: string): Promise<string> {
const q = `SELECT tz.name as timezone
FROM users u
JOIN timezones tz ON u.timezone_id = tz.id
WHERE u.id = $1`;
const result = await db.query(q, [userId]);
return result.rows[0]?.timezone || "UTC";
}
function buildBillableQuery(billable: { billable: boolean; nonBillable: boolean }): string {
if (!billable) return "";
const { billable: isBillable, nonBillable } = billable;
if (isBillable && nonBillable) {
return "";
} else if (isBillable) {
return " AND tasks.billable IS TRUE";
} else if (nonBillable) {
return " AND tasks.billable IS FALSE";
}
return "";
}

View File

@@ -0,0 +1,117 @@
import WorklenzControllerBase from "../worklenz-controller-base";
import { IWorkLenzRequest } from "../../interfaces/worklenz-request";
import db from "../../config/db";
import moment from "moment-timezone";
import { DATE_RANGES } from "../../shared/constants";
export default abstract class ReportingControllerBaseWithTimezone extends WorklenzControllerBase {
/**
* Get the user's timezone from the database or request
* @param userId - The user ID
* @returns The user's timezone or 'UTC' as default
*/
protected static async getUserTimezone(userId: string): Promise<string> {
const q = `SELECT tz.name as timezone
FROM users u
JOIN timezones tz ON u.timezone_id = tz.id
WHERE u.id = $1`;
const result = await db.query(q, [userId]);
return result.rows[0]?.timezone || 'UTC';
}
/**
* Generate date range clause with timezone support
* @param key - Date range key (e.g., YESTERDAY, LAST_WEEK)
* @param dateRange - Array of date strings
* @param userTimezone - User's timezone (e.g., 'America/New_York')
* @returns SQL clause for date filtering
*/
protected static getDateRangeClauseWithTimezone(key: string, dateRange: string[], userTimezone: string) {
// For custom date ranges
if (dateRange.length === 2) {
// Convert dates to user's timezone start/end of day
const start = moment.tz(dateRange[0], userTimezone).startOf('day');
const end = moment.tz(dateRange[1], userTimezone).endOf('day');
// Convert to UTC for database comparison
const startUtc = start.utc().format("YYYY-MM-DD HH:mm:ss");
const endUtc = end.utc().format("YYYY-MM-DD HH:mm:ss");
if (start.isSame(end, 'day')) {
// Single day selection
return `AND task_work_log.created_at >= '${startUtc}'::TIMESTAMP AND task_work_log.created_at <= '${endUtc}'::TIMESTAMP`;
}
return `AND task_work_log.created_at >= '${startUtc}'::TIMESTAMP AND task_work_log.created_at <= '${endUtc}'::TIMESTAMP`;
}
// For predefined ranges, calculate based on user's timezone
const now = moment.tz(userTimezone);
let startDate, endDate;
switch (key) {
case DATE_RANGES.YESTERDAY:
startDate = now.clone().subtract(1, 'day').startOf('day');
endDate = now.clone().subtract(1, 'day').endOf('day');
break;
case DATE_RANGES.LAST_WEEK:
startDate = now.clone().subtract(1, 'week').startOf('week');
endDate = now.clone().subtract(1, 'week').endOf('week');
break;
case DATE_RANGES.LAST_MONTH:
startDate = now.clone().subtract(1, 'month').startOf('month');
endDate = now.clone().subtract(1, 'month').endOf('month');
break;
case DATE_RANGES.LAST_QUARTER:
startDate = now.clone().subtract(3, 'months').startOf('day');
endDate = now.clone().endOf('day');
break;
default:
return "";
}
if (startDate && endDate) {
const startUtc = startDate.utc().format("YYYY-MM-DD HH:mm:ss");
const endUtc = endDate.utc().format("YYYY-MM-DD HH:mm:ss");
return `AND task_work_log.created_at >= '${startUtc}'::TIMESTAMP AND task_work_log.created_at <= '${endUtc}'::TIMESTAMP`;
}
return "";
}
/**
* Format dates for display in user's timezone
* @param date - Date to format
* @param userTimezone - User's timezone
* @param format - Moment format string
* @returns Formatted date string
*/
protected static formatDateInTimezone(date: string | Date, userTimezone: string, format: string = "YYYY-MM-DD HH:mm:ss") {
return moment.tz(date, userTimezone).format(format);
}
/**
* Get working days count between two dates in user's timezone
* @param startDate - Start date
* @param endDate - End date
* @param userTimezone - User's timezone
* @returns Number of working days
*/
protected static getWorkingDaysInTimezone(startDate: string, endDate: string, userTimezone: string): number {
const start = moment.tz(startDate, userTimezone);
const end = moment.tz(endDate, userTimezone);
let workingDays = 0;
const current = start.clone();
while (current.isSameOrBefore(end, 'day')) {
// Monday = 1, Friday = 5
if (current.isoWeekday() >= 1 && current.isoWeekday() <= 5) {
workingDays++;
}
current.add(1, 'day');
}
return workingDays;
}
}

View File

@@ -6,10 +6,69 @@ import { IWorkLenzResponse } from "../../interfaces/worklenz-response";
import { ServerResponse } from "../../models/server-response";
import { DATE_RANGES, TASK_PRIORITY_COLOR_ALPHA } from "../../shared/constants";
import { formatDuration, getColor, int } from "../../shared/utils";
import ReportingControllerBase from "./reporting-controller-base";
import ReportingControllerBaseWithTimezone from "./reporting-controller-base-with-timezone";
import Excel from "exceljs";
export default class ReportingMembersController extends ReportingControllerBase {
export default class ReportingMembersController extends ReportingControllerBaseWithTimezone {
protected static getPercentage(n: number, total: number) {
return +(n ? (n / total) * 100 : 0).toFixed();
}
protected static getCurrentTeamId(req: IWorkLenzRequest): string | null {
return req.user?.team_id ?? null;
}
public static convertMinutesToHoursAndMinutes(totalMinutes: number) {
const hours = Math.floor(totalMinutes / 60);
const minutes = totalMinutes % 60;
return `${hours}h ${minutes}m`;
}
public static convertSecondsToHoursAndMinutes(seconds: number) {
const hours = Math.floor(seconds / 3600);
const minutes = Math.floor((seconds % 3600) / 60);
return `${hours}h ${minutes}m`;
}
protected static formatEndDate(endDate: string) {
const end = moment(endDate).format("YYYY-MM-DD");
const fEndDate = moment(end);
return fEndDate;
}
protected static formatCurrentDate() {
const current = moment().format("YYYY-MM-DD");
const fCurrentDate = moment(current);
return fCurrentDate;
}
protected static getDaysLeft(endDate: string): number | null {
if (!endDate) return null;
const fCurrentDate = this.formatCurrentDate();
const fEndDate = this.formatEndDate(endDate);
return fEndDate.diff(fCurrentDate, "days");
}
protected static isOverdue(endDate: string): boolean {
if (!endDate) return false;
const fCurrentDate = this.formatCurrentDate();
const fEndDate = this.formatEndDate(endDate);
return fEndDate.isBefore(fCurrentDate);
}
protected static isToday(endDate: string): boolean {
if (!endDate) return false;
const fCurrentDate = this.formatCurrentDate();
const fEndDate = this.formatEndDate(endDate);
return fEndDate.isSame(fCurrentDate);
}
private static async getMembers(
teamId: string, searchQuery = "",
@@ -487,7 +546,9 @@ export default class ReportingMembersController extends ReportingControllerBase
dateRange = date_range.split(",");
}
const durationClause = ReportingMembersController.getDateRangeClauseMembers(duration as string || DATE_RANGES.LAST_WEEK, dateRange, "twl");
// Get user timezone for proper date filtering
const userTimezone = await this.getUserTimezone(req.user?.id as string);
const durationClause = this.getDateRangeClauseWithTimezone(duration as string || DATE_RANGES.LAST_WEEK, dateRange, userTimezone);
const minMaxDateClause = this.getMinMaxDates(duration as string || DATE_RANGES.LAST_WEEK, dateRange, "task_work_log");
const memberName = (req.query.member_name as string)?.trim() || null;
@@ -1038,7 +1099,9 @@ export default class ReportingMembersController extends ReportingControllerBase
public static async getMemberTimelogs(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
const { team_member_id, team_id, duration, date_range, archived, billable } = req.body;
const durationClause = ReportingMembersController.getDateRangeClauseMembers(duration || DATE_RANGES.LAST_WEEK, date_range, "twl");
// Get user timezone for proper date filtering
const userTimezone = await this.getUserTimezone(req.user?.id as string);
const durationClause = this.getDateRangeClauseWithTimezone(duration || DATE_RANGES.LAST_WEEK, date_range, userTimezone);
const minMaxDateClause = this.getMinMaxDates(duration || DATE_RANGES.LAST_WEEK, date_range, "task_work_log");
const billableQuery = this.buildBillableQuery(billable);
@@ -1230,8 +1293,8 @@ public static async getSingleMemberProjects(req: IWorkLenzRequest, res: IWorkLen
row.actual_time = int(row.actual_time);
row.estimated_time_string = this.convertMinutesToHoursAndMinutes(int(row.estimated_time));
row.actual_time_string = this.convertSecondsToHoursAndMinutes(int(row.actual_time));
row.days_left = ReportingControllerBase.getDaysLeft(row.end_date);
row.is_overdue = ReportingControllerBase.isOverdue(row.end_date);
row.days_left = this.getDaysLeft(row.end_date);
row.is_overdue = this.isOverdue(row.end_date);
if (row.days_left && row.is_overdue) {
row.days_left = row.days_left.toString().replace(/-/g, "");
}