org
This commit is contained in:
17
kms/migrations/001_initial_schema.down.sql
Normal file
17
kms/migrations/001_initial_schema.down.sql
Normal file
@ -0,0 +1,17 @@
|
||||
-- Migration: 001_initial_schema (DOWN)
|
||||
-- Drop all tables and extensions created in the up migration
|
||||
|
||||
-- Drop tables in reverse order of creation (due to foreign key constraints)
|
||||
DROP TABLE IF EXISTS granted_permissions;
|
||||
DROP TABLE IF EXISTS static_tokens;
|
||||
DROP TABLE IF EXISTS available_permissions;
|
||||
DROP TABLE IF EXISTS applications;
|
||||
|
||||
-- Drop triggers and functions
|
||||
DROP TRIGGER IF EXISTS update_applications_updated_at ON applications;
|
||||
DROP TRIGGER IF EXISTS update_static_tokens_updated_at ON static_tokens;
|
||||
DROP TRIGGER IF EXISTS update_available_permissions_updated_at ON available_permissions;
|
||||
DROP FUNCTION IF EXISTS update_updated_at_column();
|
||||
|
||||
-- Drop extension (be careful with this in production)
|
||||
-- DROP EXTENSION IF EXISTS "uuid-ossp";
|
||||
169
kms/migrations/001_initial_schema.up.sql
Normal file
169
kms/migrations/001_initial_schema.up.sql
Normal file
@ -0,0 +1,169 @@
|
||||
-- Migration: 001_initial_schema
|
||||
-- Create initial database schema for API Key Management Service
|
||||
|
||||
-- Enable UUID extension
|
||||
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||
|
||||
-- Applications table
|
||||
CREATE TABLE applications (
|
||||
app_id VARCHAR(255) PRIMARY KEY,
|
||||
app_link VARCHAR(500) NOT NULL,
|
||||
type TEXT[] NOT NULL CHECK (array_length(type, 1) > 0),
|
||||
callback_url VARCHAR(500) NOT NULL,
|
||||
hmac_key VARCHAR(255) NOT NULL,
|
||||
token_renewal_duration BIGINT NOT NULL, -- Duration in nanoseconds
|
||||
max_token_duration BIGINT NOT NULL, -- Duration in nanoseconds
|
||||
owner_type VARCHAR(20) NOT NULL CHECK (owner_type IN ('individual', 'team')),
|
||||
owner_name VARCHAR(255) NOT NULL,
|
||||
owner_owner VARCHAR(255) NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Create index for applications
|
||||
CREATE INDEX idx_applications_owner_type ON applications(owner_type);
|
||||
CREATE INDEX idx_applications_created_at ON applications(created_at);
|
||||
|
||||
-- Available permissions table (global catalog)
|
||||
CREATE TABLE available_permissions (
|
||||
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
scope VARCHAR(255) UNIQUE NOT NULL,
|
||||
name VARCHAR(255) NOT NULL,
|
||||
description TEXT NOT NULL,
|
||||
category VARCHAR(100) NOT NULL,
|
||||
parent_scope VARCHAR(255) REFERENCES available_permissions(scope) ON DELETE SET NULL,
|
||||
is_system BOOLEAN DEFAULT FALSE,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
created_by VARCHAR(255) NOT NULL,
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
updated_by VARCHAR(255) NOT NULL
|
||||
);
|
||||
|
||||
-- Create indexes for available permissions
|
||||
CREATE INDEX idx_available_permissions_scope ON available_permissions(scope);
|
||||
CREATE INDEX idx_available_permissions_category ON available_permissions(category);
|
||||
CREATE INDEX idx_available_permissions_parent_scope ON available_permissions(parent_scope);
|
||||
CREATE INDEX idx_available_permissions_is_system ON available_permissions(is_system);
|
||||
|
||||
-- Static tokens table
|
||||
CREATE TABLE static_tokens (
|
||||
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
app_id VARCHAR(255) NOT NULL REFERENCES applications(app_id) ON DELETE CASCADE,
|
||||
owner_type VARCHAR(20) NOT NULL CHECK (owner_type IN ('individual', 'team')),
|
||||
owner_name VARCHAR(255) NOT NULL,
|
||||
owner_owner VARCHAR(255) NOT NULL,
|
||||
key_hash VARCHAR(255) NOT NULL UNIQUE, -- Store hashed key for security
|
||||
type VARCHAR(20) NOT NULL CHECK (type = 'hmac'),
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Create indexes for static tokens
|
||||
CREATE INDEX idx_static_tokens_app_id ON static_tokens(app_id);
|
||||
CREATE INDEX idx_static_tokens_key_hash ON static_tokens(key_hash);
|
||||
CREATE INDEX idx_static_tokens_created_at ON static_tokens(created_at);
|
||||
|
||||
-- Granted permissions table (links tokens to permissions)
|
||||
CREATE TABLE granted_permissions (
|
||||
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
|
||||
token_type VARCHAR(20) NOT NULL CHECK (token_type = 'static'),
|
||||
token_id UUID NOT NULL REFERENCES static_tokens(id) ON DELETE CASCADE,
|
||||
permission_id UUID NOT NULL REFERENCES available_permissions(id) ON DELETE CASCADE,
|
||||
scope VARCHAR(255) NOT NULL, -- Denormalized for fast reads
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
created_by VARCHAR(255) NOT NULL,
|
||||
revoked BOOLEAN DEFAULT FALSE,
|
||||
|
||||
-- Ensure unique permission per token
|
||||
UNIQUE(token_type, token_id, permission_id)
|
||||
);
|
||||
|
||||
-- Create indexes for granted permissions
|
||||
CREATE INDEX idx_granted_permissions_token ON granted_permissions(token_type, token_id);
|
||||
CREATE INDEX idx_granted_permissions_permission_id ON granted_permissions(permission_id);
|
||||
CREATE INDEX idx_granted_permissions_scope ON granted_permissions(scope);
|
||||
CREATE INDEX idx_granted_permissions_revoked ON granted_permissions(revoked);
|
||||
|
||||
-- Create trigger for updating updated_at timestamps
|
||||
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = NOW();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Apply triggers to tables that have updated_at
|
||||
CREATE TRIGGER update_applications_updated_at BEFORE UPDATE ON applications
|
||||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
CREATE TRIGGER update_static_tokens_updated_at BEFORE UPDATE ON static_tokens
|
||||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
CREATE TRIGGER update_available_permissions_updated_at BEFORE UPDATE ON available_permissions
|
||||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
-- Insert initial system permissions
|
||||
INSERT INTO available_permissions (scope, name, description, category, is_system, created_by, updated_by) VALUES
|
||||
-- Internal application management
|
||||
('internal', 'Internal System Access', 'Full access to internal system operations', 'system', true, 'system', 'system'),
|
||||
('internal.read', 'Internal Read Access', 'Read access to internal system data', 'system', true, 'system', 'system'),
|
||||
('internal.write', 'Internal Write Access', 'Write access to internal system data', 'system', true, 'system', 'system'),
|
||||
('internal.admin', 'Internal Admin Access', 'Administrative access to internal system', 'system', true, 'system', 'system'),
|
||||
|
||||
-- Application management
|
||||
('app', 'Application Access', 'Access to application management', 'application', false, 'system', 'system'),
|
||||
('app.read', 'Application Read', 'Read application information', 'application', false, 'system', 'system'),
|
||||
('app.write', 'Application Write', 'Create and update applications', 'application', false, 'system', 'system'),
|
||||
('app.delete', 'Application Delete', 'Delete applications', 'application', false, 'system', 'system'),
|
||||
|
||||
-- Token management
|
||||
('token', 'Token Access', 'Access to token management', 'token', false, 'system', 'system'),
|
||||
('token.read', 'Token Read', 'Read token information', 'token', false, 'system', 'system'),
|
||||
('token.create', 'Token Create', 'Create new tokens', 'token', false, 'system', 'system'),
|
||||
('token.revoke', 'Token Revoke', 'Revoke existing tokens', 'token', false, 'system', 'system'),
|
||||
|
||||
-- Permission management
|
||||
('permission', 'Permission Access', 'Access to permission management', 'permission', false, 'system', 'system'),
|
||||
('permission.read', 'Permission Read', 'Read permission information', 'permission', false, 'system', 'system'),
|
||||
('permission.write', 'Permission Write', 'Create and update permissions', 'permission', false, 'system', 'system'),
|
||||
('permission.grant', 'Permission Grant', 'Grant permissions to tokens', 'permission', false, 'system', 'system'),
|
||||
('permission.revoke', 'Permission Revoke', 'Revoke permissions from tokens', 'permission', false, 'system', 'system'),
|
||||
|
||||
-- Repository access (example permissions)
|
||||
('repo', 'Repository Access', 'Access to repository operations', 'repository', false, 'system', 'system'),
|
||||
('repo.read', 'Repository Read', 'Read repository data', 'repository', false, 'system', 'system'),
|
||||
('repo.write', 'Repository Write', 'Write to repositories', 'repository', false, 'system', 'system'),
|
||||
('repo.admin', 'Repository Admin', 'Administrative access to repositories', 'repository', false, 'system', 'system');
|
||||
|
||||
-- Set up parent-child relationships for hierarchical permissions
|
||||
UPDATE available_permissions SET parent_scope = 'internal' WHERE scope IN ('internal.read', 'internal.write', 'internal.admin');
|
||||
UPDATE available_permissions SET parent_scope = 'app' WHERE scope IN ('app.read', 'app.write', 'app.delete');
|
||||
UPDATE available_permissions SET parent_scope = 'token' WHERE scope IN ('token.read', 'token.create', 'token.revoke');
|
||||
UPDATE available_permissions SET parent_scope = 'permission' WHERE scope IN ('permission.read', 'permission.write', 'permission.grant', 'permission.revoke');
|
||||
UPDATE available_permissions SET parent_scope = 'repo' WHERE scope IN ('repo.read', 'repo.write', 'repo.admin');
|
||||
|
||||
-- Insert the internal application (for bootstrapping)
|
||||
INSERT INTO applications (
|
||||
app_id,
|
||||
app_link,
|
||||
type,
|
||||
callback_url,
|
||||
hmac_key,
|
||||
token_renewal_duration,
|
||||
max_token_duration,
|
||||
owner_type,
|
||||
owner_name,
|
||||
owner_owner
|
||||
) VALUES (
|
||||
'internal.api-key-service',
|
||||
'http://localhost:8080',
|
||||
ARRAY['static'],
|
||||
'http://localhost:8080/auth/callback',
|
||||
'bootstrap-hmac-key-change-in-production',
|
||||
604800000000000, -- 7 days in nanoseconds
|
||||
2592000000000000, -- 30 days in nanoseconds
|
||||
'team',
|
||||
'API Key Service',
|
||||
'system'
|
||||
);
|
||||
14
kms/migrations/002_user_sessions.down.sql
Normal file
14
kms/migrations/002_user_sessions.down.sql
Normal file
@ -0,0 +1,14 @@
|
||||
-- Drop user_sessions table and related objects
|
||||
DROP INDEX IF EXISTS idx_user_sessions_tenant;
|
||||
DROP INDEX IF EXISTS idx_user_sessions_metadata;
|
||||
DROP INDEX IF EXISTS idx_user_sessions_active_expires;
|
||||
DROP INDEX IF EXISTS idx_user_sessions_active;
|
||||
DROP INDEX IF EXISTS idx_user_sessions_created_at;
|
||||
DROP INDEX IF EXISTS idx_user_sessions_last_activity;
|
||||
DROP INDEX IF EXISTS idx_user_sessions_expires_at;
|
||||
DROP INDEX IF EXISTS idx_user_sessions_status;
|
||||
DROP INDEX IF EXISTS idx_user_sessions_user_app;
|
||||
DROP INDEX IF EXISTS idx_user_sessions_app_id;
|
||||
DROP INDEX IF EXISTS idx_user_sessions_user_id;
|
||||
|
||||
DROP TABLE IF EXISTS user_sessions;
|
||||
60
kms/migrations/002_user_sessions.up.sql
Normal file
60
kms/migrations/002_user_sessions.up.sql
Normal file
@ -0,0 +1,60 @@
|
||||
-- Create user_sessions table for session management
|
||||
CREATE TABLE IF NOT EXISTS user_sessions (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
user_id VARCHAR(255) NOT NULL,
|
||||
app_id VARCHAR(255) NOT NULL,
|
||||
session_type VARCHAR(20) NOT NULL CHECK (session_type IN ('web', 'mobile', 'api')),
|
||||
status VARCHAR(20) NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'expired', 'revoked', 'suspended')),
|
||||
access_token TEXT,
|
||||
refresh_token TEXT,
|
||||
id_token TEXT,
|
||||
ip_address INET,
|
||||
user_agent TEXT,
|
||||
last_activity TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
|
||||
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
revoked_at TIMESTAMP WITH TIME ZONE,
|
||||
revoked_by VARCHAR(255),
|
||||
metadata JSONB DEFAULT '{}',
|
||||
|
||||
-- Foreign key constraint to applications table
|
||||
CONSTRAINT fk_user_sessions_app_id FOREIGN KEY (app_id) REFERENCES applications(app_id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
-- Create indexes for performance
|
||||
CREATE INDEX IF NOT EXISTS idx_user_sessions_user_id ON user_sessions(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_user_sessions_app_id ON user_sessions(app_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_user_sessions_user_app ON user_sessions(user_id, app_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_user_sessions_status ON user_sessions(status);
|
||||
CREATE INDEX IF NOT EXISTS idx_user_sessions_expires_at ON user_sessions(expires_at);
|
||||
CREATE INDEX IF NOT EXISTS idx_user_sessions_last_activity ON user_sessions(last_activity);
|
||||
CREATE INDEX IF NOT EXISTS idx_user_sessions_created_at ON user_sessions(created_at);
|
||||
|
||||
-- Create partial indexes for active sessions (most common queries)
|
||||
CREATE INDEX IF NOT EXISTS idx_user_sessions_active ON user_sessions(user_id, app_id) WHERE status = 'active';
|
||||
CREATE INDEX IF NOT EXISTS idx_user_sessions_active_expires ON user_sessions(user_id, expires_at) WHERE status = 'active';
|
||||
|
||||
-- Create GIN index for metadata JSONB queries
|
||||
CREATE INDEX IF NOT EXISTS idx_user_sessions_metadata ON user_sessions USING GIN (metadata);
|
||||
|
||||
-- Create index for tenant-based queries (if using multi-tenancy)
|
||||
CREATE INDEX IF NOT EXISTS idx_user_sessions_tenant ON user_sessions((metadata->>'tenant_id')) WHERE metadata->>'tenant_id' IS NOT NULL;
|
||||
|
||||
-- Add comments for documentation
|
||||
COMMENT ON TABLE user_sessions IS 'Stores user session information for authentication and session management';
|
||||
COMMENT ON COLUMN user_sessions.id IS 'Unique session identifier';
|
||||
COMMENT ON COLUMN user_sessions.user_id IS 'User identifier (email, username, or external ID)';
|
||||
COMMENT ON COLUMN user_sessions.app_id IS 'Application identifier this session belongs to';
|
||||
COMMENT ON COLUMN user_sessions.session_type IS 'Type of session: web, mobile, or api';
|
||||
COMMENT ON COLUMN user_sessions.status IS 'Current session status: active, expired, revoked, or suspended';
|
||||
COMMENT ON COLUMN user_sessions.access_token IS 'OAuth2/OIDC access token (encrypted/hashed)';
|
||||
COMMENT ON COLUMN user_sessions.refresh_token IS 'OAuth2/OIDC refresh token (encrypted/hashed)';
|
||||
COMMENT ON COLUMN user_sessions.id_token IS 'OIDC ID token (encrypted/hashed)';
|
||||
COMMENT ON COLUMN user_sessions.ip_address IS 'IP address of the client when session was created';
|
||||
COMMENT ON COLUMN user_sessions.user_agent IS 'User agent string of the client';
|
||||
COMMENT ON COLUMN user_sessions.last_activity IS 'Timestamp of last session activity';
|
||||
COMMENT ON COLUMN user_sessions.expires_at IS 'When the session expires';
|
||||
COMMENT ON COLUMN user_sessions.revoked_at IS 'When the session was revoked (if applicable)';
|
||||
COMMENT ON COLUMN user_sessions.revoked_by IS 'Who revoked the session (user ID or system)';
|
||||
COMMENT ON COLUMN user_sessions.metadata IS 'Additional session metadata (device info, location, etc.)';
|
||||
11
kms/migrations/003_add_token_prefix.down.sql
Normal file
11
kms/migrations/003_add_token_prefix.down.sql
Normal file
@ -0,0 +1,11 @@
|
||||
-- Migration: 003_add_token_prefix (down)
|
||||
-- Remove token prefix field from applications table
|
||||
|
||||
-- Drop constraint first
|
||||
ALTER TABLE applications DROP CONSTRAINT IF EXISTS chk_token_prefix_format;
|
||||
|
||||
-- Drop index
|
||||
DROP INDEX IF EXISTS idx_applications_token_prefix;
|
||||
|
||||
-- Drop the prefix column
|
||||
ALTER TABLE applications DROP COLUMN IF EXISTS token_prefix;
|
||||
20
kms/migrations/003_add_token_prefix.up.sql
Normal file
20
kms/migrations/003_add_token_prefix.up.sql
Normal file
@ -0,0 +1,20 @@
|
||||
-- Migration: 003_add_token_prefix
|
||||
-- Add token prefix field to applications table
|
||||
|
||||
-- Add prefix field to applications table
|
||||
ALTER TABLE applications ADD COLUMN token_prefix VARCHAR(10) DEFAULT '' NOT NULL;
|
||||
|
||||
-- Add check constraint to ensure prefix is 2-4 uppercase letters
|
||||
ALTER TABLE applications ADD CONSTRAINT chk_token_prefix_format
|
||||
CHECK (token_prefix ~ '^[A-Z]{2,4}$' OR token_prefix = '');
|
||||
|
||||
-- Create index for prefix field
|
||||
CREATE INDEX idx_applications_token_prefix ON applications(token_prefix);
|
||||
|
||||
-- Update existing applications with empty prefix (they will use the default "kms_" prefix)
|
||||
-- Applications can later be updated to have custom prefixes
|
||||
|
||||
-- Set the internal application prefix to "KMS"
|
||||
UPDATE applications
|
||||
SET token_prefix = 'KMS'
|
||||
WHERE app_id = 'internal.api-key-service';
|
||||
27
kms/migrations/004_add_audit_events.down.sql
Normal file
27
kms/migrations/004_add_audit_events.down.sql
Normal file
@ -0,0 +1,27 @@
|
||||
-- Migration: 004_add_audit_events (down)
|
||||
-- Remove audit_events table and related objects
|
||||
|
||||
-- Drop the cleanup function
|
||||
DROP FUNCTION IF EXISTS cleanup_old_audit_events(INTEGER);
|
||||
|
||||
-- Drop indexes first (they will be dropped automatically with the table, but explicit for clarity)
|
||||
DROP INDEX IF EXISTS idx_audit_events_timestamp;
|
||||
DROP INDEX IF EXISTS idx_audit_events_type;
|
||||
DROP INDEX IF EXISTS idx_audit_events_severity;
|
||||
DROP INDEX IF EXISTS idx_audit_events_status;
|
||||
DROP INDEX IF EXISTS idx_audit_events_actor_id;
|
||||
DROP INDEX IF EXISTS idx_audit_events_actor_type;
|
||||
DROP INDEX IF EXISTS idx_audit_events_tenant_id;
|
||||
DROP INDEX IF EXISTS idx_audit_events_resource;
|
||||
DROP INDEX IF EXISTS idx_audit_events_request_id;
|
||||
DROP INDEX IF EXISTS idx_audit_events_session_id;
|
||||
DROP INDEX IF EXISTS idx_audit_events_details;
|
||||
DROP INDEX IF EXISTS idx_audit_events_metadata;
|
||||
DROP INDEX IF EXISTS idx_audit_events_tags;
|
||||
DROP INDEX IF EXISTS idx_audit_events_actor_timestamp;
|
||||
DROP INDEX IF EXISTS idx_audit_events_type_timestamp;
|
||||
DROP INDEX IF EXISTS idx_audit_events_tenant_timestamp;
|
||||
DROP INDEX IF EXISTS idx_audit_events_resource_timestamp;
|
||||
|
||||
-- Drop the audit_events table
|
||||
DROP TABLE IF EXISTS audit_events;
|
||||
102
kms/migrations/004_add_audit_events.up.sql
Normal file
102
kms/migrations/004_add_audit_events.up.sql
Normal file
@ -0,0 +1,102 @@
|
||||
-- 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)';
|
||||
Reference in New Issue
Block a user