-- UTF-8 Encoding für deutsche Sonderzeichen sicherstellen SET client_encoding = 'UTF8'; -- Zeitzone auf Europe/Berlin setzen SET timezone = 'Europe/Berlin'; CREATE TABLE IF NOT EXISTS customers ( id SERIAL PRIMARY KEY, name TEXT NOT NULL, email TEXT, is_test BOOLEAN DEFAULT FALSE, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, CONSTRAINT unique_email UNIQUE (email) ); CREATE TABLE IF NOT EXISTS licenses ( id SERIAL PRIMARY KEY, license_key TEXT UNIQUE NOT NULL, customer_id INTEGER REFERENCES customers(id), license_type TEXT NOT NULL, valid_from DATE NOT NULL, valid_until DATE NOT NULL, is_active BOOLEAN DEFAULT TRUE, is_test BOOLEAN DEFAULT FALSE, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE IF NOT EXISTS sessions ( id SERIAL PRIMARY KEY, license_id INTEGER REFERENCES licenses(id), session_id TEXT UNIQUE NOT NULL, ip_address TEXT, user_agent TEXT, started_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, last_heartbeat TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, ended_at TIMESTAMP WITH TIME ZONE, is_active BOOLEAN DEFAULT TRUE ); -- Audit-Log-Tabelle für Änderungsprotokolle CREATE TABLE IF NOT EXISTS audit_log ( id SERIAL PRIMARY KEY, timestamp TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, username TEXT NOT NULL, action TEXT NOT NULL, entity_type TEXT NOT NULL, entity_id INTEGER, old_values JSONB, new_values JSONB, ip_address TEXT, user_agent TEXT, additional_info TEXT ); -- Index für bessere Performance bei Abfragen CREATE INDEX idx_audit_log_timestamp ON audit_log(timestamp DESC); CREATE INDEX idx_audit_log_username ON audit_log(username); CREATE INDEX idx_audit_log_entity ON audit_log(entity_type, entity_id); -- Backup-Historie-Tabelle CREATE TABLE IF NOT EXISTS backup_history ( id SERIAL PRIMARY KEY, filename TEXT NOT NULL, filepath TEXT NOT NULL, filesize BIGINT, backup_type TEXT NOT NULL, -- 'manual' oder 'scheduled' status TEXT NOT NULL, -- 'success', 'failed', 'in_progress' error_message TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, created_by TEXT NOT NULL, tables_count INTEGER, records_count INTEGER, duration_seconds NUMERIC, is_encrypted BOOLEAN DEFAULT TRUE ); -- Index für bessere Performance CREATE INDEX idx_backup_history_created_at ON backup_history(created_at DESC); CREATE INDEX idx_backup_history_status ON backup_history(status); -- Login-Attempts-Tabelle für Rate-Limiting CREATE TABLE IF NOT EXISTS login_attempts ( ip_address VARCHAR(45) PRIMARY KEY, attempt_count INTEGER DEFAULT 0, first_attempt TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, last_attempt TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, blocked_until TIMESTAMP WITH TIME ZONE NULL, last_username_tried TEXT, last_error_message TEXT ); -- Index für schnelle Abfragen CREATE INDEX idx_login_attempts_blocked_until ON login_attempts(blocked_until); CREATE INDEX idx_login_attempts_last_attempt ON login_attempts(last_attempt DESC); -- Migration: Füge created_at zu licenses hinzu, falls noch nicht vorhanden DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'licenses' AND column_name = 'created_at') THEN ALTER TABLE licenses ADD COLUMN created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP; -- Setze created_at für bestehende Einträge auf das valid_from Datum UPDATE licenses SET created_at = valid_from WHERE created_at IS NULL; END IF; END $$; -- ===================== RESOURCE POOL SYSTEM ===================== -- Haupttabelle für den Resource Pool CREATE TABLE IF NOT EXISTS resource_pools ( id SERIAL PRIMARY KEY, resource_type VARCHAR(20) NOT NULL CHECK (resource_type IN ('domain', 'ipv4', 'phone')), resource_value VARCHAR(255) NOT NULL, status VARCHAR(20) DEFAULT 'available' CHECK (status IN ('available', 'allocated', 'quarantine')), allocated_to_license INTEGER REFERENCES licenses(id) ON DELETE SET NULL, status_changed_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, status_changed_by VARCHAR(50), quarantine_reason VARCHAR(100) CHECK (quarantine_reason IN ('abuse', 'defect', 'maintenance', 'blacklisted', 'expired', 'review', NULL)), quarantine_until TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, notes TEXT, is_test BOOLEAN DEFAULT FALSE, UNIQUE(resource_type, resource_value) ); -- Resource History für vollständige Nachverfolgbarkeit CREATE TABLE IF NOT EXISTS resource_history ( id SERIAL PRIMARY KEY, resource_id INTEGER REFERENCES resource_pools(id) ON DELETE CASCADE, license_id INTEGER REFERENCES licenses(id) ON DELETE SET NULL, action VARCHAR(50) NOT NULL CHECK (action IN ('allocated', 'deallocated', 'quarantined', 'released', 'created', 'deleted')), action_by VARCHAR(50) NOT NULL, action_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, details JSONB, ip_address TEXT ); -- Resource Metrics für Performance-Tracking und ROI CREATE TABLE IF NOT EXISTS resource_metrics ( id SERIAL PRIMARY KEY, resource_id INTEGER REFERENCES resource_pools(id) ON DELETE CASCADE, metric_date DATE NOT NULL, usage_count INTEGER DEFAULT 0, performance_score DECIMAL(5,2) DEFAULT 0.00, cost DECIMAL(10,2) DEFAULT 0.00, revenue DECIMAL(10,2) DEFAULT 0.00, issues_count INTEGER DEFAULT 0, availability_percent DECIMAL(5,2) DEFAULT 100.00, UNIQUE(resource_id, metric_date) ); -- Zuordnungstabelle zwischen Lizenzen und Ressourcen CREATE TABLE IF NOT EXISTS license_resources ( id SERIAL PRIMARY KEY, license_id INTEGER REFERENCES licenses(id) ON DELETE CASCADE, resource_id INTEGER REFERENCES resource_pools(id) ON DELETE CASCADE, assigned_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, assigned_by VARCHAR(50), is_active BOOLEAN DEFAULT TRUE, UNIQUE(license_id, resource_id) ); -- Erweiterung der licenses Tabelle um Resource-Counts DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'licenses' AND column_name = 'domain_count') THEN ALTER TABLE licenses ADD COLUMN domain_count INTEGER DEFAULT 1 CHECK (domain_count >= 0 AND domain_count <= 10), ADD COLUMN ipv4_count INTEGER DEFAULT 1 CHECK (ipv4_count >= 0 AND ipv4_count <= 10), ADD COLUMN phone_count INTEGER DEFAULT 1 CHECK (phone_count >= 0 AND phone_count <= 10); END IF; END $$; -- Erweiterung der licenses Tabelle um device_limit DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'licenses' AND column_name = 'device_limit') THEN ALTER TABLE licenses ADD COLUMN device_limit INTEGER DEFAULT 3 CHECK (device_limit >= 1 AND device_limit <= 10); END IF; END $$; -- Tabelle für Geräte-Registrierungen CREATE TABLE IF NOT EXISTS device_registrations ( id SERIAL PRIMARY KEY, license_id INTEGER REFERENCES licenses(id) ON DELETE CASCADE, hardware_id TEXT NOT NULL, device_name TEXT, operating_system TEXT, first_seen TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, last_seen TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, is_active BOOLEAN DEFAULT TRUE, deactivated_at TIMESTAMP WITH TIME ZONE, deactivated_by TEXT, ip_address TEXT, user_agent TEXT, UNIQUE(license_id, hardware_id) ); -- Indizes für device_registrations CREATE INDEX IF NOT EXISTS idx_device_license ON device_registrations(license_id); CREATE INDEX IF NOT EXISTS idx_device_hardware ON device_registrations(hardware_id); CREATE INDEX IF NOT EXISTS idx_device_active ON device_registrations(license_id, is_active) WHERE is_active = TRUE; -- Indizes für Performance CREATE INDEX IF NOT EXISTS idx_resource_status ON resource_pools(status); CREATE INDEX IF NOT EXISTS idx_resource_type_status ON resource_pools(resource_type, status); CREATE INDEX IF NOT EXISTS idx_resource_allocated ON resource_pools(allocated_to_license) WHERE allocated_to_license IS NOT NULL; CREATE INDEX IF NOT EXISTS idx_resource_quarantine ON resource_pools(quarantine_until) WHERE status = 'quarantine'; CREATE INDEX IF NOT EXISTS idx_resource_history_date ON resource_history(action_at DESC); CREATE INDEX IF NOT EXISTS idx_resource_history_resource ON resource_history(resource_id); CREATE INDEX IF NOT EXISTS idx_resource_metrics_date ON resource_metrics(metric_date DESC); CREATE INDEX IF NOT EXISTS idx_license_resources_active ON license_resources(license_id) WHERE is_active = TRUE; -- Users table for authentication with password and 2FA support CREATE TABLE IF NOT EXISTS users ( id SERIAL PRIMARY KEY, username VARCHAR(50) UNIQUE NOT NULL, password_hash VARCHAR(255) NOT NULL, email VARCHAR(100), totp_secret VARCHAR(32), totp_enabled BOOLEAN DEFAULT FALSE, backup_codes TEXT, -- JSON array of hashed backup codes created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, last_password_change TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, password_reset_token VARCHAR(64), password_reset_expires TIMESTAMP WITH TIME ZONE, failed_2fa_attempts INTEGER DEFAULT 0, last_failed_2fa TIMESTAMP WITH TIME ZONE ); -- Index for faster login lookups CREATE INDEX IF NOT EXISTS idx_users_username ON users(username); CREATE INDEX IF NOT EXISTS idx_users_reset_token ON users(password_reset_token) WHERE password_reset_token IS NOT NULL; -- Migration: Add is_test column to licenses if it doesn't exist DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'licenses' AND column_name = 'is_test') THEN ALTER TABLE licenses ADD COLUMN is_test BOOLEAN DEFAULT FALSE; -- Mark all existing licenses as test data UPDATE licenses SET is_test = TRUE; -- Add index for better performance when filtering test data CREATE INDEX idx_licenses_is_test ON licenses(is_test); END IF; END $$; -- Migration: Add is_test column to customers if it doesn't exist DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'customers' AND column_name = 'is_test') THEN ALTER TABLE customers ADD COLUMN is_test BOOLEAN DEFAULT FALSE; -- Mark all existing customers as test data UPDATE customers SET is_test = TRUE; -- Add index for better performance CREATE INDEX idx_customers_is_test ON customers(is_test); END IF; END $$; -- Migration: Add is_test column to resource_pools if it doesn't exist DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'resource_pools' AND column_name = 'is_test') THEN ALTER TABLE resource_pools ADD COLUMN is_test BOOLEAN DEFAULT FALSE; -- Mark all existing resources as test data UPDATE resource_pools SET is_test = TRUE; -- Add index for better performance CREATE INDEX idx_resource_pools_is_test ON resource_pools(is_test); END IF; END $$;