-- 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);