-- Phase 2: Admin Audit and Security Migration -- This migration adds admin audit logging and security event tracking -- Admin audit trail (HIGH PRIORITY) CREATE TABLE IF NOT EXISTS admin_audit_log ( id SERIAL PRIMARY KEY, admin_user VARCHAR(100) NOT NULL, action_type VARCHAR(50) NOT NULL, resource_affected VARCHAR(200), changes_made JSONB DEFAULT '{}'::jsonb, request_ip INET, user_agent TEXT, timestamp TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, session_id VARCHAR(255), success BOOLEAN DEFAULT TRUE, error_message TEXT ); -- Security events (HIGH PRIORITY) CREATE TABLE IF NOT EXISTS security_events ( id SERIAL PRIMARY KEY, event_type VARCHAR(50) NOT NULL, -- login_attempt, unauthorized_access, admin_action, etc. severity VARCHAR(20) DEFAULT 'info', -- info, warning, error, critical source_ip INET, user_identifier VARCHAR(100), event_data JSONB DEFAULT '{}'::jsonb, timestamp TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, resolved BOOLEAN DEFAULT FALSE, resolution_notes TEXT, resolved_at TIMESTAMPTZ, resolved_by VARCHAR(100) ); -- Performance tracking (HIGH PRIORITY) CREATE TABLE IF NOT EXISTS performance_metrics ( id SERIAL PRIMARY KEY, metric_name VARCHAR(100) NOT NULL, metric_value FLOAT NOT NULL, metric_unit VARCHAR(50), character_id INTEGER REFERENCES characters(id) ON DELETE SET NULL, component VARCHAR(100), -- 'llm_client', 'conversation_engine', 'vector_store', etc. timestamp TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, additional_data JSONB DEFAULT '{}'::jsonb ); -- System configuration management (HIGH PRIORITY) CREATE TABLE IF NOT EXISTS system_configuration ( id SERIAL PRIMARY KEY, config_section VARCHAR(100) NOT NULL, config_key VARCHAR(200) NOT NULL, config_value JSONB NOT NULL, description TEXT, created_by VARCHAR(100) NOT NULL, created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, is_active BOOLEAN DEFAULT TRUE, is_sensitive BOOLEAN DEFAULT FALSE, -- Mark sensitive configs like tokens version INTEGER DEFAULT 1 ); -- Configuration change history CREATE TABLE IF NOT EXISTS system_configuration_history ( id SERIAL PRIMARY KEY, config_id INTEGER REFERENCES system_configuration(id) ON DELETE CASCADE, old_value JSONB, new_value JSONB, changed_by VARCHAR(100) NOT NULL, change_reason TEXT, changed_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP ); -- File operations audit (MEDIUM PRIORITY) CREATE TABLE IF NOT EXISTS file_operations_log ( id SERIAL PRIMARY KEY, character_id INTEGER REFERENCES characters(id) ON DELETE CASCADE, operation_type VARCHAR(20) NOT NULL, -- 'read', 'write', 'delete', 'create' file_path VARCHAR(500) NOT NULL, file_size BIGINT, success BOOLEAN DEFAULT TRUE, error_message TEXT, timestamp TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, mcp_server VARCHAR(100), -- Which MCP server performed the operation request_context JSONB DEFAULT '{}'::jsonb ); -- Admin session tracking CREATE TABLE IF NOT EXISTS admin_sessions ( id SERIAL PRIMARY KEY, session_id VARCHAR(255) UNIQUE NOT NULL, admin_user VARCHAR(100) NOT NULL, created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, last_activity TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, expires_at TIMESTAMPTZ NOT NULL, source_ip INET, user_agent TEXT, is_active BOOLEAN DEFAULT TRUE ); -- Indexes for performance CREATE INDEX IF NOT EXISTS idx_admin_audit_user ON admin_audit_log(admin_user); CREATE INDEX IF NOT EXISTS idx_admin_audit_timestamp ON admin_audit_log(timestamp); CREATE INDEX IF NOT EXISTS idx_admin_audit_action_type ON admin_audit_log(action_type); CREATE INDEX IF NOT EXISTS idx_security_events_type ON security_events(event_type); CREATE INDEX IF NOT EXISTS idx_security_events_severity ON security_events(severity); CREATE INDEX IF NOT EXISTS idx_security_events_timestamp ON security_events(timestamp); CREATE INDEX IF NOT EXISTS idx_security_events_resolved ON security_events(resolved); CREATE INDEX IF NOT EXISTS idx_performance_metrics_name ON performance_metrics(metric_name); CREATE INDEX IF NOT EXISTS idx_performance_metrics_timestamp ON performance_metrics(timestamp); CREATE INDEX IF NOT EXISTS idx_performance_metrics_component ON performance_metrics(component); CREATE INDEX IF NOT EXISTS idx_system_config_section_key ON system_configuration(config_section, config_key); CREATE INDEX IF NOT EXISTS idx_system_config_active ON system_configuration(is_active); CREATE INDEX IF NOT EXISTS idx_config_history_config_id ON system_configuration_history(config_id); CREATE INDEX IF NOT EXISTS idx_config_history_changed_at ON system_configuration_history(changed_at); CREATE INDEX IF NOT EXISTS idx_file_ops_character_id ON file_operations_log(character_id); CREATE INDEX IF NOT EXISTS idx_file_ops_timestamp ON file_operations_log(timestamp); CREATE INDEX IF NOT EXISTS idx_file_ops_operation_type ON file_operations_log(operation_type); CREATE INDEX IF NOT EXISTS idx_admin_sessions_session_id ON admin_sessions(session_id); CREATE INDEX IF NOT EXISTS idx_admin_sessions_user ON admin_sessions(admin_user); CREATE INDEX IF NOT EXISTS idx_admin_sessions_active ON admin_sessions(is_active); -- Add updated_at trigger for system_configuration DROP TRIGGER IF EXISTS update_system_configuration_updated_at ON system_configuration; -- Note: We don't have updated_at on system_configuration, so we'll track changes in history table -- Insert some initial configuration items INSERT INTO system_configuration (config_section, config_key, config_value, description, created_by, is_sensitive) VALUES ('conversation', 'max_conversation_length', '50', 'Maximum number of messages in a conversation', 'system', FALSE), ('conversation', 'quiet_hours_start', '23', 'Hour when conversations should wind down', 'system', FALSE), ('conversation', 'quiet_hours_end', '7', 'Hour when conversations can resume', 'system', FALSE), ('llm', 'max_tokens', '2000', 'Maximum tokens per LLM request', 'system', FALSE), ('llm', 'temperature', '0.8', 'LLM temperature setting', 'system', FALSE), ('vector_store', 'embedding_model', 'all-MiniLM-L6-v2', 'Embedding model for vector store', 'system', FALSE), ('security', 'session_timeout_hours', '24', 'Admin session timeout in hours', 'system', FALSE) ON CONFLICT DO NOTHING; -- Create function to log configuration changes CREATE OR REPLACE FUNCTION log_configuration_change() RETURNS TRIGGER AS $$ BEGIN -- Only log if the value actually changed IF OLD.config_value IS DISTINCT FROM NEW.config_value THEN INSERT INTO system_configuration_history ( config_id, old_value, new_value, changed_by, change_reason ) VALUES ( NEW.id, OLD.config_value, NEW.config_value, COALESCE(current_setting('app.current_user', TRUE), 'system'), COALESCE(current_setting('app.change_reason', TRUE), 'Configuration update') ); END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; -- Add trigger for configuration changes DROP TRIGGER IF EXISTS system_configuration_change_trigger ON system_configuration; CREATE TRIGGER system_configuration_change_trigger AFTER UPDATE ON system_configuration FOR EACH ROW EXECUTE FUNCTION log_configuration_change();