Files
git.stella-ops.org/docs/db/schemas/scanner.sql
master 4391f35d8a Refactor SurfaceCacheValidator to simplify oldest entry calculation
Add global using for Xunit in test project

Enhance ImportValidatorTests with async validation and quarantine checks

Implement FileSystemQuarantineServiceTests for quarantine functionality

Add integration tests for ImportValidator to check monotonicity

Create BundleVersionTests to validate version parsing and comparison logic

Implement VersionMonotonicityCheckerTests for monotonicity checks and activation logic
2025-12-16 10:44:00 +02:00

176 lines
7.0 KiB
PL/PgSQL

-- =============================================================================
-- SCANNER SCHEMA - ProofSpine Audit Trail Tables
-- Version: V3100_001
-- Sprint: SPRINT_3100_0001_0001
-- =============================================================================
CREATE SCHEMA IF NOT EXISTS scanner;
-- =============================================================================
-- PROOF SPINES
-- =============================================================================
-- Main proof spine table - represents a complete verifiable decision chain
-- from SBOM through vulnerability matching to final VEX verdict
CREATE TABLE scanner.proof_spines (
spine_id TEXT PRIMARY KEY,
artifact_id TEXT NOT NULL,
vuln_id TEXT NOT NULL,
policy_profile_id TEXT NOT NULL,
verdict TEXT NOT NULL CHECK (verdict IN (
'not_affected', 'affected', 'fixed', 'under_investigation'
)),
verdict_reason TEXT,
root_hash TEXT NOT NULL,
scan_run_id TEXT NOT NULL,
segment_count INT NOT NULL DEFAULT 0,
created_at_utc TIMESTAMPTZ NOT NULL DEFAULT NOW(),
superseded_by_spine_id TEXT REFERENCES scanner.proof_spines(spine_id),
-- Deterministic spine ID = hash(artifact_id + vuln_id + policy_profile_id + root_hash)
CONSTRAINT proof_spines_unique_decision UNIQUE (artifact_id, vuln_id, policy_profile_id, root_hash)
);
-- Composite index for common lookups
CREATE INDEX idx_proof_spines_lookup
ON scanner.proof_spines(artifact_id, vuln_id, policy_profile_id);
CREATE INDEX idx_proof_spines_scan_run
ON scanner.proof_spines(scan_run_id);
CREATE INDEX idx_proof_spines_created
ON scanner.proof_spines(created_at_utc DESC);
CREATE INDEX idx_proof_spines_verdict
ON scanner.proof_spines(verdict);
-- =============================================================================
-- PROOF SEGMENTS
-- =============================================================================
-- Individual segments within a spine - each segment is DSSE-signed
CREATE TABLE scanner.proof_segments (
segment_id TEXT PRIMARY KEY,
spine_id TEXT NOT NULL REFERENCES scanner.proof_spines(spine_id) ON DELETE CASCADE,
idx INT NOT NULL,
segment_type TEXT NOT NULL CHECK (segment_type IN (
'SbomSlice', 'Match', 'Reachability',
'GuardAnalysis', 'RuntimeObservation', 'PolicyEval'
)),
input_hash TEXT NOT NULL,
result_hash TEXT NOT NULL,
prev_segment_hash TEXT,
envelope_json TEXT NOT NULL, -- DSSE envelope as JSON
tool_id TEXT NOT NULL,
tool_version TEXT NOT NULL,
status TEXT NOT NULL DEFAULT 'Pending' CHECK (status IN (
'Pending', 'Verified', 'Partial', 'Invalid', 'Untrusted'
)),
created_at_utc TIMESTAMPTZ NOT NULL DEFAULT NOW(),
CONSTRAINT proof_segments_unique_idx UNIQUE (spine_id, idx)
);
CREATE INDEX idx_proof_segments_spine ON scanner.proof_segments(spine_id);
CREATE INDEX idx_proof_segments_type ON scanner.proof_segments(segment_type);
CREATE INDEX idx_proof_segments_status ON scanner.proof_segments(status);
-- =============================================================================
-- PROOF SPINE HISTORY
-- =============================================================================
-- Audit trail for spine lifecycle events (creation, supersession, verification)
CREATE TABLE scanner.proof_spine_history (
history_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
spine_id TEXT NOT NULL REFERENCES scanner.proof_spines(spine_id),
action TEXT NOT NULL CHECK (action IN (
'created', 'superseded', 'verified', 'invalidated'
)),
actor TEXT,
reason TEXT,
occurred_at_utc TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX idx_proof_spine_history_spine ON scanner.proof_spine_history(spine_id);
CREATE INDEX idx_proof_spine_history_action ON scanner.proof_spine_history(action);
CREATE INDEX idx_proof_spine_history_occurred ON scanner.proof_spine_history(occurred_at_utc DESC);
-- =============================================================================
-- VERIFICATION CACHE
-- =============================================================================
-- Caches verification results to avoid re-verifying unchanged spines
CREATE TABLE scanner.proof_spine_verification_cache (
spine_id TEXT PRIMARY KEY REFERENCES scanner.proof_spines(spine_id) ON DELETE CASCADE,
verified_at_utc TIMESTAMPTZ NOT NULL DEFAULT NOW(),
verifier_version TEXT NOT NULL,
all_segments_valid BOOLEAN NOT NULL,
invalid_segment_ids TEXT[],
signature_algorithm TEXT NOT NULL,
key_fingerprint TEXT NOT NULL
);
CREATE INDEX idx_verification_cache_verified ON scanner.proof_spine_verification_cache(verified_at_utc DESC);
-- =============================================================================
-- FUNCTIONS
-- =============================================================================
-- Function to update segment count after segment insert
CREATE OR REPLACE FUNCTION scanner.update_spine_segment_count()
RETURNS TRIGGER AS $$
BEGIN
UPDATE scanner.proof_spines
SET segment_count = (
SELECT COUNT(*) FROM scanner.proof_segments WHERE spine_id = NEW.spine_id
)
WHERE spine_id = NEW.spine_id;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Trigger to maintain segment count
CREATE TRIGGER trg_update_segment_count
AFTER INSERT OR DELETE ON scanner.proof_segments
FOR EACH ROW EXECUTE FUNCTION scanner.update_spine_segment_count();
-- Function to record history on spine events
CREATE OR REPLACE FUNCTION scanner.record_spine_history()
RETURNS TRIGGER AS $$
BEGIN
IF TG_OP = 'INSERT' THEN
INSERT INTO scanner.proof_spine_history (spine_id, action, reason)
VALUES (NEW.spine_id, 'created', 'Spine created');
ELSIF TG_OP = 'UPDATE' AND NEW.superseded_by_spine_id IS NOT NULL
AND OLD.superseded_by_spine_id IS NULL THEN
INSERT INTO scanner.proof_spine_history (spine_id, action, reason)
VALUES (OLD.spine_id, 'superseded', 'Superseded by ' || NEW.superseded_by_spine_id);
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Trigger to record spine history
CREATE TRIGGER trg_record_spine_history
AFTER INSERT OR UPDATE ON scanner.proof_spines
FOR EACH ROW EXECUTE FUNCTION scanner.record_spine_history();
-- =============================================================================
-- COMMENTS
-- =============================================================================
COMMENT ON TABLE scanner.proof_spines IS
'Verifiable decision chains from SBOM to VEX verdict with cryptographic integrity';
COMMENT ON TABLE scanner.proof_segments IS
'Individual DSSE-signed evidence segments within a proof spine';
COMMENT ON TABLE scanner.proof_spine_history IS
'Audit trail for spine lifecycle events';
COMMENT ON COLUMN scanner.proof_spines.root_hash IS
'SHA256 hash of concatenated segment result hashes for tamper detection';
COMMENT ON COLUMN scanner.proof_segments.prev_segment_hash IS
'Hash chain linking - NULL for first segment, result_hash of previous segment otherwise';
COMMENT ON COLUMN scanner.proof_segments.envelope_json IS
'DSSE envelope containing signed segment payload';