-- Migration: 009_snapshots -- Description: Creates ledger_snapshots table for time-travel/snapshot functionality -- Date: 2025-12-07 -- Create ledger_snapshots table CREATE TABLE IF NOT EXISTS ledger_snapshots ( tenant_id TEXT NOT NULL, snapshot_id UUID NOT NULL, label TEXT, description TEXT, status TEXT NOT NULL DEFAULT 'Creating', created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ, expires_at TIMESTAMPTZ, sequence_number BIGINT NOT NULL, snapshot_timestamp TIMESTAMPTZ NOT NULL, findings_count BIGINT NOT NULL DEFAULT 0, vex_statements_count BIGINT NOT NULL DEFAULT 0, advisories_count BIGINT NOT NULL DEFAULT 0, sboms_count BIGINT NOT NULL DEFAULT 0, events_count BIGINT NOT NULL DEFAULT 0, size_bytes BIGINT NOT NULL DEFAULT 0, merkle_root TEXT, dsse_digest TEXT, metadata JSONB, include_entity_types JSONB, sign_requested BOOLEAN NOT NULL DEFAULT FALSE, PRIMARY KEY (tenant_id, snapshot_id) ); -- Index for listing snapshots by status CREATE INDEX IF NOT EXISTS idx_ledger_snapshots_status ON ledger_snapshots (tenant_id, status, created_at DESC); -- Index for finding expired snapshots CREATE INDEX IF NOT EXISTS idx_ledger_snapshots_expires ON ledger_snapshots (expires_at) WHERE expires_at IS NOT NULL AND status = 'Available'; -- Index for sequence lookups CREATE INDEX IF NOT EXISTS idx_ledger_snapshots_sequence ON ledger_snapshots (tenant_id, sequence_number); -- Index for label search CREATE INDEX IF NOT EXISTS idx_ledger_snapshots_label ON ledger_snapshots (tenant_id, label) WHERE label IS NOT NULL; -- Enable RLS ALTER TABLE ledger_snapshots ENABLE ROW LEVEL SECURITY; -- RLS policy for tenant isolation DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_policies WHERE tablename = 'ledger_snapshots' AND policyname = 'ledger_snapshots_tenant_isolation' ) THEN CREATE POLICY ledger_snapshots_tenant_isolation ON ledger_snapshots USING (tenant_id = current_setting('app.tenant_id', true)) WITH CHECK (tenant_id = current_setting('app.tenant_id', true)); END IF; END $$; -- Add comment COMMENT ON TABLE ledger_snapshots IS 'Point-in-time snapshots of ledger state for time-travel queries'; COMMENT ON COLUMN ledger_snapshots.sequence_number IS 'Ledger sequence number at snapshot time'; COMMENT ON COLUMN ledger_snapshots.snapshot_timestamp IS 'Timestamp of ledger state captured'; COMMENT ON COLUMN ledger_snapshots.merkle_root IS 'Merkle root hash of all events up to sequence_number'; COMMENT ON COLUMN ledger_snapshots.dsse_digest IS 'DSSE envelope digest if signed';