Files
skybridge/migrations/004_add_audit_events.up.sql
2025-08-25 21:28:14 -04:00

102 lines
5.2 KiB
PL/PgSQL

-- Migration: 004_add_audit_events
-- Add audit_events table for comprehensive audit logging
-- Create audit_events table
CREATE TABLE IF NOT EXISTS audit_events (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
type VARCHAR(50) NOT NULL,
severity VARCHAR(20) NOT NULL CHECK (severity IN ('info', 'warning', 'error', 'critical')),
status VARCHAR(20) NOT NULL CHECK (status IN ('success', 'failure', 'pending')),
timestamp TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
-- Actor information
actor_id VARCHAR(255),
actor_type VARCHAR(50) CHECK (actor_type IN ('user', 'system', 'service')),
actor_ip INET,
user_agent TEXT,
-- Tenant information (for multi-tenancy support)
tenant_id UUID,
-- Resource information
resource_id VARCHAR(255),
resource_type VARCHAR(100),
-- Event details
action VARCHAR(100) NOT NULL,
description TEXT NOT NULL,
details JSONB DEFAULT '{}',
-- Request context
request_id VARCHAR(100),
session_id VARCHAR(255),
-- Additional metadata
tags TEXT[],
metadata JSONB DEFAULT '{}'
);
-- Create indexes for efficient querying
CREATE INDEX IF NOT EXISTS idx_audit_events_timestamp ON audit_events(timestamp DESC);
CREATE INDEX IF NOT EXISTS idx_audit_events_type ON audit_events(type);
CREATE INDEX IF NOT EXISTS idx_audit_events_severity ON audit_events(severity);
CREATE INDEX IF NOT EXISTS idx_audit_events_status ON audit_events(status);
CREATE INDEX IF NOT EXISTS idx_audit_events_actor_id ON audit_events(actor_id);
CREATE INDEX IF NOT EXISTS idx_audit_events_actor_type ON audit_events(actor_type);
CREATE INDEX IF NOT EXISTS idx_audit_events_tenant_id ON audit_events(tenant_id) WHERE tenant_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_audit_events_resource ON audit_events(resource_type, resource_id) WHERE resource_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_audit_events_request_id ON audit_events(request_id) WHERE request_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_audit_events_session_id ON audit_events(session_id) WHERE session_id IS NOT NULL;
-- GIN indexes for JSONB columns
CREATE INDEX IF NOT EXISTS idx_audit_events_details ON audit_events USING GIN (details);
CREATE INDEX IF NOT EXISTS idx_audit_events_metadata ON audit_events USING GIN (metadata);
-- GIN index for tags array
CREATE INDEX IF NOT EXISTS idx_audit_events_tags ON audit_events USING GIN (tags);
-- Composite indexes for common query patterns
CREATE INDEX IF NOT EXISTS idx_audit_events_actor_timestamp ON audit_events(actor_id, timestamp DESC) WHERE actor_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_audit_events_type_timestamp ON audit_events(type, timestamp DESC);
CREATE INDEX IF NOT EXISTS idx_audit_events_tenant_timestamp ON audit_events(tenant_id, timestamp DESC) WHERE tenant_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_audit_events_resource_timestamp ON audit_events(resource_type, resource_id, timestamp DESC) WHERE resource_id IS NOT NULL;
-- Add comments for documentation
COMMENT ON TABLE audit_events IS 'Comprehensive audit log for all system events and user actions';
COMMENT ON COLUMN audit_events.id IS 'Unique event identifier';
COMMENT ON COLUMN audit_events.type IS 'Event type (e.g., auth.login, app.created)';
COMMENT ON COLUMN audit_events.severity IS 'Event severity level: info, warning, error, critical';
COMMENT ON COLUMN audit_events.status IS 'Event status: success, failure, pending';
COMMENT ON COLUMN audit_events.timestamp IS 'When the event occurred';
COMMENT ON COLUMN audit_events.actor_id IS 'ID of the user/system that triggered the event';
COMMENT ON COLUMN audit_events.actor_type IS 'Type of actor: user, system, service';
COMMENT ON COLUMN audit_events.actor_ip IS 'IP address of the actor';
COMMENT ON COLUMN audit_events.user_agent IS 'User agent string (for HTTP requests)';
COMMENT ON COLUMN audit_events.tenant_id IS 'Tenant ID for multi-tenant environments';
COMMENT ON COLUMN audit_events.resource_id IS 'ID of the resource being acted upon';
COMMENT ON COLUMN audit_events.resource_type IS 'Type of resource (e.g., application, token)';
COMMENT ON COLUMN audit_events.action IS 'Action performed';
COMMENT ON COLUMN audit_events.description IS 'Human-readable description of the event';
COMMENT ON COLUMN audit_events.details IS 'Additional structured details as JSON';
COMMENT ON COLUMN audit_events.request_id IS 'Request ID for tracing';
COMMENT ON COLUMN audit_events.session_id IS 'Session ID for user session tracking';
COMMENT ON COLUMN audit_events.tags IS 'Array of tags for categorization';
COMMENT ON COLUMN audit_events.metadata IS 'Additional metadata as JSON';
-- Create a function to automatically clean up old audit events (optional)
CREATE OR REPLACE FUNCTION cleanup_old_audit_events(retention_days INTEGER DEFAULT 365)
RETURNS INTEGER AS $$
DECLARE
deleted_count INTEGER;
BEGIN
-- Delete audit events older than retention period
DELETE FROM audit_events
WHERE timestamp < NOW() - (retention_days || ' days')::INTERVAL;
GET DIAGNOSTICS deleted_count = ROW_COUNT;
RETURN deleted_count;
END;
$$ LANGUAGE plpgsql;
COMMENT ON FUNCTION cleanup_old_audit_events(INTEGER) IS 'Function to clean up audit events older than specified days (default: 365 days)';