Add unit tests for Router configuration and transport layers
- Implemented tests for RouterConfig, RoutingOptions, StaticInstanceConfig, and RouterConfigOptions to ensure default values are set correctly. - Added tests for RouterConfigProvider to validate configurations and ensure defaults are returned when no file is specified. - Created tests for ConfigValidationResult to check success and error scenarios. - Developed tests for ServiceCollectionExtensions to verify service registration for RouterConfig. - Introduced UdpTransportTests to validate serialization, connection, request-response, and error handling in UDP transport. - Added scripts for signing authority gaps and hashing DevPortal SDK snippets.
This commit is contained in:
23
docs/db/schemas/audit.sql
Normal file
23
docs/db/schemas/audit.sql
Normal file
@@ -0,0 +1,23 @@
|
||||
-- Shared audit schema (generic event log usable by multiple modules)
|
||||
-- Status: PROPOSED (2025-12-05)
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS audit;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS audit.events (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
tenant_id UUID NOT NULL,
|
||||
module TEXT NOT NULL, -- e.g., authority, scheduler, notify, issuer
|
||||
entity_type TEXT NOT NULL, -- e.g., issuer, schedule, policy_pack
|
||||
entity_id UUID,
|
||||
action TEXT NOT NULL, -- e.g., create, update, delete
|
||||
actor TEXT,
|
||||
actor_type TEXT CHECK (actor_type IN ('user','service','system')),
|
||||
reason TEXT,
|
||||
details JSONB DEFAULT '{}'::jsonb,
|
||||
correlation_id TEXT,
|
||||
occurred_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_audit_module_time ON audit.events(module, occurred_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_audit_tenant_time ON audit.events(tenant_id, occurred_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_audit_entity ON audit.events(entity_type, entity_id);
|
||||
163
docs/db/schemas/authority.sql
Normal file
163
docs/db/schemas/authority.sql
Normal file
@@ -0,0 +1,163 @@
|
||||
-- Generated from docs/db/SPECIFICATION.md §5.1 (2025-11-28)
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS authority;
|
||||
|
||||
-- Core identity tables
|
||||
CREATE TABLE IF NOT EXISTS authority.tenants (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
code TEXT NOT NULL UNIQUE,
|
||||
display_name TEXT NOT NULL,
|
||||
status TEXT NOT NULL DEFAULT 'active'
|
||||
CHECK (status IN ('active', 'suspended', 'trial', 'terminated')),
|
||||
settings JSONB DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS authority.users (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL REFERENCES authority.tenants(id),
|
||||
subject_id UUID NOT NULL UNIQUE,
|
||||
username TEXT NOT NULL,
|
||||
normalized_username TEXT NOT NULL,
|
||||
display_name TEXT,
|
||||
email TEXT,
|
||||
email_verified BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
disabled BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
plugin TEXT,
|
||||
attributes JSONB DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE (tenant_id, normalized_username)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS authority.roles (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID REFERENCES authority.tenants(id),
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
is_system BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
permissions TEXT[] DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE (tenant_id, name)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS authority.user_roles (
|
||||
user_id UUID NOT NULL REFERENCES authority.users(id) ON DELETE CASCADE,
|
||||
role_id UUID NOT NULL REFERENCES authority.roles(id) ON DELETE CASCADE,
|
||||
granted_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
granted_by TEXT,
|
||||
PRIMARY KEY (user_id, role_id)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS authority.service_accounts (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL REFERENCES authority.tenants(id),
|
||||
account_id TEXT NOT NULL,
|
||||
display_name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
enabled BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
allowed_scopes TEXT[] DEFAULT '{}',
|
||||
authorized_clients TEXT[] DEFAULT '{}',
|
||||
attributes JSONB DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE (tenant_id, account_id)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS authority.clients (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
client_id TEXT NOT NULL UNIQUE,
|
||||
client_secret_hash TEXT,
|
||||
display_name TEXT,
|
||||
type TEXT NOT NULL DEFAULT 'confidential'
|
||||
CHECK (type IN ('public', 'confidential')),
|
||||
redirect_uris TEXT[] DEFAULT '{}',
|
||||
post_logout_redirect_uris TEXT[] DEFAULT '{}',
|
||||
permissions TEXT[] DEFAULT '{}',
|
||||
requirements TEXT[] DEFAULT '{}',
|
||||
settings JSONB DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS authority.scopes (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
display_name TEXT,
|
||||
description TEXT,
|
||||
resources TEXT[] DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS authority.tokens (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
subject_id UUID NOT NULL,
|
||||
client_id TEXT,
|
||||
token_type TEXT NOT NULL CHECK (token_type IN ('access', 'refresh', 'authorization_code')),
|
||||
token_hash TEXT NOT NULL UNIQUE,
|
||||
scopes TEXT[] DEFAULT '{}',
|
||||
issued_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
expires_at TIMESTAMPTZ NOT NULL,
|
||||
revoked_at TIMESTAMPTZ,
|
||||
revocation_reason TEXT,
|
||||
metadata JSONB DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS authority.revocations (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
token_id UUID REFERENCES authority.tokens(id),
|
||||
jti TEXT,
|
||||
revoked_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
reason TEXT,
|
||||
revoked_by TEXT
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS authority.login_attempts (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID REFERENCES authority.tenants(id),
|
||||
username TEXT NOT NULL,
|
||||
ip_address INET,
|
||||
user_agent TEXT,
|
||||
success BOOLEAN NOT NULL,
|
||||
failure_reason TEXT,
|
||||
attempted_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS authority.licenses (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL REFERENCES authority.tenants(id),
|
||||
license_key TEXT NOT NULL UNIQUE,
|
||||
edition TEXT NOT NULL CHECK (edition IN ('community', 'standard', 'enterprise', 'sovereign')),
|
||||
max_nodes INT,
|
||||
max_projects INT,
|
||||
features JSONB DEFAULT '{}',
|
||||
start_date DATE NOT NULL,
|
||||
end_date DATE,
|
||||
issued_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
issued_by TEXT,
|
||||
revoked_at TIMESTAMPTZ,
|
||||
revocation_reason TEXT
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS authority.license_usage (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
license_id UUID NOT NULL REFERENCES authority.licenses(id),
|
||||
scanner_node_id TEXT NOT NULL,
|
||||
project_id TEXT,
|
||||
scanner_version TEXT,
|
||||
first_seen_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
last_seen_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE (license_id, scanner_node_id)
|
||||
);
|
||||
|
||||
-- Indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_users_tenant ON authority.users(tenant_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_users_email ON authority.users(email) WHERE email IS NOT NULL;
|
||||
CREATE INDEX IF NOT EXISTS idx_users_subject ON authority.users(subject_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_service_accounts_tenant ON authority.service_accounts(tenant_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_tokens_subject ON authority.tokens(subject_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_tokens_expires ON authority.tokens(expires_at) WHERE revoked_at IS NULL;
|
||||
CREATE INDEX IF NOT EXISTS idx_tokens_hash ON authority.tokens(token_hash);
|
||||
CREATE INDEX IF NOT EXISTS idx_login_attempts_tenant_time ON authority.login_attempts(tenant_id, attempted_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_licenses_tenant ON authority.licenses(tenant_id);
|
||||
98
docs/db/schemas/issuer.sql
Normal file
98
docs/db/schemas/issuer.sql
Normal file
@@ -0,0 +1,98 @@
|
||||
-- IssuerDirectory PostgreSQL schema (designed from docs/modules/issuer-directory/architecture.md)
|
||||
-- Status: PROPOSED (2025-12-05) – replaces Mongo collections issuer_directory.issuers / issuer_keys / issuer_audit
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS issuer;
|
||||
|
||||
-- Issuers (tenant or global)
|
||||
CREATE TABLE IF NOT EXISTS issuer.issuers (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL, -- use @global GUID for seed publishers
|
||||
name TEXT NOT NULL, -- logical issuer name (slug)
|
||||
display_name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
endpoints JSONB DEFAULT '{}'::jsonb, -- CSAF feeds, OIDC issuer URLs, contact links
|
||||
tags TEXT[] DEFAULT '{}',
|
||||
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active','revoked','deprecated')),
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
created_by TEXT,
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_by TEXT,
|
||||
UNIQUE (tenant_id, name)
|
||||
);
|
||||
|
||||
-- Keys
|
||||
CREATE TABLE IF NOT EXISTS issuer.issuer_keys (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
issuer_id UUID NOT NULL REFERENCES issuer.issuers(id) ON DELETE CASCADE,
|
||||
key_id TEXT NOT NULL, -- stable key identifier
|
||||
key_type TEXT NOT NULL CHECK (key_type IN ('ed25519','x509','dsse','kms','hsm','fido2')),
|
||||
public_key TEXT NOT NULL, -- PEM / base64
|
||||
fingerprint TEXT NOT NULL, -- canonical fingerprint for dedupe
|
||||
not_before TIMESTAMPTZ,
|
||||
not_after TIMESTAMPTZ,
|
||||
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active','retired','revoked')),
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
created_by TEXT,
|
||||
revoked_at TIMESTAMPTZ,
|
||||
revoked_by TEXT,
|
||||
revoke_reason TEXT,
|
||||
metadata JSONB DEFAULT '{}'::jsonb,
|
||||
UNIQUE (issuer_id, key_id),
|
||||
UNIQUE (fingerprint)
|
||||
);
|
||||
|
||||
-- Trust overrides (tenant-scoped weights)
|
||||
CREATE TABLE IF NOT EXISTS issuer.trust_overrides (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
issuer_id UUID NOT NULL REFERENCES issuer.issuers(id) ON DELETE CASCADE,
|
||||
tenant_id UUID NOT NULL, -- consumer tenant applying the override
|
||||
weight NUMERIC(5,2) NOT NULL CHECK (weight >= 0 AND weight <= 1),
|
||||
rationale TEXT,
|
||||
expires_at TIMESTAMPTZ,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
created_by TEXT,
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_by TEXT,
|
||||
UNIQUE (issuer_id, tenant_id)
|
||||
);
|
||||
|
||||
-- Audit log (issuer-domain specific)
|
||||
CREATE TABLE IF NOT EXISTS issuer.audit (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
tenant_id UUID NOT NULL,
|
||||
actor TEXT,
|
||||
action TEXT NOT NULL, -- create_issuer, update_issuer, delete_issuer, add_key, rotate_key, revoke_key, set_trust, delete_trust, seed_csaf
|
||||
issuer_id UUID,
|
||||
key_id TEXT,
|
||||
trust_override_id UUID,
|
||||
reason TEXT,
|
||||
details JSONB DEFAULT '{}'::jsonb,
|
||||
correlation_id TEXT,
|
||||
occurred_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_issuers_tenant ON issuer.issuers(tenant_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_issuers_status ON issuer.issuers(status);
|
||||
CREATE INDEX IF NOT EXISTS idx_keys_issuer ON issuer.issuer_keys(issuer_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_keys_status ON issuer.issuer_keys(status);
|
||||
CREATE INDEX IF NOT EXISTS idx_trust_tenant ON issuer.trust_overrides(tenant_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_audit_tenant_time ON issuer.audit(tenant_id, occurred_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_audit_issuer ON issuer.audit(issuer_id);
|
||||
|
||||
-- Updated-at trigger for issuers/trust overrides
|
||||
CREATE OR REPLACE FUNCTION issuer.update_updated_at()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = NOW();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TRIGGER trg_issuers_updated_at
|
||||
BEFORE UPDATE ON issuer.issuers
|
||||
FOR EACH ROW EXECUTE FUNCTION issuer.update_updated_at();
|
||||
|
||||
CREATE TRIGGER trg_trust_updated_at
|
||||
BEFORE UPDATE ON issuer.trust_overrides
|
||||
FOR EACH ROW EXECUTE FUNCTION issuer.update_updated_at();
|
||||
340
docs/db/schemas/notify.sql
Normal file
340
docs/db/schemas/notify.sql
Normal file
@@ -0,0 +1,340 @@
|
||||
-- Notify Schema Migration 001: Initial Schema
|
||||
-- Creates the notify schema for notifications, channels, and delivery tracking
|
||||
|
||||
-- Create schema
|
||||
CREATE SCHEMA IF NOT EXISTS notify;
|
||||
|
||||
-- Channel types
|
||||
DO $$ BEGIN
|
||||
CREATE TYPE notify.channel_type AS ENUM (
|
||||
'email', 'slack', 'teams', 'webhook', 'pagerduty', 'opsgenie'
|
||||
);
|
||||
EXCEPTION
|
||||
WHEN duplicate_object THEN null;
|
||||
END $$;
|
||||
|
||||
-- Delivery status
|
||||
DO $$ BEGIN
|
||||
CREATE TYPE notify.delivery_status AS ENUM (
|
||||
'pending', 'queued', 'sending', 'sent', 'delivered', 'failed', 'bounced'
|
||||
);
|
||||
EXCEPTION
|
||||
WHEN duplicate_object THEN null;
|
||||
END $$;
|
||||
|
||||
-- Channels table
|
||||
CREATE TABLE IF NOT EXISTS notify.channels (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
channel_type notify.channel_type NOT NULL,
|
||||
enabled BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
config JSONB NOT NULL DEFAULT '{}',
|
||||
credentials JSONB,
|
||||
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_channels_tenant ON notify.channels(tenant_id);
|
||||
CREATE INDEX idx_channels_type ON notify.channels(tenant_id, channel_type);
|
||||
|
||||
-- Rules table (notification routing rules)
|
||||
CREATE TABLE IF NOT EXISTS notify.rules (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
enabled BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
priority INT NOT NULL DEFAULT 0,
|
||||
event_types TEXT[] NOT NULL DEFAULT '{}',
|
||||
filter JSONB NOT NULL DEFAULT '{}',
|
||||
channel_ids UUID[] NOT NULL DEFAULT '{}',
|
||||
template_id UUID,
|
||||
metadata JSONB NOT NULL DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(tenant_id, name)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_rules_tenant ON notify.rules(tenant_id);
|
||||
CREATE INDEX idx_rules_enabled ON notify.rules(tenant_id, enabled, priority DESC);
|
||||
|
||||
-- Templates table
|
||||
CREATE TABLE IF NOT EXISTS notify.templates (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
channel_type notify.channel_type NOT NULL,
|
||||
subject_template TEXT,
|
||||
body_template TEXT NOT NULL,
|
||||
locale TEXT NOT NULL DEFAULT 'en',
|
||||
metadata JSONB NOT NULL DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(tenant_id, name, channel_type, locale)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_templates_tenant ON notify.templates(tenant_id);
|
||||
|
||||
-- Deliveries table
|
||||
CREATE TABLE IF NOT EXISTS notify.deliveries (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
channel_id UUID NOT NULL REFERENCES notify.channels(id),
|
||||
rule_id UUID REFERENCES notify.rules(id),
|
||||
template_id UUID REFERENCES notify.templates(id),
|
||||
status notify.delivery_status NOT NULL DEFAULT 'pending',
|
||||
recipient TEXT NOT NULL,
|
||||
subject TEXT,
|
||||
body TEXT,
|
||||
event_type TEXT NOT NULL,
|
||||
event_payload JSONB NOT NULL DEFAULT '{}',
|
||||
attempt INT NOT NULL DEFAULT 0,
|
||||
max_attempts INT NOT NULL DEFAULT 3,
|
||||
next_retry_at TIMESTAMPTZ,
|
||||
error_message TEXT,
|
||||
external_id TEXT,
|
||||
correlation_id TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
queued_at TIMESTAMPTZ,
|
||||
sent_at TIMESTAMPTZ,
|
||||
delivered_at TIMESTAMPTZ,
|
||||
failed_at TIMESTAMPTZ
|
||||
);
|
||||
|
||||
CREATE INDEX idx_deliveries_tenant ON notify.deliveries(tenant_id);
|
||||
CREATE INDEX idx_deliveries_status ON notify.deliveries(tenant_id, status);
|
||||
CREATE INDEX idx_deliveries_pending ON notify.deliveries(status, next_retry_at)
|
||||
WHERE status IN ('pending', 'queued');
|
||||
CREATE INDEX idx_deliveries_channel ON notify.deliveries(channel_id);
|
||||
CREATE INDEX idx_deliveries_correlation ON notify.deliveries(correlation_id);
|
||||
CREATE INDEX idx_deliveries_created ON notify.deliveries(tenant_id, created_at);
|
||||
|
||||
-- Digests table (aggregated notifications)
|
||||
CREATE TABLE IF NOT EXISTS notify.digests (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
channel_id UUID NOT NULL REFERENCES notify.channels(id),
|
||||
recipient TEXT NOT NULL,
|
||||
digest_key TEXT NOT NULL,
|
||||
event_count INT NOT NULL DEFAULT 0,
|
||||
events JSONB NOT NULL DEFAULT '[]',
|
||||
status TEXT NOT NULL DEFAULT 'collecting' CHECK (status IN ('collecting', 'sending', 'sent')),
|
||||
collect_until TIMESTAMPTZ NOT NULL,
|
||||
sent_at TIMESTAMPTZ,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(tenant_id, channel_id, recipient, digest_key)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_digests_tenant ON notify.digests(tenant_id);
|
||||
CREATE INDEX idx_digests_collect ON notify.digests(status, collect_until)
|
||||
WHERE status = 'collecting';
|
||||
|
||||
-- Quiet hours table
|
||||
CREATE TABLE IF NOT EXISTS notify.quiet_hours (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
user_id UUID,
|
||||
channel_id UUID REFERENCES notify.channels(id),
|
||||
start_time TIME NOT NULL,
|
||||
end_time TIME NOT NULL,
|
||||
timezone TEXT NOT NULL DEFAULT 'UTC',
|
||||
days_of_week INT[] NOT NULL DEFAULT '{0,1,2,3,4,5,6}',
|
||||
enabled BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_quiet_hours_tenant ON notify.quiet_hours(tenant_id);
|
||||
|
||||
-- Maintenance windows table
|
||||
CREATE TABLE IF NOT EXISTS notify.maintenance_windows (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
start_at TIMESTAMPTZ NOT NULL,
|
||||
end_at TIMESTAMPTZ NOT NULL,
|
||||
suppress_channels UUID[],
|
||||
suppress_event_types TEXT[],
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
created_by TEXT,
|
||||
UNIQUE(tenant_id, name)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_maintenance_windows_tenant ON notify.maintenance_windows(tenant_id);
|
||||
CREATE INDEX idx_maintenance_windows_active ON notify.maintenance_windows(start_at, end_at);
|
||||
|
||||
-- Escalation policies table
|
||||
CREATE TABLE IF NOT EXISTS notify.escalation_policies (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
enabled BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
steps JSONB NOT NULL DEFAULT '[]',
|
||||
repeat_count INT NOT NULL DEFAULT 0,
|
||||
metadata JSONB NOT NULL DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(tenant_id, name)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_escalation_policies_tenant ON notify.escalation_policies(tenant_id);
|
||||
|
||||
-- Escalation states table
|
||||
CREATE TABLE IF NOT EXISTS notify.escalation_states (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
policy_id UUID NOT NULL REFERENCES notify.escalation_policies(id),
|
||||
incident_id UUID,
|
||||
correlation_id TEXT NOT NULL,
|
||||
current_step INT NOT NULL DEFAULT 0,
|
||||
repeat_iteration INT NOT NULL DEFAULT 0,
|
||||
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'acknowledged', 'resolved', 'expired')),
|
||||
started_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
next_escalation_at TIMESTAMPTZ,
|
||||
acknowledged_at TIMESTAMPTZ,
|
||||
acknowledged_by TEXT,
|
||||
resolved_at TIMESTAMPTZ,
|
||||
resolved_by TEXT,
|
||||
metadata JSONB NOT NULL DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE INDEX idx_escalation_states_tenant ON notify.escalation_states(tenant_id);
|
||||
CREATE INDEX idx_escalation_states_active ON notify.escalation_states(status, next_escalation_at)
|
||||
WHERE status = 'active';
|
||||
CREATE INDEX idx_escalation_states_correlation ON notify.escalation_states(correlation_id);
|
||||
|
||||
-- On-call schedules table
|
||||
CREATE TABLE IF NOT EXISTS notify.on_call_schedules (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
timezone TEXT NOT NULL DEFAULT 'UTC',
|
||||
rotation_type TEXT NOT NULL DEFAULT 'weekly' CHECK (rotation_type IN ('daily', 'weekly', 'custom')),
|
||||
participants JSONB NOT NULL DEFAULT '[]',
|
||||
overrides JSONB NOT NULL DEFAULT '[]',
|
||||
metadata JSONB NOT NULL DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(tenant_id, name)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_on_call_schedules_tenant ON notify.on_call_schedules(tenant_id);
|
||||
|
||||
-- Inbox table (in-app notifications)
|
||||
CREATE TABLE IF NOT EXISTS notify.inbox (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
user_id UUID NOT NULL,
|
||||
title TEXT NOT NULL,
|
||||
body TEXT,
|
||||
event_type TEXT NOT NULL,
|
||||
event_payload JSONB NOT NULL DEFAULT '{}',
|
||||
read BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
archived BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
action_url TEXT,
|
||||
correlation_id TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
read_at TIMESTAMPTZ,
|
||||
archived_at TIMESTAMPTZ
|
||||
);
|
||||
|
||||
CREATE INDEX idx_inbox_tenant_user ON notify.inbox(tenant_id, user_id);
|
||||
CREATE INDEX idx_inbox_unread ON notify.inbox(tenant_id, user_id, read, created_at DESC)
|
||||
WHERE read = FALSE AND archived = FALSE;
|
||||
|
||||
-- Incidents table
|
||||
CREATE TABLE IF NOT EXISTS notify.incidents (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
title TEXT NOT NULL,
|
||||
description TEXT,
|
||||
severity TEXT NOT NULL DEFAULT 'medium' CHECK (severity IN ('critical', 'high', 'medium', 'low')),
|
||||
status TEXT NOT NULL DEFAULT 'open' CHECK (status IN ('open', 'acknowledged', 'resolved', 'closed')),
|
||||
source TEXT,
|
||||
correlation_id TEXT,
|
||||
assigned_to UUID,
|
||||
escalation_policy_id UUID REFERENCES notify.escalation_policies(id),
|
||||
metadata JSONB NOT NULL DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
acknowledged_at TIMESTAMPTZ,
|
||||
resolved_at TIMESTAMPTZ,
|
||||
closed_at TIMESTAMPTZ,
|
||||
created_by TEXT
|
||||
);
|
||||
|
||||
CREATE INDEX idx_incidents_tenant ON notify.incidents(tenant_id);
|
||||
CREATE INDEX idx_incidents_status ON notify.incidents(tenant_id, status);
|
||||
CREATE INDEX idx_incidents_severity ON notify.incidents(tenant_id, severity);
|
||||
CREATE INDEX idx_incidents_correlation ON notify.incidents(correlation_id);
|
||||
|
||||
-- Audit log table
|
||||
CREATE TABLE IF NOT EXISTS notify.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,
|
||||
details JSONB,
|
||||
correlation_id TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_audit_tenant ON notify.audit(tenant_id);
|
||||
CREATE INDEX idx_audit_created ON notify.audit(tenant_id, created_at);
|
||||
|
||||
-- Locks table (lightweight distributed locks)
|
||||
CREATE TABLE IF NOT EXISTS notify.locks (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id TEXT NOT NULL,
|
||||
resource TEXT NOT NULL,
|
||||
owner TEXT NOT NULL,
|
||||
expires_at TIMESTAMPTZ NOT NULL,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(tenant_id, resource)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_locks_tenant ON notify.locks(tenant_id);
|
||||
CREATE INDEX idx_locks_expiry ON notify.locks(expires_at);
|
||||
|
||||
-- Update timestamp function
|
||||
CREATE OR REPLACE FUNCTION notify.update_updated_at()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = NOW();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Triggers
|
||||
CREATE TRIGGER trg_channels_updated_at
|
||||
BEFORE UPDATE ON notify.channels
|
||||
FOR EACH ROW EXECUTE FUNCTION notify.update_updated_at();
|
||||
|
||||
CREATE TRIGGER trg_rules_updated_at
|
||||
BEFORE UPDATE ON notify.rules
|
||||
FOR EACH ROW EXECUTE FUNCTION notify.update_updated_at();
|
||||
|
||||
CREATE TRIGGER trg_templates_updated_at
|
||||
BEFORE UPDATE ON notify.templates
|
||||
FOR EACH ROW EXECUTE FUNCTION notify.update_updated_at();
|
||||
|
||||
CREATE TRIGGER trg_digests_updated_at
|
||||
BEFORE UPDATE ON notify.digests
|
||||
FOR EACH ROW EXECUTE FUNCTION notify.update_updated_at();
|
||||
|
||||
CREATE TRIGGER trg_escalation_policies_updated_at
|
||||
BEFORE UPDATE ON notify.escalation_policies
|
||||
FOR EACH ROW EXECUTE FUNCTION notify.update_updated_at();
|
||||
|
||||
CREATE TRIGGER trg_on_call_schedules_updated_at
|
||||
BEFORE UPDATE ON notify.on_call_schedules
|
||||
FOR EACH ROW EXECUTE FUNCTION notify.update_updated_at();
|
||||
2
docs/db/schemas/packs.sql
Normal file
2
docs/db/schemas/packs.sql
Normal file
@@ -0,0 +1,2 @@
|
||||
-- TODO: Export PacksRegistry schema DDL (SPECIFICATION.md §2.2 table, §5 mentions packs)
|
||||
-- Source of truth: SPECIFICATION.md (Last Updated: 2025-11-28)
|
||||
220
docs/db/schemas/policy.sql
Normal file
220
docs/db/schemas/policy.sql
Normal file
@@ -0,0 +1,220 @@
|
||||
-- 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();
|
||||
207
docs/db/schemas/scheduler.sql
Normal file
207
docs/db/schemas/scheduler.sql
Normal file
@@ -0,0 +1,207 @@
|
||||
-- Generated from docs/db/SPECIFICATION.md §5.4 (2025-11-28)
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS scheduler;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.schedules (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
enabled BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
cron_expression TEXT,
|
||||
timezone TEXT NOT NULL DEFAULT 'UTC',
|
||||
mode TEXT NOT NULL CHECK (mode IN ('scheduled', 'manual', 'on_event', 'continuous')),
|
||||
selection JSONB NOT NULL DEFAULT '{}',
|
||||
only_if JSONB DEFAULT '{}',
|
||||
notify JSONB DEFAULT '{}',
|
||||
limits JSONB DEFAULT '{}',
|
||||
subscribers TEXT[] DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
created_by TEXT,
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_by TEXT,
|
||||
deleted_at TIMESTAMPTZ,
|
||||
deleted_by TEXT,
|
||||
UNIQUE (tenant_id, name) WHERE deleted_at IS NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.triggers (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
schedule_id UUID NOT NULL REFERENCES scheduler.schedules(id) ON DELETE CASCADE,
|
||||
trigger_type TEXT NOT NULL CHECK (trigger_type IN ('cron', 'fixed_delay', 'manual', 'on_event', 'webhook')),
|
||||
cron_expression TEXT,
|
||||
fixed_delay_seconds INT,
|
||||
event_filter JSONB,
|
||||
timezone TEXT DEFAULT 'UTC',
|
||||
next_fire_time TIMESTAMPTZ,
|
||||
last_fire_time TIMESTAMPTZ,
|
||||
misfire_policy TEXT DEFAULT 'skip' CHECK (misfire_policy IN ('skip', 'fire_now', 'queue')),
|
||||
enabled BOOLEAN NOT NULL DEFAULT TRUE
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.runs (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
schedule_id UUID REFERENCES scheduler.schedules(id),
|
||||
trigger_id UUID REFERENCES scheduler.triggers(id),
|
||||
state TEXT NOT NULL CHECK (state IN ('pending', 'queued', 'running', 'completed', 'failed', 'cancelled', 'stale', 'timeout')),
|
||||
reason JSONB DEFAULT '{}',
|
||||
stats JSONB DEFAULT '{}',
|
||||
deltas JSONB DEFAULT '[]',
|
||||
worker_id UUID,
|
||||
retry_of UUID REFERENCES scheduler.runs(id),
|
||||
retry_count INT NOT NULL DEFAULT 0,
|
||||
error TEXT,
|
||||
error_details JSONB,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
started_at TIMESTAMPTZ,
|
||||
finished_at TIMESTAMPTZ,
|
||||
timeout_at TIMESTAMPTZ
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.graph_jobs (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
sbom_id TEXT NOT NULL,
|
||||
sbom_version_id TEXT,
|
||||
sbom_digest TEXT NOT NULL,
|
||||
graph_snapshot_id TEXT,
|
||||
status TEXT NOT NULL CHECK (status IN ('pending', 'running', 'completed', 'failed', 'cancelled')),
|
||||
trigger TEXT NOT NULL CHECK (trigger IN ('manual', 'scheduled', 'on_sbom_change', 'on_feed_update')),
|
||||
priority INT NOT NULL DEFAULT 100,
|
||||
attempts INT NOT NULL DEFAULT 0,
|
||||
max_attempts INT NOT NULL DEFAULT 3,
|
||||
cartographer_job_id TEXT,
|
||||
correlation_id TEXT,
|
||||
metadata JSONB DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
started_at TIMESTAMPTZ,
|
||||
completed_at TIMESTAMPTZ,
|
||||
error TEXT,
|
||||
error_details JSONB
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.policy_jobs (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
policy_pack_id TEXT NOT NULL,
|
||||
policy_version INT,
|
||||
target_type TEXT NOT NULL CHECK (target_type IN ('image', 'sbom', 'project', 'artifact')),
|
||||
target_id TEXT NOT NULL,
|
||||
status TEXT NOT NULL CHECK (status IN ('pending', 'running', 'completed', 'failed')),
|
||||
priority INT NOT NULL DEFAULT 100,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
started_at TIMESTAMPTZ,
|
||||
completed_at TIMESTAMPTZ,
|
||||
result JSONB DEFAULT '{}',
|
||||
error TEXT
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.impact_snapshots (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
run_id UUID NOT NULL REFERENCES scheduler.runs(id),
|
||||
image_digest TEXT NOT NULL,
|
||||
image_reference TEXT,
|
||||
new_findings INT NOT NULL DEFAULT 0,
|
||||
new_criticals INT NOT NULL DEFAULT 0,
|
||||
new_high INT NOT NULL DEFAULT 0,
|
||||
new_medium INT NOT NULL DEFAULT 0,
|
||||
new_low INT NOT NULL DEFAULT 0,
|
||||
total_findings INT NOT NULL DEFAULT 0,
|
||||
kev_hits TEXT[] DEFAULT '{}',
|
||||
top_findings JSONB DEFAULT '[]',
|
||||
report_url TEXT,
|
||||
attestation JSONB DEFAULT '{}',
|
||||
detected_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.workers (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
node_id TEXT NOT NULL UNIQUE,
|
||||
hostname TEXT,
|
||||
capabilities TEXT[] DEFAULT '{}',
|
||||
max_concurrent_jobs INT NOT NULL DEFAULT 1,
|
||||
current_jobs INT NOT NULL DEFAULT 0,
|
||||
version TEXT,
|
||||
last_heartbeat_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
registered_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'draining', 'paused', 'dead'))
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.execution_logs (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
run_id UUID NOT NULL REFERENCES scheduler.runs(id) ON DELETE CASCADE,
|
||||
logged_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
level TEXT NOT NULL CHECK (level IN ('trace', 'debug', 'info', 'warn', 'error', 'fatal')),
|
||||
message TEXT NOT NULL,
|
||||
logger TEXT,
|
||||
data JSONB DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.locks (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
lock_key TEXT NOT NULL UNIQUE,
|
||||
lock_type TEXT NOT NULL DEFAULT 'exclusive' CHECK (lock_type IN ('exclusive', 'shared')),
|
||||
holder_id TEXT NOT NULL,
|
||||
holder_info JSONB DEFAULT '{}',
|
||||
acquired_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
expires_at TIMESTAMPTZ NOT NULL,
|
||||
renewed_at TIMESTAMPTZ
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.run_summaries (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
schedule_id UUID REFERENCES scheduler.schedules(id),
|
||||
period_start TIMESTAMPTZ NOT NULL,
|
||||
period_end TIMESTAMPTZ NOT NULL,
|
||||
total_runs INT NOT NULL DEFAULT 0,
|
||||
successful_runs INT NOT NULL DEFAULT 0,
|
||||
failed_runs INT NOT NULL DEFAULT 0,
|
||||
cancelled_runs INT NOT NULL DEFAULT 0,
|
||||
avg_duration_seconds NUMERIC(10,2),
|
||||
max_duration_seconds INT,
|
||||
min_duration_seconds INT,
|
||||
total_findings_detected INT NOT NULL DEFAULT 0,
|
||||
new_criticals INT NOT NULL DEFAULT 0,
|
||||
computed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE (tenant_id, schedule_id, period_start)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.audit (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
action TEXT NOT NULL,
|
||||
entity_type TEXT NOT NULL,
|
||||
entity_id UUID NOT NULL,
|
||||
actor TEXT,
|
||||
actor_type TEXT CHECK (actor_type IN ('user', 'service', 'system')),
|
||||
old_value JSONB,
|
||||
new_value JSONB,
|
||||
details JSONB DEFAULT '{}',
|
||||
ip_address INET,
|
||||
occurred_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_schedules_tenant ON scheduler.schedules(tenant_id) WHERE deleted_at IS NULL;
|
||||
CREATE INDEX IF NOT EXISTS idx_schedules_enabled ON scheduler.schedules(tenant_id, enabled) WHERE deleted_at IS NULL;
|
||||
CREATE INDEX IF NOT EXISTS idx_triggers_schedule ON scheduler.triggers(schedule_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_triggers_next_fire ON scheduler.triggers(next_fire_time) WHERE enabled = TRUE;
|
||||
CREATE INDEX IF NOT EXISTS idx_runs_tenant_state ON scheduler.runs(tenant_id, state);
|
||||
CREATE INDEX IF NOT EXISTS idx_runs_schedule ON scheduler.runs(schedule_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_runs_created ON scheduler.runs(created_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_runs_state_created ON scheduler.runs(state, created_at) WHERE state IN ('pending', 'queued', 'running');
|
||||
CREATE INDEX IF NOT EXISTS idx_graph_jobs_tenant_status ON scheduler.graph_jobs(tenant_id, status);
|
||||
CREATE INDEX IF NOT EXISTS idx_graph_jobs_sbom ON scheduler.graph_jobs(sbom_digest);
|
||||
CREATE INDEX IF NOT EXISTS idx_policy_jobs_tenant_status ON scheduler.policy_jobs(tenant_id, status);
|
||||
CREATE INDEX IF NOT EXISTS idx_impact_snapshots_run ON scheduler.impact_snapshots(run_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_impact_snapshots_tenant ON scheduler.impact_snapshots(tenant_id, detected_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_workers_status ON scheduler.workers(status);
|
||||
CREATE INDEX IF NOT EXISTS idx_workers_heartbeat ON scheduler.workers(last_heartbeat_at);
|
||||
CREATE INDEX IF NOT EXISTS idx_execution_logs_run ON scheduler.execution_logs(run_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_locks_expires ON scheduler.locks(expires_at);
|
||||
CREATE INDEX IF NOT EXISTS idx_run_summaries_tenant ON scheduler.run_summaries(tenant_id, period_start DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_audit_tenant_time ON scheduler.audit(tenant_id, occurred_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_audit_entity ON scheduler.audit(entity_type, entity_id);
|
||||
245
docs/db/schemas/vex.sql
Normal file
245
docs/db/schemas/vex.sql
Normal file
@@ -0,0 +1,245 @@
|
||||
-- Generated from docs/db/SPECIFICATION.md §5.3 (2025-11-28)
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS vex;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.projects (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
key TEXT NOT NULL,
|
||||
display_name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
settings JSONB DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE (tenant_id, key)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.graph_revisions (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
project_id UUID NOT NULL REFERENCES vex.projects(id),
|
||||
revision_id TEXT NOT NULL UNIQUE,
|
||||
parent_revision_id TEXT,
|
||||
sbom_hash TEXT NOT NULL,
|
||||
sbom_format TEXT NOT NULL CHECK (sbom_format IN ('cyclonedx', 'spdx', 'syft', 'other')),
|
||||
sbom_location TEXT,
|
||||
feed_snapshot_id UUID,
|
||||
lattice_policy_version TEXT,
|
||||
unknowns_snapshot_id UUID,
|
||||
node_count INT NOT NULL DEFAULT 0,
|
||||
edge_count INT NOT NULL DEFAULT 0,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
created_by TEXT,
|
||||
notes TEXT
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.graph_nodes (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
graph_revision_id UUID NOT NULL REFERENCES vex.graph_revisions(id) ON DELETE CASCADE,
|
||||
node_key TEXT NOT NULL,
|
||||
node_type TEXT NOT NULL CHECK (node_type IN ('component', 'vulnerability', 'runtime_entity', 'file', 'package', 'service')),
|
||||
purl TEXT,
|
||||
name TEXT,
|
||||
version TEXT,
|
||||
attributes JSONB DEFAULT '{}',
|
||||
UNIQUE (graph_revision_id, node_key)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.graph_edges (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
graph_revision_id UUID NOT NULL REFERENCES vex.graph_revisions(id) ON DELETE CASCADE,
|
||||
from_node_id BIGINT NOT NULL REFERENCES vex.graph_nodes(id) ON DELETE CASCADE,
|
||||
to_node_id BIGINT NOT NULL REFERENCES vex.graph_nodes(id) ON DELETE CASCADE,
|
||||
edge_type TEXT NOT NULL CHECK (edge_type IN (
|
||||
'depends_on', 'dev_depends_on', 'optional_depends_on',
|
||||
'contains', 'introduces', 'mitigates', 'affects',
|
||||
'build_tool', 'test_dependency'
|
||||
)),
|
||||
attributes JSONB DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.statements (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
project_id UUID REFERENCES vex.projects(id),
|
||||
graph_revision_id UUID REFERENCES vex.graph_revisions(id),
|
||||
advisory_id UUID,
|
||||
vulnerability_id TEXT NOT NULL,
|
||||
subject_node_id BIGINT REFERENCES vex.graph_nodes(id),
|
||||
product_key TEXT,
|
||||
status TEXT NOT NULL CHECK (status IN ('affected', 'not_affected', 'under_investigation', 'fixed')),
|
||||
status_justification TEXT CHECK (status_justification IN (
|
||||
'component_not_present', 'vulnerable_code_not_present',
|
||||
'vulnerable_code_not_in_execute_path', 'vulnerable_code_cannot_be_controlled_by_adversary',
|
||||
'inline_mitigations_already_exist', NULL
|
||||
)),
|
||||
impact_statement TEXT,
|
||||
action_statement TEXT,
|
||||
action_statement_timestamp TIMESTAMPTZ,
|
||||
evidence JSONB DEFAULT '{}',
|
||||
provenance JSONB DEFAULT '{}',
|
||||
evaluated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
evaluated_by TEXT,
|
||||
superseded_by UUID REFERENCES vex.statements(id),
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.observations (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
provider_id TEXT NOT NULL,
|
||||
vulnerability_id TEXT NOT NULL,
|
||||
product_key TEXT NOT NULL,
|
||||
status TEXT NOT NULL CHECK (status IN ('affected', 'not_affected', 'under_investigation', 'fixed')),
|
||||
status_justification TEXT,
|
||||
content_hash TEXT NOT NULL,
|
||||
linkset_id UUID,
|
||||
dsse_envelope_hash TEXT,
|
||||
provenance JSONB DEFAULT '{}',
|
||||
observed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
expires_at TIMESTAMPTZ,
|
||||
UNIQUE (tenant_id, provider_id, vulnerability_id, product_key, content_hash)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.linksets (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
linkset_id TEXT NOT NULL,
|
||||
provider_id TEXT NOT NULL,
|
||||
sbom_digest TEXT,
|
||||
vex_digest TEXT,
|
||||
sbom_location TEXT,
|
||||
vex_location TEXT,
|
||||
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'superseded', 'revoked')),
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
metadata JSONB DEFAULT '{}',
|
||||
UNIQUE (tenant_id, linkset_id)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.linkset_events (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
linkset_id UUID NOT NULL REFERENCES vex.linksets(id),
|
||||
event_type TEXT NOT NULL CHECK (event_type IN ('created', 'updated', 'superseded', 'revoked')),
|
||||
details JSONB DEFAULT '{}',
|
||||
occurred_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.consensus (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
vulnerability_id TEXT NOT NULL,
|
||||
product_key TEXT NOT NULL,
|
||||
computed_status TEXT NOT NULL CHECK (computed_status IN ('affected', 'not_affected', 'under_investigation', 'fixed', 'conflict')),
|
||||
confidence_score NUMERIC(3,2) CHECK (confidence_score >= 0 AND confidence_score <= 1),
|
||||
contributing_observations UUID[] DEFAULT '{}',
|
||||
conflict_details JSONB,
|
||||
computed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE (tenant_id, vulnerability_id, product_key)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.consensus_holds (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
consensus_id UUID NOT NULL REFERENCES vex.consensus(id),
|
||||
hold_type TEXT NOT NULL CHECK (hold_type IN ('manual_review', 'conflict_resolution', 'policy_override')),
|
||||
reason TEXT NOT NULL,
|
||||
placed_by TEXT NOT NULL,
|
||||
placed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
released_at TIMESTAMPTZ,
|
||||
released_by TEXT
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.unknowns_snapshots (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
project_id UUID NOT NULL REFERENCES vex.projects(id),
|
||||
graph_revision_id UUID REFERENCES vex.graph_revisions(id),
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
created_by TEXT,
|
||||
rationale TEXT,
|
||||
item_count INT NOT NULL DEFAULT 0
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.unknown_items (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
snapshot_id UUID NOT NULL REFERENCES vex.unknowns_snapshots(id) ON DELETE CASCADE,
|
||||
item_key TEXT NOT NULL,
|
||||
item_type TEXT NOT NULL CHECK (item_type IN (
|
||||
'missing_sbom', 'ambiguous_package', 'missing_feed',
|
||||
'unresolved_edge', 'no_version_info', 'unknown_ecosystem'
|
||||
)),
|
||||
severity TEXT CHECK (severity IN ('critical', 'high', 'medium', 'low', 'info')),
|
||||
details JSONB DEFAULT '{}',
|
||||
resolved_at TIMESTAMPTZ,
|
||||
resolution TEXT
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.evidence_manifests (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
manifest_id TEXT NOT NULL UNIQUE,
|
||||
merkle_root TEXT NOT NULL,
|
||||
signature TEXT,
|
||||
signer_id TEXT,
|
||||
sealed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
item_count INT NOT NULL DEFAULT 0,
|
||||
items JSONB NOT NULL DEFAULT '[]',
|
||||
metadata JSONB DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.cvss_receipts (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
statement_id UUID NOT NULL REFERENCES vex.statements(id),
|
||||
cvss_metric_id UUID,
|
||||
cvss_version TEXT NOT NULL,
|
||||
vector TEXT NOT NULL,
|
||||
score_used NUMERIC(3,1) NOT NULL,
|
||||
context JSONB DEFAULT '{}',
|
||||
scored_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.attestations (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
statement_id UUID REFERENCES vex.statements(id),
|
||||
graph_revision_id UUID REFERENCES vex.graph_revisions(id),
|
||||
attestation_type TEXT NOT NULL CHECK (attestation_type IN ('in-toto', 'dsse', 'sigstore')),
|
||||
envelope_hash TEXT NOT NULL,
|
||||
rekor_log_id TEXT,
|
||||
rekor_log_index BIGINT,
|
||||
signer_id TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
metadata JSONB DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vex.timeline_events (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
project_id UUID REFERENCES vex.projects(id),
|
||||
event_type TEXT NOT NULL,
|
||||
entity_type TEXT NOT NULL,
|
||||
entity_id UUID NOT NULL,
|
||||
actor TEXT,
|
||||
details JSONB DEFAULT '{}',
|
||||
occurred_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_projects_tenant ON vex.projects(tenant_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_graph_revisions_project ON vex.graph_revisions(project_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_graph_revisions_sbom ON vex.graph_revisions(sbom_hash);
|
||||
CREATE INDEX IF NOT EXISTS idx_graph_nodes_revision ON vex.graph_nodes(graph_revision_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_graph_nodes_purl ON vex.graph_nodes(purl) WHERE purl IS NOT NULL;
|
||||
CREATE INDEX IF NOT EXISTS idx_graph_edges_revision ON vex.graph_edges(graph_revision_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_graph_edges_from ON vex.graph_edges(from_node_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_graph_edges_to ON vex.graph_edges(to_node_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_statements_tenant_vuln ON vex.statements(tenant_id, vulnerability_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_statements_project ON vex.statements(project_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_statements_graph ON vex.statements(graph_revision_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_observations_tenant_vuln ON vex.observations(tenant_id, vulnerability_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_observations_provider ON vex.observations(provider_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_linksets_tenant ON vex.linksets(tenant_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_consensus_tenant_vuln ON vex.consensus(tenant_id, vulnerability_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_unknowns_project ON vex.unknowns_snapshots(project_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_attestations_tenant ON vex.attestations(tenant_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_attestations_rekor ON vex.attestations(rekor_log_id) WHERE rekor_log_id IS NOT NULL;
|
||||
CREATE INDEX IF NOT EXISTS idx_timeline_tenant_time ON vex.timeline_events(tenant_id, occurred_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_timeline_entity ON vex.timeline_events(entity_type, entity_id);
|
||||
183
docs/db/schemas/vuln.sql
Normal file
183
docs/db/schemas/vuln.sql
Normal file
@@ -0,0 +1,183 @@
|
||||
-- Generated from docs/db/SPECIFICATION.md §5.2 (2025-11-28)
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS vuln;
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.sources (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
key TEXT NOT NULL UNIQUE,
|
||||
display_name TEXT NOT NULL,
|
||||
url TEXT,
|
||||
source_type TEXT NOT NULL CHECK (source_type IN ('nvd', 'osv', 'ghsa', 'vendor', 'oval', 'custom')),
|
||||
enabled BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
priority INT NOT NULL DEFAULT 100,
|
||||
config JSONB DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.feed_snapshots (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
source_id UUID NOT NULL REFERENCES vuln.sources(id),
|
||||
snapshot_id TEXT NOT NULL,
|
||||
taken_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
completed_at TIMESTAMPTZ,
|
||||
status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'processing', 'completed', 'failed')),
|
||||
stats JSONB DEFAULT '{}',
|
||||
checksum TEXT,
|
||||
error TEXT,
|
||||
UNIQUE (source_id, snapshot_id)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_snapshots (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
source_id UUID NOT NULL REFERENCES vuln.sources(id),
|
||||
source_advisory_id TEXT NOT NULL,
|
||||
feed_snapshot_id UUID REFERENCES vuln.feed_snapshots(id),
|
||||
imported_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
raw_payload JSONB NOT NULL,
|
||||
payload_hash TEXT NOT NULL,
|
||||
is_latest BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
UNIQUE (source_id, source_advisory_id, payload_hash)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisories (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_key TEXT NOT NULL UNIQUE,
|
||||
primary_vuln_id TEXT NOT NULL,
|
||||
source_id UUID REFERENCES vuln.sources(id),
|
||||
title TEXT,
|
||||
summary TEXT,
|
||||
description TEXT,
|
||||
language TEXT DEFAULT 'en',
|
||||
severity TEXT CHECK (severity IN ('critical', 'high', 'medium', 'low', 'none', 'unknown')),
|
||||
exploit_known BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
state TEXT NOT NULL DEFAULT 'active' CHECK (state IN ('active', 'rejected', 'withdrawn', 'disputed')),
|
||||
published_at TIMESTAMPTZ,
|
||||
modified_at TIMESTAMPTZ,
|
||||
withdrawn_at TIMESTAMPTZ,
|
||||
current_snapshot_id UUID REFERENCES vuln.advisory_snapshots(id),
|
||||
canonical_metric_id UUID,
|
||||
provenance JSONB DEFAULT '[]',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_aliases (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
alias_type TEXT NOT NULL CHECK (alias_type IN ('cve', 'ghsa', 'osv', 'vendor', 'internal', 'other')),
|
||||
alias_value TEXT NOT NULL,
|
||||
provenance JSONB DEFAULT '{}',
|
||||
UNIQUE (alias_type, alias_value)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_cvss (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
version TEXT NOT NULL CHECK (version IN ('2.0', '3.0', '3.1', '4.0')),
|
||||
vector TEXT NOT NULL,
|
||||
base_score NUMERIC(3,1) NOT NULL CHECK (base_score >= 0 AND base_score <= 10),
|
||||
base_severity TEXT,
|
||||
temporal_score NUMERIC(3,1) CHECK (temporal_score >= 0 AND temporal_score <= 10),
|
||||
environmental_score NUMERIC(3,1) CHECK (environmental_score >= 0 AND environmental_score <= 10),
|
||||
source TEXT,
|
||||
is_primary BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
provenance JSONB DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_affected (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
package_type TEXT NOT NULL CHECK (package_type IN ('rpm', 'deb', 'cpe', 'semver', 'vendor', 'ics-vendor', 'generic')),
|
||||
ecosystem TEXT,
|
||||
package_name TEXT NOT NULL,
|
||||
package_purl TEXT,
|
||||
platform TEXT,
|
||||
version_ranges JSONB NOT NULL DEFAULT '[]',
|
||||
statuses JSONB DEFAULT '[]',
|
||||
normalized_versions JSONB DEFAULT '[]',
|
||||
provenance JSONB DEFAULT '[]'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_references (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
url TEXT NOT NULL,
|
||||
title TEXT,
|
||||
ref_type TEXT,
|
||||
provenance JSONB DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_credits (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
name TEXT NOT NULL,
|
||||
contact TEXT,
|
||||
credit_type TEXT,
|
||||
provenance JSONB DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_weaknesses (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
cwe_id TEXT NOT NULL,
|
||||
description TEXT,
|
||||
provenance JSONB DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.kev_flags (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
cve_id TEXT NOT NULL UNIQUE,
|
||||
advisory_id UUID REFERENCES vuln.advisories(id),
|
||||
added_date DATE NOT NULL,
|
||||
due_date DATE,
|
||||
vendor_project TEXT,
|
||||
product TEXT,
|
||||
vulnerability_name TEXT,
|
||||
short_description TEXT,
|
||||
required_action TEXT,
|
||||
notes TEXT,
|
||||
known_ransomware_campaign BOOLEAN DEFAULT FALSE,
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.source_states (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
source_id UUID NOT NULL REFERENCES vuln.sources(id) UNIQUE,
|
||||
cursor TEXT,
|
||||
last_fetch_at TIMESTAMPTZ,
|
||||
last_success_at TIMESTAMPTZ,
|
||||
consecutive_failures INT DEFAULT 0,
|
||||
last_error TEXT,
|
||||
last_error_at TIMESTAMPTZ,
|
||||
metadata JSONB DEFAULT '{}'
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS vuln.merge_events (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id),
|
||||
event_type TEXT NOT NULL CHECK (event_type IN ('created', 'updated', 'merged', 'superseded', 'withdrawn')),
|
||||
source_id UUID REFERENCES vuln.sources(id),
|
||||
changes JSONB DEFAULT '{}',
|
||||
occurred_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_advisories_primary_vuln ON vuln.advisories(primary_vuln_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_advisories_modified ON vuln.advisories(modified_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_advisories_published ON vuln.advisories(published_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_advisories_severity ON vuln.advisories(severity) WHERE state = 'active';
|
||||
CREATE INDEX IF NOT EXISTS idx_advisories_state ON vuln.advisories(state);
|
||||
CREATE INDEX IF NOT EXISTS idx_advisory_aliases_value ON vuln.advisory_aliases(alias_value);
|
||||
CREATE INDEX IF NOT EXISTS idx_advisory_aliases_advisory ON vuln.advisory_aliases(advisory_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_advisory_affected_purl ON vuln.advisory_affected(package_purl) WHERE package_purl IS NOT NULL;
|
||||
CREATE INDEX IF NOT EXISTS idx_advisory_affected_name ON vuln.advisory_affected(ecosystem, package_name);
|
||||
CREATE INDEX IF NOT EXISTS idx_advisory_affected_advisory ON vuln.advisory_affected(advisory_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_advisory_snapshots_latest ON vuln.advisory_snapshots(source_id, source_advisory_id) WHERE is_latest = TRUE;
|
||||
CREATE INDEX IF NOT EXISTS idx_kev_flags_cve ON vuln.kev_flags(cve_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_merge_events_advisory ON vuln.merge_events(advisory_id, occurred_at DESC);
|
||||
|
||||
-- Full-text search
|
||||
CREATE INDEX IF NOT EXISTS idx_advisories_fts ON vuln.advisories USING GIN (
|
||||
to_tsvector('english', COALESCE(title, '') || ' ' || COALESCE(summary, '') || ' ' || COALESCE(description, ''))
|
||||
);
|
||||
Reference in New Issue
Block a user