-- TimeClock v3 - Datenbankschema -- Basierend auf stechuhr2 Struktur -- ============================================================================ -- Basis-Tabellen -- ============================================================================ -- State Tabelle (Bundesländer/Regionen) CREATE TABLE IF NOT EXISTS `state` ( `id` bigint NOT NULL AUTO_INCREMENT, `version` int NOT NULL DEFAULT 0, `state_name` text NOT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- User Tabelle CREATE TABLE IF NOT EXISTS `user` ( `id` bigint NOT NULL AUTO_INCREMENT, `version` int NOT NULL DEFAULT 0, `last_change` datetime DEFAULT NULL, `role` int NOT NULL DEFAULT 0, `daily_hours` int NOT NULL DEFAULT 8, `state_id` bigint DEFAULT NULL, `full_name` text NOT NULL, `week_hours` int NOT NULL DEFAULT 40, `week_workdays` int NOT NULL DEFAULT 5, `preferred_title_type` int NOT NULL DEFAULT 0, `overtime_offset_minutes` int DEFAULT 0 COMMENT 'Überstunden-Startwert in Minuten (z.B. Übertrag aus altem System)', PRIMARY KEY (`id`), KEY `fk_user_state` (`state_id`), CONSTRAINT `fk_user_state` FOREIGN KEY (`state_id`) REFERENCES `state` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ============================================================================ -- Authentifizierung -- ============================================================================ -- Auth Info Tabelle CREATE TABLE IF NOT EXISTS `auth_info` ( `id` bigint NOT NULL AUTO_INCREMENT, `version` int NOT NULL DEFAULT 0, `user_id` bigint DEFAULT NULL, `password_hash` varchar(100) NOT NULL, `password_method` varchar(20) NOT NULL, `password_salt` varchar(60) NOT NULL, `status` int NOT NULL DEFAULT 1, `failed_login_attempts` int NOT NULL DEFAULT 0, `last_login_attempt` datetime DEFAULT NULL, `email` varchar(256) NOT NULL, `unverified_email` varchar(256) NOT NULL DEFAULT '', `email_token` varchar(64) NOT NULL DEFAULT '', `email_token_expires` datetime DEFAULT NULL, `email_token_role` int NOT NULL DEFAULT 0, PRIMARY KEY (`id`), UNIQUE KEY `email_unique` (`email`), KEY `fk_auth_info_user` (`user_id`), CONSTRAINT `fk_auth_info_user` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Auth Token Tabelle CREATE TABLE IF NOT EXISTS `auth_token` ( `id` bigint NOT NULL AUTO_INCREMENT, `version` int NOT NULL DEFAULT 0, `auth_info_id` bigint DEFAULT NULL, `value` varchar(64) NOT NULL, `expires` datetime DEFAULT NULL, PRIMARY KEY (`id`), KEY `fk_auth_token_auth_info` (`auth_info_id`), CONSTRAINT `fk_auth_token_auth_info` FOREIGN KEY (`auth_info_id`) REFERENCES `auth_info` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Auth Identity Tabelle CREATE TABLE IF NOT EXISTS `auth_identity` ( `id` bigint NOT NULL, `version` int NOT NULL DEFAULT 0, `auth_info_id` bigint DEFAULT NULL, `provider` varchar(64) NOT NULL, `identity` varchar(512) NOT NULL, KEY `fk_auth_identity_auth_info` (`auth_info_id`), CONSTRAINT `fk_auth_identity_auth_info` FOREIGN KEY (`auth_info_id`) REFERENCES `auth_info` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ============================================================================ -- Zeiterfassung -- ============================================================================ -- Worklog Tabelle (Haupttabelle für Zeiteinträge) CREATE TABLE IF NOT EXISTS `worklog` ( `id` bigint NOT NULL AUTO_INCREMENT, `version` int NOT NULL DEFAULT 0, `user_id` bigint NOT NULL, `state` text NOT NULL, `tstamp` datetime DEFAULT NULL, `relatedTo_id` bigint DEFAULT NULL, PRIMARY KEY (`id`), KEY `fk_worklog_relatedTo` (`relatedTo_id`), KEY `worklog_tstamp_IDX` (`tstamp`) USING BTREE, KEY `worklog_user_id_IDX` (`user_id`,`tstamp`) USING BTREE, CONSTRAINT `fk_worklog_relatedTo` FOREIGN KEY (`relatedTo_id`) REFERENCES `worklog` (`id`), CONSTRAINT `fk_worklog_user` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Timefix Tabelle (Zeitkorrekturen) CREATE TABLE IF NOT EXISTS `timefix` ( `id` bigint NOT NULL AUTO_INCREMENT, `version` int NOT NULL DEFAULT 0, `user_id` bigint DEFAULT NULL, `worklog_id` bigint DEFAULT NULL, `fix_type` text NOT NULL, `fix_date_time` datetime DEFAULT NULL, PRIMARY KEY (`id`), KEY `fk_timefix_user` (`user_id`), KEY `fk_timefix_worklog` (`worklog_id`), KEY `timefix_fix_date_time_IDX` (`fix_date_time`) USING BTREE, CONSTRAINT `fk_timefix_user` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`), CONSTRAINT `fk_timefix_worklog` FOREIGN KEY (`worklog_id`) REFERENCES `worklog` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ============================================================================ -- Arbeitszeit-Einstellungen -- ============================================================================ -- Weekly Worktime Tabelle CREATE TABLE IF NOT EXISTS `weekly_worktime` ( `id` int NOT NULL AUTO_INCREMENT, `weekly_work_time` double NOT NULL DEFAULT 40, `starting_from` date DEFAULT NULL, `ends_at` date DEFAULT NULL, `user_id` int DEFAULT NULL, `version` int NOT NULL DEFAULT 0, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- User Settings Type Tabelle CREATE TABLE IF NOT EXISTS `user_settings_type` ( `id` int NOT NULL AUTO_INCREMENT, `name` varchar(100) NOT NULL, `version` int NOT NULL DEFAULT 0, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- User Setting Tabelle CREATE TABLE IF NOT EXISTS `user_setting` ( `id` int NOT NULL AUTO_INCREMENT, `user_id` bigint NOT NULL, `setting_id` int NOT NULL, `begin_date` date DEFAULT NULL, `end_date` date DEFAULT NULL, `value` varchar(100) DEFAULT NULL, `version` int NOT NULL DEFAULT 0, PRIMARY KEY (`id`), KEY `user_setting_user_FK` (`user_id`), KEY `user_setting_user_settings_type_FK` (`setting_id`), CONSTRAINT `user_setting_user_FK` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`), CONSTRAINT `user_setting_user_settings_type_FK` FOREIGN KEY (`setting_id`) REFERENCES `user_settings_type` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Timewish Tabelle CREATE TABLE IF NOT EXISTS `timewish` ( `id` bigint NOT NULL AUTO_INCREMENT, `version` int NOT NULL DEFAULT 0, `user_id` bigint DEFAULT NULL, `day` int NOT NULL COMMENT '1=Mo, 2=Di, 3=Mi, 4=Do, 5=Fr, 6=Sa, 7=So', `wishtype` int NOT NULL COMMENT '1=Ende nach Uhrzeit, 2=Ende nach Stunden', `hours` float NOT NULL, `end_time` time DEFAULT NULL, `start_date` date NOT NULL COMMENT 'Ab welchem Datum gilt dieser Timewish', `end_date` date DEFAULT NULL COMMENT 'Bis welchem Datum gilt dieser Timewish (NULL = bis heute)', PRIMARY KEY (`id`), KEY `fk_timewish_user` (`user_id`), CONSTRAINT `fk_timewish_user` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ============================================================================ -- Urlaub & Krankmeldungen -- ============================================================================ -- Sick Type Tabelle CREATE TABLE IF NOT EXISTS `sick_type` ( `id` bigint NOT NULL AUTO_INCREMENT, `version` int NOT NULL DEFAULT 0, `description` text NOT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Sick Tabelle (Krankmeldungen) CREATE TABLE IF NOT EXISTS `sick` ( `id` bigint NOT NULL AUTO_INCREMENT, `version` int NOT NULL DEFAULT 0, `user_id` bigint DEFAULT NULL, `first_day` date DEFAULT NULL, `last_day` date DEFAULT NULL, `sick_type_id` bigint DEFAULT NULL, PRIMARY KEY (`id`), KEY `fk_sick_user` (`user_id`), KEY `fk_sick_sick_type` (`sick_type_id`), CONSTRAINT `fk_sick_sick_type` FOREIGN KEY (`sick_type_id`) REFERENCES `sick_type` (`id`), CONSTRAINT `fk_sick_user` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Vacation Tabelle (Urlaub) CREATE TABLE IF NOT EXISTS `vacation` ( `id` bigint NOT NULL AUTO_INCREMENT, `version` int NOT NULL DEFAULT 0, `user_id` bigint NOT NULL, `first_day` date DEFAULT NULL, `last_day` date DEFAULT NULL, `vacation_type` int NOT NULL, PRIMARY KEY (`id`), KEY `fk_vacation_user` (`user_id`), CONSTRAINT `fk_vacation_user` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ============================================================================ -- Feiertage -- ============================================================================ -- Holiday Tabelle CREATE TABLE IF NOT EXISTS `holiday` ( `id` bigint NOT NULL AUTO_INCREMENT, `version` int NOT NULL DEFAULT 0, `date` date DEFAULT NULL, `hours` int NOT NULL DEFAULT 8, `description` text NOT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Holiday State Verknüpfung CREATE TABLE IF NOT EXISTS `holiday_state` ( `state_id` bigint NOT NULL, `holiday_id` bigint NOT NULL, PRIMARY KEY (`state_id`,`holiday_id`), KEY `holiday_state_state` (`state_id`), KEY `holiday_state_holiday` (`holiday_id`), CONSTRAINT `fk_holiday_state_key1` FOREIGN KEY (`state_id`) REFERENCES `state` (`id`) ON DELETE CASCADE, CONSTRAINT `fk_holiday_state_key2` FOREIGN KEY (`holiday_id`) REFERENCES `holiday` (`id`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ============================================================================ -- ACL (Access Control List) -- ============================================================================ -- ACL User Tabelle CREATE TABLE IF NOT EXISTS `acl_user` ( `id` bigint NOT NULL, `version` int NOT NULL DEFAULT 0, `user_id` bigint DEFAULT NULL, `to_email` text NOT NULL, KEY `fk_acl_user_user` (`user_id`), CONSTRAINT `fk_acl_user_user` FOREIGN KEY (`user_id`) REFERENCES `user` (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ACL Type Tabelle CREATE TABLE IF NOT EXISTS `acl_type` ( `id` bigint NOT NULL, `version` int NOT NULL DEFAULT 0, `description` text NOT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ACL Tabelle CREATE TABLE IF NOT EXISTS `acl` ( `id` bigint NOT NULL, `version` int NOT NULL DEFAULT 0, `acl_user_id` bigint NOT NULL, `acl_type` int NOT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ============================================================================ -- Hilfstabellen -- ============================================================================ -- Dates Tabelle CREATE TABLE IF NOT EXISTS `dates` ( `id` int NOT NULL AUTO_INCREMENT, `date` date NOT NULL, PRIMARY KEY (`id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ============================================================================ -- Erfolgsmeldung -- ============================================================================ SELECT '✅ Alle Tabellen erfolgreich erstellt!' AS Status;