# 🗄️ Datenbank Dokumentation der PostgreSQL-Datenbank des Ninja Cross Parkour Systems. ## 📋 Inhaltsverzeichnis - [🏗️ Schema-Übersicht](#️-schema-übersicht) - [📊 Tabellen](#-tabellen) - [🔗 Beziehungen](#-beziehungen) - [📈 Indizes](#-indizes) - [🔧 Funktionen](#-funktionen) - [📊 Statistiken](#-statistiken) - [🛠️ Wartung](#️-wartung) ## 🏗️ Schema-Übersicht ### Datenbank-Name `ninjaserver` ### Zeichensatz `UTF-8` ### Zeitzone `Europe/Berlin` ### Version PostgreSQL 12 oder höher ## 📊 Tabellen ### `players` - Spieler ```sql CREATE TABLE players ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), firstname VARCHAR(50) NOT NULL, lastname VARCHAR(50) NOT NULL, birthdate DATE NOT NULL, rfiduid VARCHAR(20) UNIQUE, supabase_user_id UUID, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); ``` **Beschreibung:** Speichert alle Spieler-Informationen. **Felder:** - `id` - Eindeutige UUID - `firstname` - Vorname (max. 50 Zeichen) - `lastname` - Nachname (max. 50 Zeichen) - `birthdate` - Geburtsdatum - `rfiduid` - RFID-Karten-ID (eindeutig) - `supabase_user_id` - Verknüpfung zu Supabase - `created_at` - Erstellungszeitpunkt - `updated_at` - Letzte Aktualisierung ### `locations` - Standorte ```sql CREATE TABLE locations ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name VARCHAR(255) UNIQUE NOT NULL, latitude DECIMAL(10, 8) NOT NULL, longitude DECIMAL(11, 8) NOT NULL, time_threshold JSONB DEFAULT '{"seconds": 120}', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); ``` **Beschreibung:** Speichert alle Parkour-Standorte. **Felder:** - `id` - Eindeutige UUID - `name` - Standortname (eindeutig) - `latitude` - Breitengrad (10,8 Dezimalstellen) - `longitude` - Längengrad (11,8 Dezimalstellen) - `time_threshold` - Zeit-Schwelle als JSON - `created_at` - Erstellungszeitpunkt - `updated_at` - Letzte Aktualisierung ### `times` - Zeiten ```sql CREATE TABLE times ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), player_id UUID REFERENCES players(id) ON DELETE CASCADE, location_id UUID REFERENCES locations(id) ON DELETE CASCADE, recorded_time JSONB NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); ``` **Beschreibung:** Speichert alle gemessenen Zeiten. **Felder:** - `id` - Eindeutige UUID - `player_id` - Verweis auf Spieler - `location_id` - Verweis auf Standort - `recorded_time` - Zeit als JSON (Sekunden, Minuten, Millisekunden) - `created_at` - Erstellungszeitpunkt ### `achievements` - Achievements ```sql CREATE TABLE achievements ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name VARCHAR(255) NOT NULL, description TEXT, category VARCHAR(50) NOT NULL, condition_type VARCHAR(50) NOT NULL, condition_value INTEGER NOT NULL, icon VARCHAR(10), points INTEGER DEFAULT 0, is_active BOOLEAN DEFAULT true, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); ``` **Beschreibung:** Definiert alle verfügbaren Achievements. **Felder:** - `id` - Eindeutige UUID - `name` - Achievement-Name - `description` - Beschreibung - `category` - Kategorie (consistency, improvement, seasonal, monthly) - `condition_type` - Bedingungstyp - `condition_value` - Bedingungswert - `icon` - Emoji-Icon - `points` - Punkte - `is_active` - Aktiv-Status - `created_at` - Erstellungszeitpunkt - `updated_at` - Letzte Aktualisierung ### `player_achievements` - Spieler-Achievements ```sql CREATE TABLE player_achievements ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), player_id UUID REFERENCES players(id) ON DELETE CASCADE, achievement_id UUID REFERENCES achievements(id) ON DELETE CASCADE, earned_at TIMESTAMP, progress INTEGER DEFAULT 0, is_completed BOOLEAN DEFAULT false, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, UNIQUE(player_id, achievement_id) ); ``` **Beschreibung:** Verknüpft Spieler mit ihren Achievements. **Felder:** - `id` - Eindeutige UUID - `player_id` - Verweis auf Spieler - `achievement_id` - Verweis auf Achievement - `earned_at` - Zeitpunkt der Verleihung - `progress` - Fortschritt (0-100) - `is_completed` - Abgeschlossen-Status - `created_at` - Erstellungszeitpunkt ### `adminusers` - Admin-Benutzer ```sql CREATE TABLE adminusers ( id SERIAL PRIMARY KEY, username VARCHAR(50) UNIQUE NOT NULL, password_hash VARCHAR(255) NOT NULL, is_active BOOLEAN DEFAULT true, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, last_login TIMESTAMP ); ``` **Beschreibung:** Speichert Admin-Benutzer für das System. **Felder:** - `id` - Auto-increment ID - `username` - Benutzername (eindeutig) - `password_hash` - Gehashtes Passwort - `is_active` - Aktiv-Status - `created_at` - Erstellungszeitpunkt - `last_login` - Letzter Login ### `api_tokens` - API-Tokens ```sql CREATE TABLE api_tokens ( id SERIAL PRIMARY KEY, token VARCHAR(255) UNIQUE NOT NULL, description TEXT, standorte TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, expires_at TIMESTAMP, is_active BOOLEAN DEFAULT true ); ``` **Beschreibung:** Speichert API-Tokens für Authentifizierung. **Felder:** - `id` - Auto-increment ID - `token` - API-Token (eindeutig) - `description` - Beschreibung - `standorte` - Zugewiesene Standorte - `created_at` - Erstellungszeitpunkt - `expires_at` - Ablaufzeitpunkt - `is_active` - Aktiv-Status ### `page_views` - Seitenaufrufe ```sql CREATE TABLE page_views ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), page VARCHAR(255) NOT NULL, user_agent TEXT, ip_address INET, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); ``` **Beschreibung:** Verfolgt Seitenaufrufe für Statistiken. **Felder:** - `id` - Eindeutige UUID - `page` - Seitenname - `user_agent` - Browser-Informationen - `ip_address` - IP-Adresse - `created_at` - Zeitpunkt des Aufrufs ## 🔗 Beziehungen ### Foreign Key Constraints ```sql -- times -> players ALTER TABLE times ADD CONSTRAINT fk_times_player FOREIGN KEY (player_id) REFERENCES players(id) ON DELETE CASCADE; -- times -> locations ALTER TABLE times ADD CONSTRAINT fk_times_location FOREIGN KEY (location_id) REFERENCES locations(id) ON DELETE CASCADE; -- player_achievements -> players ALTER TABLE player_achievements ADD CONSTRAINT fk_player_achievements_player FOREIGN KEY (player_id) REFERENCES players(id) ON DELETE CASCADE; -- player_achievements -> achievements ALTER TABLE player_achievements ADD CONSTRAINT fk_player_achievements_achievement FOREIGN KEY (achievement_id) REFERENCES achievements(id) ON DELETE CASCADE; ``` ### Beziehungsdiagramm ``` players (1) -----> (N) times players (1) -----> (N) player_achievements locations (1) ---> (N) times achievements (1) -> (N) player_achievements ``` ## 📈 Indizes ### Primäre Indizes ```sql -- Primärschlüssel (automatisch) CREATE UNIQUE INDEX idx_players_pkey ON players(id); CREATE UNIQUE INDEX idx_locations_pkey ON locations(id); CREATE UNIQUE INDEX idx_times_pkey ON times(id); CREATE UNIQUE INDEX idx_achievements_pkey ON achievements(id); CREATE UNIQUE INDEX idx_player_achievements_pkey ON player_achievements(id); ``` ### Performance-Indizes ```sql -- Zeiten-Indizes CREATE INDEX idx_times_player_id ON times(player_id); CREATE INDEX idx_times_location_id ON times(location_id); CREATE INDEX idx_times_created_at ON times(created_at); CREATE INDEX idx_times_player_created ON times(player_id, created_at DESC); -- Achievement-Indizes CREATE INDEX idx_player_achievements_player_id ON player_achievements(player_id); CREATE INDEX idx_player_achievements_achievement_id ON player_achievements(achievement_id); CREATE INDEX idx_player_achievements_completed ON player_achievements(is_completed) WHERE is_completed = true; -- Standort-Indizes CREATE INDEX idx_locations_name ON locations(name); CREATE INDEX idx_locations_coordinates ON locations(latitude, longitude); -- Spieler-Indizes CREATE INDEX idx_players_rfiduid ON players(rfiduid); CREATE INDEX idx_players_supabase_user_id ON players(supabase_user_id); CREATE INDEX idx_players_name ON players(firstname, lastname); -- API-Token-Indizes CREATE INDEX idx_api_tokens_token ON api_tokens(token); CREATE INDEX idx_api_tokens_active ON api_tokens(is_active) WHERE is_active = true; -- Seitenaufruf-Indizes CREATE INDEX idx_page_views_page ON page_views(page); CREATE INDEX idx_page_views_created_at ON page_views(created_at); ``` ### Composite-Indizes ```sql -- Für häufige Abfragen CREATE INDEX idx_times_player_location_time ON times(player_id, location_id, created_at DESC); CREATE INDEX idx_player_achievements_player_completed ON player_achievements(player_id, is_completed); CREATE INDEX idx_achievements_category_active ON achievements(category, is_active); ``` ## 🔧 Funktionen ### Achievement-Funktionen ```sql -- Konsistenz-basierte Achievements prüfen CREATE OR REPLACE FUNCTION check_consistency_achievements(player_uuid UUID) RETURNS INTEGER AS $$ DECLARE awarded_count INTEGER := 0; total_runs INTEGER; runs_today INTEGER; unique_days INTEGER; BEGIN -- Gesamtläufe zählen SELECT COUNT(*) INTO total_runs FROM times WHERE player_id = player_uuid; -- Läufe heute zählen SELECT COUNT(*) INTO runs_today FROM times WHERE player_id = player_uuid AND DATE(created_at) = CURRENT_DATE; -- Verschiedene Tage zählen SELECT COUNT(DISTINCT DATE(created_at)) INTO unique_days FROM times WHERE player_id = player_uuid; -- Achievements vergeben -- (Detaillierte Logik hier...) RETURN awarded_count; END; $$ LANGUAGE plpgsql; -- Verbesserungs-basierte Achievements prüfen CREATE OR REPLACE FUNCTION check_improvement_achievements(player_uuid UUID) RETURNS INTEGER AS $$ -- (Implementierung...) $$ LANGUAGE plpgsql; -- Saisonale Achievements prüfen CREATE OR REPLACE FUNCTION check_seasonal_achievements(player_uuid UUID) RETURNS INTEGER AS $$ -- (Implementierung...) $$ LANGUAGE plpgsql; -- Alle Achievements prüfen CREATE OR REPLACE FUNCTION check_all_achievements(player_uuid UUID) RETURNS INTEGER AS $$ DECLARE total_awarded INTEGER := 0; BEGIN total_awarded := total_awarded + check_consistency_achievements(player_uuid); total_awarded := total_awarded + check_improvement_achievements(player_uuid); total_awarded := total_awarded + check_seasonal_achievements(player_uuid); RETURN total_awarded; END; $$ LANGUAGE plpgsql; ``` ### Utility-Funktionen ```sql -- Beste Zeit eines Spielers ermitteln CREATE OR REPLACE FUNCTION get_best_time(player_uuid UUID) RETURNS JSONB AS $$ DECLARE best_time JSONB; BEGIN SELECT recorded_time INTO best_time FROM times WHERE player_id = player_uuid ORDER BY (recorded_time->>'seconds')::INTEGER ASC LIMIT 1; RETURN COALESCE(best_time, '{"seconds": 0, "minutes": 0, "milliseconds": 0}'); END; $$ LANGUAGE plpgsql; -- Spieler-Statistiken berechnen CREATE OR REPLACE FUNCTION get_player_stats(player_uuid UUID) RETURNS JSONB AS $$ DECLARE stats JSONB; total_runs INTEGER; best_time JSONB; avg_time JSONB; BEGIN SELECT COUNT(*) INTO total_runs FROM times WHERE player_id = player_uuid; SELECT get_best_time(player_uuid) INTO best_time; -- Durchschnittszeit berechnen SELECT jsonb_build_object( 'seconds', AVG((recorded_time->>'seconds')::INTEGER), 'minutes', AVG((recorded_time->>'minutes')::INTEGER), 'milliseconds', AVG((recorded_time->>'milliseconds')::INTEGER) ) INTO avg_time FROM times WHERE player_id = player_uuid; stats := jsonb_build_object( 'total_runs', total_runs, 'best_time', best_time, 'average_time', avg_time ); RETURN stats; END; $$ LANGUAGE plpgsql; ``` ## 📊 Statistiken ### Datenbank-Größe ```sql -- Gesamtgröße der Datenbank SELECT pg_size_pretty(pg_database_size('ninjaserver')) as database_size; -- Größe der einzelnen Tabellen SELECT schemaname, tablename, pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename)) as size FROM pg_tables WHERE schemaname = 'public' ORDER BY pg_total_relation_size(schemaname||'.'||tablename) DESC; ``` ### Tabellen-Statistiken ```sql -- Anzahl der Datensätze pro Tabelle SELECT 'players' as table_name, COUNT(*) as record_count FROM players UNION ALL SELECT 'locations', COUNT(*) FROM locations UNION ALL SELECT 'times', COUNT(*) FROM times UNION ALL SELECT 'achievements', COUNT(*) FROM achievements UNION ALL SELECT 'player_achievements', COUNT(*) FROM player_achievements UNION ALL SELECT 'adminusers', COUNT(*) FROM adminusers UNION ALL SELECT 'api_tokens', COUNT(*) FROM api_tokens UNION ALL SELECT 'page_views', COUNT(*) FROM page_views; ``` ### Performance-Statistiken ```sql -- Langsamste Queries SELECT query, calls, total_time, mean_time, rows FROM pg_stat_statements ORDER BY mean_time DESC LIMIT 10; -- Index-Nutzung SELECT schemaname, tablename, indexname, idx_scan, idx_tup_read, idx_tup_fetch FROM pg_stat_user_indexes ORDER BY idx_scan DESC; ``` ## 🛠️ Wartung ### Backup ```bash # Vollständiges Backup pg_dump -h localhost -U username -d ninjaserver > ninjaserver_backup.sql # Nur Schema pg_dump -h localhost -U username -d ninjaserver --schema-only > schema_backup.sql # Nur Daten pg_dump -h localhost -U username -d ninjaserver --data-only > data_backup.sql # Komprimiertes Backup pg_dump -h localhost -U username -d ninjaserver | gzip > ninjaserver_backup.sql.gz ``` ### Wiederherstellung ```bash # Vollständige Wiederherstellung psql -h localhost -U username -d ninjaserver < ninjaserver_backup.sql # Schema wiederherstellen psql -h localhost -U username -d ninjaserver < schema_backup.sql # Daten wiederherstellen psql -h localhost -U username -d ninjaserver < data_backup.sql ``` ### Wartungsaufgaben ```sql -- Tabellen analysieren ANALYZE; -- Indizes neu aufbauen REINDEX DATABASE ninjaserver; -- Vakuum durchführen VACUUM ANALYZE; -- Speicher freigeben VACUUM FULL; ``` ### Monitoring ```sql -- Aktive Verbindungen SELECT pid, usename, application_name, client_addr, state, query_start, query FROM pg_stat_activity WHERE state = 'active'; -- Locks SELECT pid, mode, locktype, relation::regclass, granted FROM pg_locks WHERE NOT granted; -- Wartende Queries SELECT pid, usename, application_name, state, query_start, query FROM pg_stat_activity WHERE state = 'waiting'; ``` ### Sicherheit ```sql -- Benutzerrechte prüfen SELECT usename, usesuper, usecreatedb, usebypassrls FROM pg_user; -- Tabellenrechte prüfen SELECT schemaname, tablename, tableowner FROM pg_tables WHERE schemaname = 'public'; -- Verbindungslimits SELECT usename, connlimit FROM pg_user; ``` --- **Hinweis:** Für detaillierte API-Dokumentation siehe [API Referenz](API-Referenz) und für Achievement-Details siehe [Achievement System](Achievement-System).