Added Break Hours data in attendance report
This commit is contained in:
parent
457867f3b0
commit
ebbfb0c445
|
|
@ -66,8 +66,8 @@ class AttendanceReport(models.Model):
|
||||||
%s::date,
|
%s::date,
|
||||||
interval '1 day'
|
interval '1 day'
|
||||||
)::date AS date
|
)::date AS date
|
||||||
),
|
),
|
||||||
employee_dates AS (
|
employee_dates AS (
|
||||||
SELECT
|
SELECT
|
||||||
emp.id AS employee_id,
|
emp.id AS employee_id,
|
||||||
emp.name AS employee_name,
|
emp.name AS employee_name,
|
||||||
|
|
@ -86,8 +86,8 @@ class AttendanceReport(models.Model):
|
||||||
WHERE
|
WHERE
|
||||||
emp.active = true
|
emp.active = true
|
||||||
""" + (" AND " + " AND ".join(emp_date_conditions) if emp_date_conditions else "") + """
|
""" + (" AND " + " AND ".join(emp_date_conditions) if emp_date_conditions else "") + """
|
||||||
),
|
),
|
||||||
daily_checkins AS (
|
daily_checkins AS (
|
||||||
SELECT
|
SELECT
|
||||||
emp.id,
|
emp.id,
|
||||||
emp.name,
|
emp.name,
|
||||||
|
|
@ -97,7 +97,8 @@ class AttendanceReport(models.Model):
|
||||||
at.worked_hours,
|
at.worked_hours,
|
||||||
ROW_NUMBER() OVER (PARTITION BY emp.id, DATE(at.check_in AT TIME ZONE 'UTC' AT TIME ZONE 'Asia/Kolkata') ORDER BY at.check_in) AS first_checkin_row,
|
ROW_NUMBER() OVER (PARTITION BY emp.id, DATE(at.check_in AT TIME ZONE 'UTC' AT TIME ZONE 'Asia/Kolkata') ORDER BY at.check_in) AS first_checkin_row,
|
||||||
ROW_NUMBER() OVER (PARTITION BY emp.id, DATE(at.check_in AT TIME ZONE 'UTC' AT TIME ZONE 'Asia/Kolkata') ORDER BY at.check_in DESC) AS last_checkout_row,
|
ROW_NUMBER() OVER (PARTITION BY emp.id, DATE(at.check_in AT TIME ZONE 'UTC' AT TIME ZONE 'Asia/Kolkata') ORDER BY at.check_in DESC) AS last_checkout_row,
|
||||||
dep.name->>'en_US' AS department
|
dep.name->>'en_US' AS department,
|
||||||
|
LEAD(at.check_in AT TIME ZONE 'UTC' AT TIME ZONE 'Asia/Kolkata') OVER (PARTITION BY emp.id, DATE(at.check_in AT TIME ZONE 'UTC' AT TIME ZONE 'Asia/Kolkata') ORDER BY at.check_in) AS next_check_in
|
||||||
FROM
|
FROM
|
||||||
hr_attendance at
|
hr_attendance at
|
||||||
LEFT JOIN
|
LEFT JOIN
|
||||||
|
|
@ -106,8 +107,8 @@ class AttendanceReport(models.Model):
|
||||||
hr_department dep ON emp.department_id = dep.id
|
hr_department dep ON emp.department_id = dep.id
|
||||||
WHERE
|
WHERE
|
||||||
""" + " AND ".join(checkin_conditions) + """
|
""" + " AND ".join(checkin_conditions) + """
|
||||||
),
|
),
|
||||||
attendance_summary AS (
|
attendance_summary AS (
|
||||||
SELECT
|
SELECT
|
||||||
id,
|
id,
|
||||||
name,
|
name,
|
||||||
|
|
@ -115,13 +116,17 @@ class AttendanceReport(models.Model):
|
||||||
MAX(CASE WHEN first_checkin_row = 1 THEN check_in END) AS first_check_in,
|
MAX(CASE WHEN first_checkin_row = 1 THEN check_in END) AS first_check_in,
|
||||||
MAX(CASE WHEN last_checkout_row = 1 THEN check_out END) AS last_check_out,
|
MAX(CASE WHEN last_checkout_row = 1 THEN check_out END) AS last_check_out,
|
||||||
SUM(worked_hours) AS total_worked_hours,
|
SUM(worked_hours) AS total_worked_hours,
|
||||||
|
-- 👇 Calculate total break time (sum of gaps between check_out and next check_in)
|
||||||
|
SUM(
|
||||||
|
EXTRACT(EPOCH FROM (next_check_in - check_out)) / 3600
|
||||||
|
) FILTER (WHERE next_check_in IS NOT NULL AND check_out IS NOT NULL) AS break_hours,
|
||||||
department
|
department
|
||||||
FROM
|
FROM
|
||||||
daily_checkins
|
daily_checkins
|
||||||
GROUP BY
|
GROUP BY
|
||||||
id, name, date, department
|
id, name, date, department
|
||||||
),
|
),
|
||||||
leave_data AS (
|
leave_data AS (
|
||||||
SELECT
|
SELECT
|
||||||
hl.employee_id,
|
hl.employee_id,
|
||||||
hl.date_from AT TIME ZONE 'UTC' AT TIME ZONE 'Asia/Kolkata' AS leave_start,
|
hl.date_from AT TIME ZONE 'UTC' AT TIME ZONE 'Asia/Kolkata' AS leave_start,
|
||||||
|
|
@ -137,8 +142,8 @@ class AttendanceReport(models.Model):
|
||||||
WHERE
|
WHERE
|
||||||
hl.state IN ('validate', 'confirm', 'validate1')
|
hl.state IN ('validate', 'confirm', 'validate1')
|
||||||
AND (hl.date_from, hl.date_to) OVERLAPS (%s::timestamp, %s::timestamp)
|
AND (hl.date_from, hl.date_to) OVERLAPS (%s::timestamp, %s::timestamp)
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
ed.employee_id AS id,
|
ed.employee_id AS id,
|
||||||
ed.employee_name AS name,
|
ed.employee_name AS name,
|
||||||
ed.date,
|
ed.date,
|
||||||
|
|
@ -147,6 +152,7 @@ class AttendanceReport(models.Model):
|
||||||
COALESCE(ats.first_check_in, NULL) AS first_check_in,
|
COALESCE(ats.first_check_in, NULL) AS first_check_in,
|
||||||
COALESCE(ats.last_check_out, NULL) AS last_check_out,
|
COALESCE(ats.last_check_out, NULL) AS last_check_out,
|
||||||
COALESCE(ats.total_worked_hours, 0) AS total_worked_hours,
|
COALESCE(ats.total_worked_hours, 0) AS total_worked_hours,
|
||||||
|
COALESCE(ats.break_hours, 0) AS total_break_hours,
|
||||||
ed.department,
|
ed.department,
|
||||||
CASE
|
CASE
|
||||||
WHEN ld.leave_type IS NOT NULL AND ld.is_half_day THEN 'on Half day ' || ld.leave_type
|
WHEN ld.leave_type IS NOT NULL AND ld.is_half_day THEN 'on Half day ' || ld.leave_type
|
||||||
|
|
@ -154,18 +160,17 @@ class AttendanceReport(models.Model):
|
||||||
WHEN ats.first_check_in IS NOT NULL THEN 'Present'
|
WHEN ats.first_check_in IS NOT NULL THEN 'Present'
|
||||||
ELSE 'NA'
|
ELSE 'NA'
|
||||||
END AS status
|
END AS status
|
||||||
FROM
|
FROM
|
||||||
employee_dates ed
|
employee_dates ed
|
||||||
LEFT JOIN
|
LEFT JOIN
|
||||||
attendance_summary ats ON ed.employee_id = ats.id AND ed.date = ats.date
|
attendance_summary ats ON ed.employee_id = ats.id AND ed.date = ats.date
|
||||||
LEFT JOIN
|
LEFT JOIN
|
||||||
leave_data ld ON ed.employee_id = ld.employee_id
|
leave_data ld ON ed.employee_id = ld.employee_id
|
||||||
AND ed.date >= DATE(ld.leave_start)
|
AND ed.date >= DATE(ld.leave_start)
|
||||||
AND ed.date <= DATE(ld.leave_end)
|
AND ed.date <= DATE(ld.leave_end)
|
||||||
ORDER BY
|
ORDER BY
|
||||||
ed.employee_id, ed.date;
|
ed.employee_id, ed.date;
|
||||||
"""
|
"""
|
||||||
|
|
||||||
# Combine all parameters in the correct order:
|
# Combine all parameters in the correct order:
|
||||||
# 1. date_range params (start_date_str, end_date_str)
|
# 1. date_range params (start_date_str, end_date_str)
|
||||||
# 2. employee_dates params (emp_date_params)
|
# 2. employee_dates params (emp_date_params)
|
||||||
|
|
@ -196,6 +201,7 @@ class AttendanceReport(models.Model):
|
||||||
'check_in': r['first_check_in'],
|
'check_in': r['first_check_in'],
|
||||||
'check_out': r['last_check_out'],
|
'check_out': r['last_check_out'],
|
||||||
'worked_hours': float(r['total_worked_hours']) if r['total_worked_hours'] is not None else 0.0,
|
'worked_hours': float(r['total_worked_hours']) if r['total_worked_hours'] is not None else 0.0,
|
||||||
|
'break_hours': float(r['total_break_hours']) if r['total_break_hours'] is not None else 0.0,
|
||||||
'status': r['status']
|
'status': r['status']
|
||||||
})
|
})
|
||||||
|
|
||||||
|
|
@ -213,7 +219,6 @@ class AttendanceReport(models.Model):
|
||||||
attendance_data = self.get_attendance_report(department_id, employee_id, start_date, end_date)
|
attendance_data = self.get_attendance_report(department_id, employee_id, start_date, end_date)
|
||||||
if not attendance_data:
|
if not attendance_data:
|
||||||
raise UserError("No data to export!")
|
raise UserError("No data to export!")
|
||||||
|
|
||||||
# Create workbook and sheet
|
# Create workbook and sheet
|
||||||
workbook = xlwt.Workbook(encoding='utf-8')
|
workbook = xlwt.Workbook(encoding='utf-8')
|
||||||
sheet = workbook.add_sheet('Attendance Report')
|
sheet = workbook.add_sheet('Attendance Report')
|
||||||
|
|
@ -281,28 +286,26 @@ class AttendanceReport(models.Model):
|
||||||
)
|
)
|
||||||
|
|
||||||
# Set column widths (in units of 1/256 of a character width)
|
# Set column widths (in units of 1/256 of a character width)
|
||||||
col_widths = [6000, 8000, 7000, 3000, 4000, 5000, 5000, 4000, 5000]
|
col_widths = [6000, 8000, 7000, 3000, 4000, 5000, 5000, 4000, 4000, 5000]
|
||||||
for i, width in enumerate(col_widths):
|
for i, width in enumerate(col_widths):
|
||||||
sheet.col(i).width = width
|
sheet.col(i).width = width
|
||||||
|
|
||||||
# Write title
|
# Write title
|
||||||
sheet.write_merge(0, 0, 0, 8, 'ATTENDANCE REPORT', title_style)
|
sheet.write_merge(0, 0, 0, 9, 'ATTENDANCE REPORT', title_style)
|
||||||
|
|
||||||
# Write date range
|
# Write date range
|
||||||
date_range = f"From: {start_date} To: {end_date}"
|
date_range = f"From: {start_date} To: {end_date}"
|
||||||
sheet.write_merge(1, 1, 0, 8, date_range, xlwt.easyxf(
|
sheet.write_merge(1, 1, 0, 9, date_range, xlwt.easyxf(
|
||||||
'font: italic on; align: horiz center'
|
'font: italic on; align: horiz center'
|
||||||
))
|
))
|
||||||
|
|
||||||
# Write headers
|
# Write headers
|
||||||
headers = [
|
headers = [
|
||||||
'Department', 'Employee Name','Week', 'Date', 'Day',
|
'Department', 'Employee Name','Week', 'Date', 'Day',
|
||||||
'Check-in', 'Check-out', 'Worked Hours', 'Status'
|
'Check-in', 'Check-out', 'Worked Hours', 'Break Hours', 'Status'
|
||||||
]
|
]
|
||||||
|
|
||||||
for col_num, header in enumerate(headers):
|
for col_num, header in enumerate(headers):
|
||||||
sheet.write(2, col_num, header, header_style)
|
sheet.write(2, col_num, header, header_style)
|
||||||
|
|
||||||
# Write data rows
|
# Write data rows
|
||||||
current_employee = None
|
current_employee = None
|
||||||
for row_num, record in enumerate(attendance_data, start=3):
|
for row_num, record in enumerate(attendance_data, start=3):
|
||||||
|
|
@ -345,11 +348,16 @@ class AttendanceReport(models.Model):
|
||||||
else:
|
else:
|
||||||
sheet.write(row_num, 7, str(record['worked_hours']), data_style)
|
sheet.write(row_num, 7, str(record['worked_hours']), data_style)
|
||||||
|
|
||||||
sheet.write(row_num, 8, record['status'], status_style)
|
# Break hours formatting
|
||||||
|
if isinstance(record['break_hours'], (float, int)):
|
||||||
|
sheet.write(row_num, 8, float(record['break_hours']), hours_style)
|
||||||
|
else:
|
||||||
|
sheet.write(row_num, 8, str(record['break_hours']), data_style)
|
||||||
|
|
||||||
|
sheet.write(row_num, 9, record['status'], status_style)
|
||||||
# Add freeze panes (headers will stay visible when scrolling)
|
# Add freeze panes (headers will stay visible when scrolling)
|
||||||
sheet.set_panes_frozen(True)
|
sheet.set_panes_frozen(True)
|
||||||
sheet.set_horz_split_pos(4) # After row 3 (headers)
|
sheet.set_horz_split_pos(3) # After row 3 (headers)
|
||||||
sheet.set_vert_split_pos(0) # No vertical split
|
sheet.set_vert_split_pos(0) # No vertical split
|
||||||
|
|
||||||
# Save to buffer
|
# Save to buffer
|
||||||
|
|
|
||||||
|
|
@ -206,7 +206,7 @@ export default class AttendanceReport extends Component {
|
||||||
}
|
}
|
||||||
|
|
||||||
async generateReport() {
|
async generateReport() {
|
||||||
|
debugger;
|
||||||
let { startDate, endDate, selectedEmployeeIds } = this.state;
|
let { startDate, endDate, selectedEmployeeIds } = this.state;
|
||||||
startDate = $('#from_date').val()
|
startDate = $('#from_date').val()
|
||||||
endDate = $('#to_date').val()
|
endDate = $('#to_date').val()
|
||||||
|
|
@ -231,7 +231,7 @@ export default class AttendanceReport extends Component {
|
||||||
// Fetch the attendance data based on the date range and selected employees
|
// Fetch the attendance data based on the date range and selected employees
|
||||||
// const attendanceData = await this.orm.searchRead('hr.attendance', domain, ['employee_id', 'check_in', 'check_out', 'worked_hours']);
|
// const attendanceData = await this.orm.searchRead('hr.attendance', domain, ['employee_id', 'check_in', 'check_out', 'worked_hours']);
|
||||||
const attendanceData = await this.orm.call('attendance.report','get_attendance_report',[$('#dept').val(),$('#emp').val(),startDate,endDate]);
|
const attendanceData = await this.orm.call('attendance.report','get_attendance_report',[$('#dept').val(),$('#emp').val(),startDate,endDate]);
|
||||||
|
debugger;
|
||||||
// Group data by employee_id
|
// Group data by employee_id
|
||||||
const rawGroups = this.groupDataByEmployee(attendanceData);
|
const rawGroups = this.groupDataByEmployee(attendanceData);
|
||||||
|
|
||||||
|
|
|
||||||
|
|
@ -65,6 +65,7 @@
|
||||||
<th>Check In</th>
|
<th>Check In</th>
|
||||||
<th>Check Out</th>
|
<th>Check Out</th>
|
||||||
<th>Worked Hours</th>
|
<th>Worked Hours</th>
|
||||||
|
<th>Break Hours</th>
|
||||||
<th>Status</th>
|
<th>Status</th>
|
||||||
</tr>
|
</tr>
|
||||||
</thead>
|
</thead>
|
||||||
|
|
@ -78,7 +79,16 @@
|
||||||
<td><t t-esc="data.day_name"/></td>
|
<td><t t-esc="data.day_name"/></td>
|
||||||
<td><t t-esc="data.check_in"/></td>
|
<td><t t-esc="data.check_in"/></td>
|
||||||
<td><t t-esc="data.check_out"/></td>
|
<td><t t-esc="data.check_out"/></td>
|
||||||
<td><t t-esc="data.worked_hours"/></td>
|
<td>
|
||||||
|
<t t-set="hours" t-value="Math.floor(data.worked_hours)"/>
|
||||||
|
<t t-set="minutes" t-value="Math.round((data.worked_hours - hours) * 60)"/>
|
||||||
|
<t t-esc="hours"/>:<t t-esc="minutes >= 10 ? minutes : '0' + minutes"/>
|
||||||
|
</td>
|
||||||
|
<td>
|
||||||
|
<t t-set="hours" t-value="Math.floor(data.break_hours)"/>
|
||||||
|
<t t-set="minutes" t-value="Math.round((data.break_hours - hours) * 60)"/>
|
||||||
|
<t t-esc="hours"/>:<t t-esc="minutes >= 10 ? minutes : '0' + minutes"/>
|
||||||
|
</td>
|
||||||
<td><t t-esc="data.status"/></td>
|
<td><t t-esc="data.status"/></td>
|
||||||
</tr>
|
</tr>
|
||||||
</tbody>
|
</tbody>
|
||||||
|
|
|
||||||
Loading…
Reference in New Issue