Files
arbeitszeitmessung/DB/initdb/01_create_tables.sql
tom 7670efa99b
Some checks failed
arbeitszeitmessung/pipeline/head There was a failure building this commit
added control tables (s_*) + working on implementing absence and booking types
2025-08-02 08:55:40 +02:00

114 lines
3.7 KiB
PL/PgSQL

-- ----------------------------
-- Table structure for anwesenheit
-- ----------------------------
DROP TABLE IF EXISTS "anwesenheit";
CREATE TABLE "anwesenheit" (
"counter_id" bigserial PRIMARY KEY,
"timestamp" timestamptz(6) DEFAULT CURRENT_TIMESTAMP,
"card_uid" varchar(255),
"check_in_out" int2,
"geraet_id" int2,
"manuelle_buchung" bool
);
COMMENT ON COLUMN "anwesenheit"."check_in_out" IS '1=Check In 2=Check Out , 3=Check in Manuell, 4=Check out manuell255=Automatic Check Out';
COMMENT ON COLUMN "anwesenheit"."geraet_id" IS 'ID des Lesegerätes';
-- ----------------------------
-- Table structure for anwesenheitstypen
-- ----------------------------
DROP TABLE IF EXISTS "s_anwesenheit_typen";
CREATE TABLE "s_anwesenheit_typen" (
"anwesenheit_id" int2 PRIMARY KEY,
"anwesenheit_name" varchar(255)
);
-- ----------------------------
-- Table structure for personal_daten
-- ----------------------------
DROP TABLE IF EXISTS "s_personal_daten";
CREATE TABLE "s_personal_daten" (
"personal_nummer" int4 NOT NULL PRIMARY KEY,
"aktiv_beschaeftigt" bool,
"vorname" varchar(255),
"nachname" varchar(255),
"geburtsdatum" date,
"plz" varchar(255),
"adresse" varchar(255),
"geschlecht" int2,
"card_uid" varchar(255),
"hauptbeschaeftigungs_ort" int2,
"arbeitszeit_per_tag" float4,
"arbeitszeit_min_start" time(6),
"arbeitszeit_max_ende" time(6),
"vorgesetzter_pers_nr" int4
);
COMMENT ON COLUMN "s_personal_daten"."geschlecht" IS '1==weiblich, 2==maennlich, 3==divers';
DROP TABLE IF EXISTS "user_password";
CREATE TABLE "user_password" (
"personal_nummer" int4 NOT NULL PRIMARY KEY,
"pass_hash" TEXT,
"zuletzt_geandert" timestamp(6) DEFAULT CURRENT_TIMESTAMP
);
-- update Funktion für pass_hash
CREATE OR REPLACE FUNCTION update_zuletzt_geandert()
RETURNS TRIGGER AS $$
BEGIN
-- Nur wenn hash geändert wurde
IF NEW.pass_hash IS DISTINCT FROM OLD.pass_hash THEN
NEW.zuletzt_geandert = now();
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER pass_hash_update
BEFORE UPDATE ON user_password
FOR EACH ROW
EXECUTE FUNCTION update_zuletzt_geandert();
-- audittabelle für arbeitsstunden bestätigung
DROP TABLE IF EXISTS "wochen_report";
CREATE TABLE "wochen_report" (
"id" serial PRIMARY KEY,
"personal_nummer" int4,
"woche_start" date,
"bestaetigt" bool DEFAULT FALSE,
UNIQUE ("personal_nummer", "woche_start")
);
DROP TABLE IF EXISTS "abwesenheit";
CREATE TABLE "abwesenheit" (
"counter_id" bigserial PRIMARY KEY,
"card_uid" varchar(255),
"abwesenheit_typ" int2,
"datum" timestamptz(6) DEFAULT NOW()::DATE
);
DROP TABLE IF EXISTS "s_abwesenheit_typen";
CREATE TABLE "s_abwesenheit_typen" (
"abwesenheit_id" int2 PRIMARY KEY,
"abwesenheit_name" varchar(255)
);
-- Adds crypto extension
CREATE EXTENSION IF NOT EXISTS pgcrypto;
-- ----------------------------
-- Insert example data
-- ----------------------------
INSERT INTO "s_personal_daten" ("personal_nummer", "aktiv_beschaeftigt", "vorname", "nachname", "geburtsdatum", "plz", "adresse", "geschlecht", "card_uid", "hauptbeschaeftigungs_ort", "arbeitszeit_per_tag", "arbeitszeit_min_start", "arbeitszeit_max_ende", "vorgesetzter_pers_nr") VALUES
(123, 't', 'Max', 'Mustermann', '2003-02-01', '08963', 'Altenburger Str. 44A', 1, 'acde-edca', 1, 7.5, '07:00:00', '20:00:00', 0);
INSERT INTO "user_password" ("personal_nummer", "pass_hash") VALUES
(123, crypt('max_pass', gen_salt('bf')));
INSERT INTO "s_anwesenheit_typen" ("anwesenheit_id", "anwesenheit_name") VALUES (1, 'Büro');
INSERT INTO "s_abwesenheit_typen" ("abwesenheit_id", "abwesenheit_name") VALUES (1, 'Urlaub'), (2, 'Krank'), (3, 'Kurzarbeit');