Files
arbeitszeitmessung/db.sql

149 lines
4.4 KiB
SQL

-- @block create table anwesenheit
CREATE TABLE "public"."anwesenheit" (
"counter_id" SERIAL PRIMARY KEY,
"timestamp" timestamp(6) DEFAULT CURRENT_TIMESTAMP,
"card_uid" varchar(255) COLLATE "pg_catalog"."default",
"check_in_out" int2,
"geraet_id" int2
);
COMMENT ON COLUMN "public"."anwesenheit"."check_in_out" IS '1=Check In 2=Check Out 254=Automatic Check Out';
COMMENT ON COLUMN "public"."anwesenheit"."geraet_id" IS 'ID des Lesegerätes';
-- @block create table personaldaten
CREATE TABLE "public"."personal_daten" (
"personal_nummer" SERIAL PRIMARY KEY,
"akiv_beschaeftig" bool,
"vorname" varchar COLLATE "pg_catalog"."default",
"nachname" varchar COLLATE "pg_catalog"."default",
"geburtsdatum" date,
"plz" varchar COLLATE "pg_catalog"."default",
"adresse" varchar COLLATE "pg_catalog"."default",
"geschlecht" numeric,
"card_uid" varchar(255) COLLATE "pg_catalog"."default",
"hauptbeschaeftigung_ort" int2
);
COMMENT ON COLUMN "public"."personal_daten"."akiv_beschaeftig" IS 'derzeit aktiv beschaeftigt : 1';
COMMENT ON COLUMN "public"."personal_daten"."geschlecht" IS 'w:1 m:2 div:3 kA:null ';
COMMENT ON COLUMN "public"."personal_daten"."card_uid" IS 'RFID-Karten-UID';
COMMENT ON COLUMN "public"."personal_daten"."hauptbeschaeftigung_ort" IS 'Chemnitz:1 Sayda:2';
-- @block drop tables
DROP TABLE IF EXISTS "public"."anwesenheit";
DROP TABLE IF EXISTS "public"."personal_daten";
-- @block insert into personal_daten
INSERT INTO personal_daten (
personal_nummer,
akiv_beschaeftig,
vorname,
nachname,
geburtsdatum,
plz,
adresse,
geschlecht,
card_uid,
hauptbeschaeftigung_ort
)
VALUES (
123,
true,
'Max',
'Mustermann',
now(),
'00815',
'Musterstrasse',
1,
'test_card',
'1'
);
-- @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;