sprints work.
This commit is contained in:
69
devops/database/migrations/005_timestamp_evidence.sql
Normal file
69
devops/database/migrations/005_timestamp_evidence.sql
Normal file
@@ -0,0 +1,69 @@
|
||||
-- -----------------------------------------------------------------------------
|
||||
-- 005_timestamp_evidence.sql
|
||||
-- Sprint: SPRINT_20260119_009 Evidence Storage for Timestamps
|
||||
-- Task: EVT-002 - PostgreSQL Schema Extension
|
||||
-- Description: Schema for storing timestamp and revocation evidence.
|
||||
-- -----------------------------------------------------------------------------
|
||||
|
||||
-- Ensure the evidence schema exists
|
||||
CREATE SCHEMA IF NOT EXISTS evidence;
|
||||
|
||||
-- Timestamp evidence storage
|
||||
CREATE TABLE IF NOT EXISTS evidence.timestamp_tokens (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
artifact_digest TEXT NOT NULL,
|
||||
digest_algorithm TEXT NOT NULL,
|
||||
tst_blob BYTEA NOT NULL,
|
||||
generation_time TIMESTAMPTZ NOT NULL,
|
||||
tsa_name TEXT NOT NULL,
|
||||
tsa_policy_oid TEXT NOT NULL,
|
||||
serial_number TEXT NOT NULL,
|
||||
tsa_chain_pem TEXT NOT NULL,
|
||||
ocsp_response BYTEA,
|
||||
crl_snapshot BYTEA,
|
||||
captured_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
provider_name TEXT NOT NULL,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT uq_timestamp_artifact_time UNIQUE (artifact_digest, generation_time)
|
||||
);
|
||||
|
||||
-- Indexes for timestamp queries
|
||||
CREATE INDEX IF NOT EXISTS idx_timestamp_artifact ON evidence.timestamp_tokens(artifact_digest);
|
||||
CREATE INDEX IF NOT EXISTS idx_timestamp_generation ON evidence.timestamp_tokens(generation_time);
|
||||
CREATE INDEX IF NOT EXISTS idx_timestamp_provider ON evidence.timestamp_tokens(provider_name);
|
||||
CREATE INDEX IF NOT EXISTS idx_timestamp_created ON evidence.timestamp_tokens(created_at);
|
||||
|
||||
-- Revocation evidence storage
|
||||
CREATE TABLE IF NOT EXISTS evidence.revocation_snapshots (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
certificate_fingerprint TEXT NOT NULL,
|
||||
source TEXT NOT NULL CHECK (source IN ('Ocsp', 'Crl', 'None')),
|
||||
raw_response BYTEA NOT NULL,
|
||||
response_time TIMESTAMPTZ NOT NULL,
|
||||
valid_until TIMESTAMPTZ NOT NULL,
|
||||
status TEXT NOT NULL CHECK (status IN ('Good', 'Revoked', 'Unknown')),
|
||||
revocation_time TIMESTAMPTZ,
|
||||
reason TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Indexes for revocation queries
|
||||
CREATE INDEX IF NOT EXISTS idx_revocation_cert ON evidence.revocation_snapshots(certificate_fingerprint);
|
||||
CREATE INDEX IF NOT EXISTS idx_revocation_valid ON evidence.revocation_snapshots(valid_until);
|
||||
CREATE INDEX IF NOT EXISTS idx_revocation_status ON evidence.revocation_snapshots(status);
|
||||
CREATE INDEX IF NOT EXISTS idx_revocation_created ON evidence.revocation_snapshots(created_at);
|
||||
|
||||
-- Comments
|
||||
COMMENT ON TABLE evidence.timestamp_tokens IS 'RFC-3161 TimeStampToken evidence for long-term validation';
|
||||
COMMENT ON TABLE evidence.revocation_snapshots IS 'OCSP/CRL certificate revocation evidence snapshots';
|
||||
|
||||
COMMENT ON COLUMN evidence.timestamp_tokens.artifact_digest IS 'SHA-256 digest of the timestamped artifact';
|
||||
COMMENT ON COLUMN evidence.timestamp_tokens.tst_blob IS 'Raw DER-encoded RFC 3161 TimeStampToken';
|
||||
COMMENT ON COLUMN evidence.timestamp_tokens.tsa_chain_pem IS 'PEM-encoded TSA certificate chain for LTV';
|
||||
COMMENT ON COLUMN evidence.timestamp_tokens.ocsp_response IS 'Stapled OCSP response at signing time';
|
||||
COMMENT ON COLUMN evidence.timestamp_tokens.crl_snapshot IS 'CRL snapshot at signing time (fallback for OCSP)';
|
||||
|
||||
COMMENT ON COLUMN evidence.revocation_snapshots.certificate_fingerprint IS 'SHA-256 fingerprint of the certificate';
|
||||
COMMENT ON COLUMN evidence.revocation_snapshots.raw_response IS 'Raw OCSP response or CRL bytes';
|
||||
COMMENT ON COLUMN evidence.revocation_snapshots.response_time IS 'thisUpdate from the response';
|
||||
COMMENT ON COLUMN evidence.revocation_snapshots.valid_until IS 'nextUpdate from the response';
|
||||
@@ -0,0 +1,21 @@
|
||||
-- -----------------------------------------------------------------------------
|
||||
-- 005_timestamp_evidence_rollback.sql
|
||||
-- Sprint: SPRINT_20260119_009 Evidence Storage for Timestamps
|
||||
-- Task: EVT-002 - PostgreSQL Schema Extension
|
||||
-- Description: Rollback migration for timestamp and revocation evidence.
|
||||
-- -----------------------------------------------------------------------------
|
||||
|
||||
-- Drop indexes first
|
||||
DROP INDEX IF EXISTS evidence.idx_timestamp_artifact;
|
||||
DROP INDEX IF EXISTS evidence.idx_timestamp_generation;
|
||||
DROP INDEX IF EXISTS evidence.idx_timestamp_provider;
|
||||
DROP INDEX IF EXISTS evidence.idx_timestamp_created;
|
||||
|
||||
DROP INDEX IF EXISTS evidence.idx_revocation_cert;
|
||||
DROP INDEX IF EXISTS evidence.idx_revocation_valid;
|
||||
DROP INDEX IF EXISTS evidence.idx_revocation_status;
|
||||
DROP INDEX IF EXISTS evidence.idx_revocation_created;
|
||||
|
||||
-- Drop tables
|
||||
DROP TABLE IF EXISTS evidence.revocation_snapshots;
|
||||
DROP TABLE IF EXISTS evidence.timestamp_tokens;
|
||||
120
devops/database/migrations/005_validation_harness.sql
Normal file
120
devops/database/migrations/005_validation_harness.sql
Normal file
@@ -0,0 +1,120 @@
|
||||
-- Validation harness schema for tracking validation runs and match results
|
||||
-- Migration: 005_validation_harness.sql
|
||||
|
||||
-- Validation runs table
|
||||
CREATE TABLE IF NOT EXISTS groundtruth.validation_runs (
|
||||
run_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
status TEXT NOT NULL DEFAULT 'pending',
|
||||
|
||||
-- Configuration (stored as JSONB)
|
||||
config JSONB NOT NULL,
|
||||
|
||||
-- Timestamps
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT now(),
|
||||
started_at TIMESTAMPTZ,
|
||||
completed_at TIMESTAMPTZ,
|
||||
|
||||
-- Metrics (populated after completion)
|
||||
total_pairs INT,
|
||||
total_functions INT,
|
||||
true_positives INT,
|
||||
false_positives INT,
|
||||
true_negatives INT,
|
||||
false_negatives INT,
|
||||
match_rate DOUBLE PRECISION,
|
||||
precision_score DOUBLE PRECISION,
|
||||
recall_score DOUBLE PRECISION,
|
||||
f1_score DOUBLE PRECISION,
|
||||
average_match_score DOUBLE PRECISION,
|
||||
|
||||
-- Mismatch counts by bucket (JSONB map)
|
||||
mismatch_counts JSONB,
|
||||
|
||||
-- Metadata
|
||||
corpus_snapshot_id TEXT,
|
||||
matcher_version TEXT,
|
||||
error_message TEXT,
|
||||
tags TEXT[] DEFAULT '{}',
|
||||
|
||||
-- Constraints
|
||||
CONSTRAINT valid_status CHECK (status IN ('pending', 'running', 'completed', 'failed', 'cancelled'))
|
||||
);
|
||||
|
||||
-- Indexes for validation runs
|
||||
CREATE INDEX IF NOT EXISTS idx_validation_runs_status ON groundtruth.validation_runs(status);
|
||||
CREATE INDEX IF NOT EXISTS idx_validation_runs_created_at ON groundtruth.validation_runs(created_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_validation_runs_tags ON groundtruth.validation_runs USING GIN (tags);
|
||||
|
||||
-- Match results table
|
||||
CREATE TABLE IF NOT EXISTS groundtruth.match_results (
|
||||
result_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
run_id UUID NOT NULL REFERENCES groundtruth.validation_runs(run_id) ON DELETE CASCADE,
|
||||
security_pair_id UUID NOT NULL,
|
||||
|
||||
-- Source function
|
||||
source_name TEXT NOT NULL,
|
||||
source_demangled_name TEXT,
|
||||
source_address BIGINT NOT NULL,
|
||||
source_size BIGINT,
|
||||
source_build_id TEXT NOT NULL,
|
||||
source_binary_name TEXT NOT NULL,
|
||||
|
||||
-- Expected target
|
||||
expected_name TEXT NOT NULL,
|
||||
expected_demangled_name TEXT,
|
||||
expected_address BIGINT NOT NULL,
|
||||
expected_size BIGINT,
|
||||
expected_build_id TEXT NOT NULL,
|
||||
expected_binary_name TEXT NOT NULL,
|
||||
|
||||
-- Actual matched target (nullable if no match found)
|
||||
actual_name TEXT,
|
||||
actual_demangled_name TEXT,
|
||||
actual_address BIGINT,
|
||||
actual_size BIGINT,
|
||||
actual_build_id TEXT,
|
||||
actual_binary_name TEXT,
|
||||
|
||||
-- Outcome
|
||||
outcome TEXT NOT NULL,
|
||||
match_score DOUBLE PRECISION,
|
||||
confidence TEXT,
|
||||
|
||||
-- Mismatch analysis
|
||||
inferred_cause TEXT,
|
||||
mismatch_detail JSONB,
|
||||
|
||||
-- Performance
|
||||
match_duration_ms DOUBLE PRECISION,
|
||||
|
||||
-- Constraints
|
||||
CONSTRAINT valid_outcome CHECK (outcome IN ('true_positive', 'false_positive', 'true_negative', 'false_negative'))
|
||||
);
|
||||
|
||||
-- Indexes for match results
|
||||
CREATE INDEX IF NOT EXISTS idx_match_results_run_id ON groundtruth.match_results(run_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_match_results_security_pair_id ON groundtruth.match_results(security_pair_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_match_results_outcome ON groundtruth.match_results(outcome);
|
||||
CREATE INDEX IF NOT EXISTS idx_match_results_inferred_cause ON groundtruth.match_results(inferred_cause) WHERE inferred_cause IS NOT NULL;
|
||||
|
||||
-- View for run summaries
|
||||
CREATE OR REPLACE VIEW groundtruth.validation_run_summaries AS
|
||||
SELECT
|
||||
run_id AS id,
|
||||
name,
|
||||
status,
|
||||
created_at,
|
||||
completed_at,
|
||||
match_rate,
|
||||
f1_score,
|
||||
total_pairs AS pair_count,
|
||||
total_functions AS function_count,
|
||||
tags
|
||||
FROM groundtruth.validation_runs;
|
||||
|
||||
-- Comments
|
||||
COMMENT ON TABLE groundtruth.validation_runs IS 'Validation harness runs with aggregate metrics';
|
||||
COMMENT ON TABLE groundtruth.match_results IS 'Per-function match results from validation runs';
|
||||
COMMENT ON VIEW groundtruth.validation_run_summaries IS 'Summary view for listing validation runs';
|
||||
27
devops/database/migrations/006_timestamp_supersession.sql
Normal file
27
devops/database/migrations/006_timestamp_supersession.sql
Normal file
@@ -0,0 +1,27 @@
|
||||
-- -----------------------------------------------------------------------------
|
||||
-- 006_timestamp_supersession.sql
|
||||
-- Sprint: SPRINT_20260119_009 Evidence Storage for Timestamps
|
||||
-- Task: EVT-005 - Re-Timestamping Support
|
||||
-- Description: Schema extension for timestamp supersession chain.
|
||||
-- -----------------------------------------------------------------------------
|
||||
|
||||
-- Add supersession column for re-timestamping chain
|
||||
ALTER TABLE evidence.timestamp_tokens
|
||||
ADD COLUMN IF NOT EXISTS supersedes_id UUID REFERENCES evidence.timestamp_tokens(id);
|
||||
|
||||
-- Index for finding superseding timestamps
|
||||
CREATE INDEX IF NOT EXISTS idx_timestamp_supersedes ON evidence.timestamp_tokens(supersedes_id);
|
||||
|
||||
-- Index for finding timestamps by expiry (for re-timestamp scheduling)
|
||||
-- Note: We need to track TSA certificate expiry separately - for now use generation_time + typical cert lifetime
|
||||
CREATE INDEX IF NOT EXISTS idx_timestamp_for_retimestamp
|
||||
ON evidence.timestamp_tokens(generation_time)
|
||||
WHERE supersedes_id IS NULL; -- Only query leaf timestamps (not already superseded)
|
||||
|
||||
-- Comments
|
||||
COMMENT ON COLUMN evidence.timestamp_tokens.supersedes_id IS 'ID of the timestamp this supersedes (for re-timestamping chain)';
|
||||
|
||||
-- Rollback script (execute separately if needed):
|
||||
-- ALTER TABLE evidence.timestamp_tokens DROP COLUMN IF EXISTS supersedes_id;
|
||||
-- DROP INDEX IF EXISTS evidence.idx_timestamp_supersedes;
|
||||
-- DROP INDEX IF EXISTS evidence.idx_timestamp_for_retimestamp;
|
||||
Reference in New Issue
Block a user