CHANGE: added team view, with submitted bookings for team members and send form for own bookings
This commit is contained in:
84
db.sql
84
db.sql
@@ -62,3 +62,87 @@ VALUES (
|
||||
-- @block select
|
||||
SELECT *
|
||||
FROM personal_daten;
|
||||
|
||||
-- @block work and pause time
|
||||
WITH ordered_bookings AS (
|
||||
SELECT
|
||||
timestamp,
|
||||
check_in_out,
|
||||
LAG(timestamp) OVER (PARTITION BY card_uid ORDER BY timestamp) AS prev_timestamp,
|
||||
LAG(check_in_out) OVER (PARTITION BY card_uid ORDER BY timestamp) AS prev_check
|
||||
FROM anwesenheit
|
||||
WHERE card_uid = 'acde-edca' -- Replace with actual card_uid
|
||||
AND timestamp::DATE = '2025-02-23' -- Replace with actual date
|
||||
)
|
||||
SELECT
|
||||
-- Total work time: Duration between check-in (1,3) and check-out (2,4,254)
|
||||
COALESCE(
|
||||
SUM(
|
||||
CASE
|
||||
WHEN prev_check IN (1, 3) AND check_in_out IN (2, 4, 254)
|
||||
THEN timestamp - prev_timestamp
|
||||
ELSE INTERVAL '0'
|
||||
END
|
||||
), INTERVAL '0'
|
||||
) AS total_work,
|
||||
|
||||
-- Total pause time: Duration between check-out (2,4,254) and next check-in (1,3)
|
||||
COALESCE(
|
||||
SUM(
|
||||
CASE
|
||||
WHEN prev_check IN (2, 4, 254) AND check_in_out IN (1, 3)
|
||||
THEN timestamp - prev_timestamp
|
||||
ELSE INTERVAL '0'
|
||||
END
|
||||
), INTERVAL '0'
|
||||
) AS total_pause
|
||||
|
||||
FROM ordered_bookings;
|
||||
|
||||
-- @block work and pause time multi day
|
||||
WITH ordered_bookings AS (
|
||||
SELECT
|
||||
timestamp::DATE AS work_date, -- Extract date for grouping
|
||||
timestamp,
|
||||
check_in_out,
|
||||
LAG(timestamp) OVER (
|
||||
PARTITION BY card_uid, timestamp::DATE -- Reset for each day
|
||||
ORDER BY timestamp
|
||||
) AS prev_timestamp,
|
||||
LAG(check_in_out) OVER (
|
||||
PARTITION BY card_uid, timestamp::DATE
|
||||
ORDER BY timestamp
|
||||
) AS prev_check
|
||||
FROM anwesenheit
|
||||
WHERE card_uid = $1 -- Replace with actual card_uid
|
||||
AND timestamp::DATE >= $2 -- Set date range
|
||||
AND timestamp::DATE < $3
|
||||
)
|
||||
SELECT
|
||||
work_date,
|
||||
|
||||
-- Total work time per day
|
||||
COALESCE(
|
||||
EXTRACT(EPOCH FROM SUM(
|
||||
CASE
|
||||
WHEN prev_check IN (1, 3) AND check_in_out IN (2, 4, 254)
|
||||
THEN timestamp - prev_timestamp
|
||||
ELSE INTERVAL '0'
|
||||
END
|
||||
)), 0
|
||||
) AS total_work,
|
||||
|
||||
-- Extract total pause time in seconds
|
||||
COALESCE(
|
||||
EXTRACT(EPOCH FROM SUM(
|
||||
CASE
|
||||
WHEN prev_check IN (2, 4, 254) AND check_in_out IN (1, 3)
|
||||
THEN timestamp - prev_timestamp
|
||||
ELSE INTERVAL '0'
|
||||
END
|
||||
)), 0
|
||||
) AS total_pause
|
||||
|
||||
FROM ordered_bookings
|
||||
GROUP BY work_date
|
||||
ORDER BY work_date;
|
||||
|
||||
Reference in New Issue
Block a user