-- Policy Schema Migration 001: Initial Schema -- Creates the policy schema for packs, rules, and risk profiles -- Create schema CREATE SCHEMA IF NOT EXISTS policy; -- Packs table (policy pack containers) CREATE TABLE IF NOT EXISTS policy.packs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), tenant_id TEXT NOT NULL, name TEXT NOT NULL, display_name TEXT, description TEXT, active_version INT, is_builtin BOOLEAN NOT NULL DEFAULT FALSE, is_deprecated BOOLEAN NOT NULL DEFAULT FALSE, metadata JSONB NOT NULL DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), created_by TEXT, UNIQUE(tenant_id, name) ); CREATE INDEX idx_packs_tenant ON policy.packs(tenant_id); CREATE INDEX idx_packs_builtin ON policy.packs(is_builtin); -- Pack versions table (immutable versions) CREATE TABLE IF NOT EXISTS policy.pack_versions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), pack_id UUID NOT NULL REFERENCES policy.packs(id) ON DELETE CASCADE, version INT NOT NULL, description TEXT, rules_hash TEXT NOT NULL, is_published BOOLEAN NOT NULL DEFAULT FALSE, published_at TIMESTAMPTZ, published_by TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), created_by TEXT, UNIQUE(pack_id, version) ); CREATE INDEX idx_pack_versions_pack ON policy.pack_versions(pack_id); CREATE INDEX idx_pack_versions_published ON policy.pack_versions(pack_id, is_published); -- Rules table (OPA/Rego rules) CREATE TABLE IF NOT EXISTS policy.rules ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), pack_version_id UUID NOT NULL REFERENCES policy.pack_versions(id) ON DELETE CASCADE, name TEXT NOT NULL, description TEXT, rule_type TEXT NOT NULL DEFAULT 'rego' CHECK (rule_type IN ('rego', 'json', 'yaml')), content TEXT NOT NULL, content_hash TEXT NOT NULL, severity TEXT NOT NULL DEFAULT 'medium' CHECK (severity IN ('critical', 'high', 'medium', 'low', 'info')), category TEXT, tags TEXT[] NOT NULL DEFAULT '{}', metadata JSONB NOT NULL DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), UNIQUE(pack_version_id, name) ); CREATE INDEX idx_rules_pack_version ON policy.rules(pack_version_id); CREATE INDEX idx_rules_severity ON policy.rules(severity); CREATE INDEX idx_rules_category ON policy.rules(category); CREATE INDEX idx_rules_tags ON policy.rules USING GIN(tags); -- Risk profiles table CREATE TABLE IF NOT EXISTS policy.risk_profiles ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), tenant_id TEXT NOT NULL, name TEXT NOT NULL, display_name TEXT, description TEXT, version INT NOT NULL DEFAULT 1, is_active BOOLEAN NOT NULL DEFAULT TRUE, thresholds JSONB NOT NULL DEFAULT '{}', scoring_weights JSONB NOT NULL DEFAULT '{}', exemptions JSONB NOT NULL DEFAULT '[]', metadata JSONB NOT NULL DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), created_by TEXT, UNIQUE(tenant_id, name, version) ); CREATE INDEX idx_risk_profiles_tenant ON policy.risk_profiles(tenant_id); CREATE INDEX idx_risk_profiles_active ON policy.risk_profiles(tenant_id, name, is_active) WHERE is_active = TRUE; -- Risk profile history (for audit trail) CREATE TABLE IF NOT EXISTS policy.risk_profile_history ( id BIGSERIAL PRIMARY KEY, risk_profile_id UUID NOT NULL REFERENCES policy.risk_profiles(id), version INT NOT NULL, thresholds JSONB NOT NULL, scoring_weights JSONB NOT NULL, exemptions JSONB NOT NULL, changed_by TEXT, changed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), change_reason TEXT ); CREATE INDEX idx_risk_profile_history_profile ON policy.risk_profile_history(risk_profile_id); -- Evaluation runs table CREATE TABLE IF NOT EXISTS policy.evaluation_runs ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), tenant_id TEXT NOT NULL, project_id TEXT, artifact_id TEXT, pack_id UUID REFERENCES policy.packs(id), pack_version INT, risk_profile_id UUID REFERENCES policy.risk_profiles(id), status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'running', 'completed', 'failed')), result TEXT CHECK (result IN ('pass', 'fail', 'warn', 'error')), score NUMERIC(5,2), findings_count INT NOT NULL DEFAULT 0, critical_count INT NOT NULL DEFAULT 0, high_count INT NOT NULL DEFAULT 0, medium_count INT NOT NULL DEFAULT 0, low_count INT NOT NULL DEFAULT 0, input_hash TEXT, duration_ms INT, error_message TEXT, metadata JSONB NOT NULL DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), started_at TIMESTAMPTZ, completed_at TIMESTAMPTZ, created_by TEXT ); CREATE INDEX idx_evaluation_runs_tenant ON policy.evaluation_runs(tenant_id); CREATE INDEX idx_evaluation_runs_project ON policy.evaluation_runs(tenant_id, project_id); CREATE INDEX idx_evaluation_runs_artifact ON policy.evaluation_runs(tenant_id, artifact_id); CREATE INDEX idx_evaluation_runs_created ON policy.evaluation_runs(tenant_id, created_at); CREATE INDEX idx_evaluation_runs_status ON policy.evaluation_runs(status); -- Explanations table (rule evaluation details) CREATE TABLE IF NOT EXISTS policy.explanations ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), evaluation_run_id UUID NOT NULL REFERENCES policy.evaluation_runs(id) ON DELETE CASCADE, rule_id UUID REFERENCES policy.rules(id), rule_name TEXT NOT NULL, result TEXT NOT NULL CHECK (result IN ('pass', 'fail', 'skip', 'error')), severity TEXT NOT NULL, message TEXT, details JSONB NOT NULL DEFAULT '{}', remediation TEXT, resource_path TEXT, line_number INT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_explanations_run ON policy.explanations(evaluation_run_id); CREATE INDEX idx_explanations_result ON policy.explanations(evaluation_run_id, result); -- Exceptions table (policy exceptions/waivers) CREATE TABLE IF NOT EXISTS policy.exceptions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), tenant_id TEXT NOT NULL, name TEXT NOT NULL, description TEXT, rule_pattern TEXT, resource_pattern TEXT, artifact_pattern TEXT, project_id TEXT, reason TEXT NOT NULL, status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'expired', 'revoked')), expires_at TIMESTAMPTZ, approved_by TEXT, approved_at TIMESTAMPTZ, revoked_by TEXT, revoked_at TIMESTAMPTZ, metadata JSONB NOT NULL DEFAULT '{}', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), created_by TEXT, UNIQUE(tenant_id, name) ); CREATE INDEX idx_exceptions_tenant ON policy.exceptions(tenant_id); CREATE INDEX idx_exceptions_status ON policy.exceptions(tenant_id, status); CREATE INDEX idx_exceptions_expires ON policy.exceptions(expires_at) WHERE status = 'active'; CREATE INDEX idx_exceptions_project ON policy.exceptions(tenant_id, project_id); -- Audit log table CREATE TABLE IF NOT EXISTS policy.audit ( id BIGSERIAL PRIMARY KEY, tenant_id TEXT NOT NULL, user_id UUID, action TEXT NOT NULL, resource_type TEXT NOT NULL, resource_id TEXT, old_value JSONB, new_value JSONB, correlation_id TEXT, created_at TIMESTAMPTZ NOT NULL DEFAULT NOW() ); CREATE INDEX idx_audit_tenant ON policy.audit(tenant_id); CREATE INDEX idx_audit_resource ON policy.audit(resource_type, resource_id); CREATE INDEX idx_audit_created ON policy.audit(tenant_id, created_at); -- Update timestamp function CREATE OR REPLACE FUNCTION policy.update_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Triggers CREATE TRIGGER trg_packs_updated_at BEFORE UPDATE ON policy.packs FOR EACH ROW EXECUTE FUNCTION policy.update_updated_at(); CREATE TRIGGER trg_risk_profiles_updated_at BEFORE UPDATE ON policy.risk_profiles FOR EACH ROW EXECUTE FUNCTION policy.update_updated_at();