Files
git.stella-ops.org/deploy/postgres-partitioning/provcache/create_provcache_schema.sql
StellaOps Bot 2a06f780cf sprints work
2025-12-25 12:19:12 +02:00

98 lines
3.8 KiB
PL/PgSQL

-- Provcache schema migration
-- Run as: psql -d stellaops -f create_provcache_schema.sql
-- Create schema
CREATE SCHEMA IF NOT EXISTS provcache;
-- Main cache items table
CREATE TABLE IF NOT EXISTS provcache.provcache_items (
verikey TEXT PRIMARY KEY,
digest_version TEXT NOT NULL DEFAULT 'v1',
verdict_hash TEXT NOT NULL,
proof_root TEXT NOT NULL,
replay_seed JSONB NOT NULL,
policy_hash TEXT NOT NULL,
signer_set_hash TEXT NOT NULL,
feed_epoch TEXT NOT NULL,
trust_score INTEGER NOT NULL CHECK (trust_score >= 0 AND trust_score <= 100),
hit_count BIGINT NOT NULL DEFAULT 0,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
expires_at TIMESTAMPTZ NOT NULL,
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
last_accessed_at TIMESTAMPTZ,
-- Constraint: expires_at must be after created_at
CONSTRAINT provcache_items_expires_check CHECK (expires_at > created_at)
);
-- Indexes for invalidation queries
CREATE INDEX IF NOT EXISTS idx_provcache_policy_hash
ON provcache.provcache_items(policy_hash);
CREATE INDEX IF NOT EXISTS idx_provcache_signer_set_hash
ON provcache.provcache_items(signer_set_hash);
CREATE INDEX IF NOT EXISTS idx_provcache_feed_epoch
ON provcache.provcache_items(feed_epoch);
CREATE INDEX IF NOT EXISTS idx_provcache_expires_at
ON provcache.provcache_items(expires_at);
CREATE INDEX IF NOT EXISTS idx_provcache_created_at
ON provcache.provcache_items(created_at);
-- Evidence chunks table for large evidence storage
CREATE TABLE IF NOT EXISTS provcache.prov_evidence_chunks (
chunk_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
proof_root TEXT NOT NULL,
chunk_index INTEGER NOT NULL,
chunk_hash TEXT NOT NULL,
blob BYTEA NOT NULL,
blob_size INTEGER NOT NULL,
content_type TEXT NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
CONSTRAINT prov_evidence_chunks_unique_index
UNIQUE (proof_root, chunk_index)
);
CREATE INDEX IF NOT EXISTS idx_prov_chunks_proof_root
ON provcache.prov_evidence_chunks(proof_root);
-- Revocation audit log
CREATE TABLE IF NOT EXISTS provcache.prov_revocations (
revocation_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
revocation_type TEXT NOT NULL,
target_hash TEXT NOT NULL,
reason TEXT,
actor TEXT,
entries_affected BIGINT NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX IF NOT EXISTS idx_prov_revocations_created_at
ON provcache.prov_revocations(created_at);
CREATE INDEX IF NOT EXISTS idx_prov_revocations_target_hash
ON provcache.prov_revocations(target_hash);
-- Function to update updated_at timestamp
CREATE OR REPLACE FUNCTION provcache.update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ language 'plpgsql';
-- Trigger for auto-updating updated_at
DROP TRIGGER IF EXISTS update_provcache_items_updated_at ON provcache.provcache_items;
CREATE TRIGGER update_provcache_items_updated_at
BEFORE UPDATE ON provcache.provcache_items
FOR EACH ROW
EXECUTE FUNCTION provcache.update_updated_at_column();
-- Grant permissions (adjust role as needed)
-- GRANT USAGE ON SCHEMA provcache TO stellaops_app;
-- GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA provcache TO stellaops_app;
-- GRANT USAGE ON ALL SEQUENCES IN SCHEMA provcache TO stellaops_app;
COMMENT ON TABLE provcache.provcache_items IS 'Provenance cache entries for cached security decisions';
COMMENT ON TABLE provcache.prov_evidence_chunks IS 'Chunked evidence storage for large SBOMs and attestations';
COMMENT ON TABLE provcache.prov_revocations IS 'Audit log of cache invalidation events';