Files
git.stella-ops.org/docs/db/triage_schema.sql

250 lines
9.7 KiB
PL/PgSQL

-- Stella Ops Triage Schema (PostgreSQL)
-- System of record: PostgreSQL
-- Ephemeral acceleration: Valkey (not represented here)
BEGIN;
-- Extensions
CREATE EXTENSION IF NOT EXISTS pgcrypto;
-- Enums
DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'triage_lane') THEN
CREATE TYPE triage_lane AS ENUM (
'ACTIVE',
'BLOCKED',
'NEEDS_EXCEPTION',
'MUTED_REACH',
'MUTED_VEX',
'COMPENSATED'
);
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'triage_verdict') THEN
CREATE TYPE triage_verdict AS ENUM ('SHIP', 'BLOCK', 'EXCEPTION');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'triage_reachability') THEN
CREATE TYPE triage_reachability AS ENUM ('YES', 'NO', 'UNKNOWN');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'triage_vex_status') THEN
CREATE TYPE triage_vex_status AS ENUM ('affected', 'not_affected', 'under_investigation', 'unknown');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'triage_decision_kind') THEN
CREATE TYPE triage_decision_kind AS ENUM ('MUTE_REACH', 'MUTE_VEX', 'ACK', 'EXCEPTION');
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'triage_snapshot_trigger') THEN
CREATE TYPE triage_snapshot_trigger AS ENUM (
'FEED_UPDATE',
'VEX_UPDATE',
'SBOM_UPDATE',
'RUNTIME_TRACE',
'POLICY_UPDATE',
'DECISION',
'RESCAN'
);
END IF;
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'triage_evidence_type') THEN
CREATE TYPE triage_evidence_type AS ENUM (
'SBOM_SLICE',
'VEX_DOC',
'PROVENANCE',
'CALLSTACK_SLICE',
'REACHABILITY_PROOF',
'REPLAY_MANIFEST',
'POLICY',
'SCAN_LOG',
'OTHER'
);
END IF;
END $$;
-- Core: finding (caseId == findingId)
CREATE TABLE IF NOT EXISTS triage_finding (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
asset_id uuid NOT NULL,
environment_id uuid NULL,
asset_label text NOT NULL, -- e.g. "prod/api-gateway:1.2.3"
purl text NOT NULL, -- package-url
cve_id text NULL,
rule_id text NULL,
first_seen_at timestamptz NOT NULL DEFAULT now(),
last_seen_at timestamptz NOT NULL DEFAULT now(),
UNIQUE (asset_id, environment_id, purl, cve_id, rule_id)
);
CREATE INDEX IF NOT EXISTS ix_triage_finding_last_seen ON triage_finding (last_seen_at DESC);
CREATE INDEX IF NOT EXISTS ix_triage_finding_asset_label ON triage_finding (asset_label);
CREATE INDEX IF NOT EXISTS ix_triage_finding_purl ON triage_finding (purl);
CREATE INDEX IF NOT EXISTS ix_triage_finding_cve ON triage_finding (cve_id);
-- Effective VEX (post-merge), with preserved provenance pointers
CREATE TABLE IF NOT EXISTS triage_effective_vex (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
finding_id uuid NOT NULL REFERENCES triage_finding(id) ON DELETE CASCADE,
status triage_vex_status NOT NULL,
source_domain text NOT NULL, -- "excititor"
source_ref text NOT NULL, -- stable ref string (preserve prune source)
pruned_sources jsonb NULL, -- array of pruned items with reasons (optional)
dsse_envelope_hash text NULL,
signature_ref text NULL, -- rekor/ledger ref
issuer text NULL,
valid_from timestamptz NOT NULL DEFAULT now(),
valid_to timestamptz NULL,
collected_at timestamptz NOT NULL DEFAULT now()
);
CREATE INDEX IF NOT EXISTS ix_triage_effective_vex_finding ON triage_effective_vex (finding_id, collected_at DESC);
-- Reachability results
CREATE TABLE IF NOT EXISTS triage_reachability_result (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
finding_id uuid NOT NULL REFERENCES triage_finding(id) ON DELETE CASCADE,
reachable triage_reachability NOT NULL,
confidence smallint NOT NULL CHECK (confidence >= 0 AND confidence <= 100),
static_proof_ref text NULL, -- evidence ref (callgraph slice / CFG slice)
runtime_proof_ref text NULL, -- evidence ref (runtime hits)
inputs_hash text NOT NULL, -- hash of inputs used to compute reachability
computed_at timestamptz NOT NULL DEFAULT now()
);
CREATE INDEX IF NOT EXISTS ix_triage_reachability_finding ON triage_reachability_result (finding_id, computed_at DESC);
-- Risk/lattice result (scanner.webservice output)
CREATE TABLE IF NOT EXISTS triage_risk_result (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
finding_id uuid NOT NULL REFERENCES triage_finding(id) ON DELETE CASCADE,
policy_id text NOT NULL,
policy_version text NOT NULL,
inputs_hash text NOT NULL,
score int NOT NULL CHECK (score >= 0 AND score <= 100),
verdict triage_verdict NOT NULL,
lane triage_lane NOT NULL,
why text NOT NULL, -- short narrative
explanation jsonb NULL, -- structured lattice explanation for UI diffing
computed_at timestamptz NOT NULL DEFAULT now(),
UNIQUE (finding_id, policy_id, policy_version, inputs_hash)
);
CREATE INDEX IF NOT EXISTS ix_triage_risk_finding ON triage_risk_result (finding_id, computed_at DESC);
CREATE INDEX IF NOT EXISTS ix_triage_risk_lane ON triage_risk_result (lane, computed_at DESC);
-- Signed Decisions (mute/ack/exception), reversible by revoke
CREATE TABLE IF NOT EXISTS triage_decision (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
finding_id uuid NOT NULL REFERENCES triage_finding(id) ON DELETE CASCADE,
kind triage_decision_kind NOT NULL,
reason_code text NOT NULL,
note text NULL,
policy_ref text NULL, -- optional: policy that allowed decision
ttl timestamptz NULL,
actor_subject text NOT NULL, -- Authority subject (sub)
actor_display text NULL,
signature_ref text NULL, -- DSSE signature reference
dsse_hash text NULL,
created_at timestamptz NOT NULL DEFAULT now(),
revoked_at timestamptz NULL,
revoke_reason text NULL,
revoke_signature_ref text NULL,
revoke_dsse_hash text NULL
);
CREATE INDEX IF NOT EXISTS ix_triage_decision_finding ON triage_decision (finding_id, created_at DESC);
CREATE INDEX IF NOT EXISTS ix_triage_decision_kind ON triage_decision (kind, created_at DESC);
CREATE INDEX IF NOT EXISTS ix_triage_decision_active ON triage_decision (finding_id) WHERE revoked_at IS NULL;
-- Evidence artifacts (hash-addressed, signed)
CREATE TABLE IF NOT EXISTS triage_evidence_artifact (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
finding_id uuid NOT NULL REFERENCES triage_finding(id) ON DELETE CASCADE,
type triage_evidence_type NOT NULL,
title text NOT NULL,
issuer text NULL,
signed boolean NOT NULL DEFAULT false,
signed_by text NULL,
content_hash text NOT NULL,
signature_ref text NULL,
media_type text NULL,
uri text NOT NULL, -- object store / file path / inline ref
size_bytes bigint NULL,
metadata jsonb NULL,
created_at timestamptz NOT NULL DEFAULT now(),
UNIQUE (finding_id, type, content_hash)
);
CREATE INDEX IF NOT EXISTS ix_triage_evidence_finding ON triage_evidence_artifact (finding_id, created_at DESC);
CREATE INDEX IF NOT EXISTS ix_triage_evidence_type ON triage_evidence_artifact (type, created_at DESC);
-- Snapshots for Smart-Diff (immutable records of input/output changes)
CREATE TABLE IF NOT EXISTS triage_snapshot (
id uuid PRIMARY KEY DEFAULT gen_random_uuid(),
finding_id uuid NOT NULL REFERENCES triage_finding(id) ON DELETE CASCADE,
trigger triage_snapshot_trigger NOT NULL,
from_inputs_hash text NULL,
to_inputs_hash text NOT NULL,
summary text NOT NULL,
diff_json jsonb NULL, -- optional: precomputed diff
created_at timestamptz NOT NULL DEFAULT now(),
UNIQUE (finding_id, to_inputs_hash, created_at)
);
CREATE INDEX IF NOT EXISTS ix_triage_snapshot_finding ON triage_snapshot (finding_id, created_at DESC);
CREATE INDEX IF NOT EXISTS ix_triage_snapshot_trigger ON triage_snapshot (trigger, created_at DESC);
-- Current-case view: latest risk + latest reachability + latest effective VEX
CREATE OR REPLACE VIEW v_triage_case_current AS
WITH latest_risk AS (
SELECT DISTINCT ON (finding_id)
finding_id, policy_id, policy_version, inputs_hash, score, verdict, lane, why, computed_at
FROM triage_risk_result
ORDER BY finding_id, computed_at DESC
),
latest_reach AS (
SELECT DISTINCT ON (finding_id)
finding_id, reachable, confidence, static_proof_ref, runtime_proof_ref, computed_at
FROM triage_reachability_result
ORDER BY finding_id, computed_at DESC
),
latest_vex AS (
SELECT DISTINCT ON (finding_id)
finding_id, status, issuer, signature_ref, source_domain, source_ref, collected_at
FROM triage_effective_vex
ORDER BY finding_id, collected_at DESC
)
SELECT
f.id AS case_id,
f.asset_id,
f.environment_id,
f.asset_label,
f.purl,
f.cve_id,
f.rule_id,
f.first_seen_at,
f.last_seen_at,
r.policy_id,
r.policy_version,
r.inputs_hash,
r.score,
r.verdict,
r.lane,
r.why,
r.computed_at AS risk_computed_at,
coalesce(re.reachable, 'UNKNOWN'::triage_reachability) AS reachable,
re.confidence AS reach_confidence,
v.status AS vex_status,
v.issuer AS vex_issuer,
v.signature_ref AS vex_signature_ref,
v.source_domain AS vex_source_domain,
v.source_ref AS vex_source_ref
FROM triage_finding f
LEFT JOIN latest_risk r ON r.finding_id = f.id
LEFT JOIN latest_reach re ON re.finding_id = f.id
LEFT JOIN latest_vex v ON v.finding_id = f.id;
COMMIT;