up
This commit is contained in:
@@ -44,28 +44,57 @@ This document specifies the PostgreSQL database design for StellaOps control-pla
|
||||
| `policy` | Policy | Policy packs, rules, risk profiles, evaluations |
|
||||
| `packs` | PacksRegistry | Package attestations, mirrors, lifecycle |
|
||||
| `issuer` | IssuerDirectory | Trust anchors, issuer keys, certificates |
|
||||
| `unknowns` | Unknowns | Bitemporal ambiguity tracking for scan gaps |
|
||||
| `audit` | Shared | Cross-cutting audit log (optional) |
|
||||
|
||||
### 2.3 Multi-Tenancy Model
|
||||
|
||||
**Strategy:** Single database, single schema set, `tenant_id` column on all tenant-scoped tables.
|
||||
**Strategy:** Single database, single schema set, `tenant_id` column on all tenant-scoped tables with **mandatory Row-Level Security (RLS)**.
|
||||
|
||||
```sql
|
||||
-- Every tenant-scoped table includes:
|
||||
tenant_id UUID NOT NULL,
|
||||
|
||||
-- Session-level tenant context (set on connection open):
|
||||
-- Session-level tenant context (MUST be set on connection open):
|
||||
SET app.tenant_id = '<tenant-uuid>';
|
||||
|
||||
-- Row-level security policy (optional, for defense in depth):
|
||||
CREATE POLICY tenant_isolation ON <table>
|
||||
USING (tenant_id = current_setting('app.tenant_id')::uuid);
|
||||
-- Row-level security policy (MANDATORY for all tenant-scoped tables):
|
||||
ALTER TABLE <schema>.<table> ENABLE ROW LEVEL SECURITY;
|
||||
ALTER TABLE <schema>.<table> FORCE ROW LEVEL SECURITY;
|
||||
|
||||
CREATE POLICY <table>_tenant_isolation ON <schema>.<table>
|
||||
FOR ALL
|
||||
USING (tenant_id = <schema>_app.require_current_tenant())
|
||||
WITH CHECK (tenant_id = <schema>_app.require_current_tenant());
|
||||
```
|
||||
|
||||
**RLS Helper Function Pattern:**
|
||||
Each schema with tenant-scoped tables has a companion `<schema>_app` schema containing a `require_current_tenant()` function that validates `app.tenant_id` is set.
|
||||
|
||||
```sql
|
||||
CREATE SCHEMA IF NOT EXISTS <schema>_app;
|
||||
|
||||
CREATE OR REPLACE FUNCTION <schema>_app.require_current_tenant()
|
||||
RETURNS TEXT
|
||||
LANGUAGE plpgsql STABLE SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
v_tenant TEXT;
|
||||
BEGIN
|
||||
v_tenant := current_setting('app.tenant_id', true);
|
||||
IF v_tenant IS NULL OR v_tenant = '' THEN
|
||||
RAISE EXCEPTION 'app.tenant_id session variable not set';
|
||||
END IF;
|
||||
RETURN v_tenant;
|
||||
END;
|
||||
$$;
|
||||
```
|
||||
|
||||
**Rationale:**
|
||||
- Simplest operational model
|
||||
- Shared connection pooling
|
||||
- Easy cross-tenant queries for admin operations
|
||||
- Defense-in-depth tenant isolation at the database level
|
||||
- Prevents data leakage even if application bugs bypass tenant checks
|
||||
- Shared connection pooling compatible
|
||||
- Admin bypass via `BYPASSRLS` roles for cross-tenant operations
|
||||
- Composite indexes on `(tenant_id, ...)` for query performance
|
||||
|
||||
---
|
||||
@@ -214,6 +243,51 @@ CREATE INDEX idx_<table>_<column>_gin ON <table> USING GIN (<column>);
|
||||
CREATE INDEX idx_<table>_<column>_<path> ON <table> ((<column>->>'path'));
|
||||
```
|
||||
|
||||
### 4.5 Generated Columns for JSONB Hot Fields
|
||||
|
||||
When JSONB fields are frequently queried with equality or range filters, use **generated columns** to extract them as first-class columns. This enables:
|
||||
- B-tree indexes with accurate statistics
|
||||
- Index-only scans via covering indexes
|
||||
- Proper cardinality estimates for query planning
|
||||
|
||||
**Pattern:**
|
||||
```sql
|
||||
-- Extract hot field as generated column
|
||||
ALTER TABLE <schema>.<table>
|
||||
ADD COLUMN IF NOT EXISTS <field_name> <type>
|
||||
GENERATED ALWAYS AS ((<jsonb_column>->>'<json_key>')::<type>) STORED;
|
||||
|
||||
-- Create B-tree index on generated column
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_<table>_<field_name>
|
||||
ON <schema>.<table> (<field_name>)
|
||||
WHERE <field_name> IS NOT NULL;
|
||||
|
||||
-- Covering index for dashboard queries
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_<table>_listing
|
||||
ON <schema>.<table> (tenant_id, created_at DESC)
|
||||
INCLUDE (<generated_col1>, <generated_col2>, <generated_col3>);
|
||||
|
||||
-- Update statistics
|
||||
ANALYZE <schema>.<table>;
|
||||
```
|
||||
|
||||
**Example (scheduler.runs stats extraction):**
|
||||
```sql
|
||||
ALTER TABLE scheduler.runs
|
||||
ADD COLUMN IF NOT EXISTS finding_count INT
|
||||
GENERATED ALWAYS AS (NULLIF((stats->>'findingCount'), '')::int) STORED;
|
||||
|
||||
CREATE INDEX ix_runs_with_findings
|
||||
ON scheduler.runs (tenant_id, created_at DESC)
|
||||
WHERE finding_count > 0;
|
||||
```
|
||||
|
||||
**Guidelines:**
|
||||
- Use `NULLIF(<expr>, '')` before casting to handle empty strings
|
||||
- Add `WHERE <column> IS NOT NULL` to partial indexes for sparse data
|
||||
- Use `INCLUDE` clause for covering indexes that return multiple generated columns
|
||||
- Run `ANALYZE` after adding generated columns to populate statistics
|
||||
|
||||
---
|
||||
|
||||
## 5. Schema Definitions
|
||||
|
||||
444
docs/db/schemas/signals.sql
Normal file
444
docs/db/schemas/signals.sql
Normal file
@@ -0,0 +1,444 @@
|
||||
-- =============================================================================
|
||||
-- SIGNALS SCHEMA - Call Graph Relational Tables
|
||||
-- Version: V3102_001
|
||||
-- Sprint: SPRINT_3102_0001_0001
|
||||
-- =============================================================================
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS signals;
|
||||
|
||||
-- =============================================================================
|
||||
-- SCAN TRACKING
|
||||
-- =============================================================================
|
||||
|
||||
-- Tracks scan context for call graph analysis
|
||||
CREATE TABLE signals.scans (
|
||||
scan_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
artifact_digest TEXT NOT NULL,
|
||||
repo_uri TEXT,
|
||||
commit_sha TEXT,
|
||||
sbom_digest TEXT,
|
||||
policy_digest TEXT,
|
||||
status TEXT NOT NULL DEFAULT 'pending'
|
||||
CHECK (status IN ('pending', 'processing', 'completed', 'failed')),
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
completed_at TIMESTAMPTZ,
|
||||
error_message TEXT,
|
||||
|
||||
-- Composite index for cache lookups
|
||||
CONSTRAINT scans_artifact_sbom_unique UNIQUE (artifact_digest, sbom_digest)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_scans_status ON signals.scans(status);
|
||||
CREATE INDEX idx_scans_artifact ON signals.scans(artifact_digest);
|
||||
CREATE INDEX idx_scans_commit ON signals.scans(commit_sha) WHERE commit_sha IS NOT NULL;
|
||||
CREATE INDEX idx_scans_created ON signals.scans(created_at DESC);
|
||||
|
||||
-- =============================================================================
|
||||
-- ARTIFACTS
|
||||
-- =============================================================================
|
||||
|
||||
-- Individual artifacts (assemblies, JARs, modules) within a scan
|
||||
CREATE TABLE signals.artifacts (
|
||||
artifact_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
scan_id UUID NOT NULL REFERENCES signals.scans(scan_id) ON DELETE CASCADE,
|
||||
artifact_key TEXT NOT NULL,
|
||||
kind TEXT NOT NULL CHECK (kind IN ('assembly', 'jar', 'module', 'binary', 'script')),
|
||||
sha256 TEXT NOT NULL,
|
||||
purl TEXT,
|
||||
build_id TEXT,
|
||||
file_path TEXT,
|
||||
size_bytes BIGINT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
|
||||
CONSTRAINT artifacts_scan_key_unique UNIQUE (scan_id, artifact_key)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_artifacts_scan ON signals.artifacts(scan_id);
|
||||
CREATE INDEX idx_artifacts_sha256 ON signals.artifacts(sha256);
|
||||
CREATE INDEX idx_artifacts_purl ON signals.artifacts(purl) WHERE purl IS NOT NULL;
|
||||
CREATE INDEX idx_artifacts_build_id ON signals.artifacts(build_id) WHERE build_id IS NOT NULL;
|
||||
|
||||
-- =============================================================================
|
||||
-- CALL GRAPH NODES
|
||||
-- =============================================================================
|
||||
|
||||
-- Individual nodes (symbols) in call graphs
|
||||
CREATE TABLE signals.cg_nodes (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
scan_id UUID NOT NULL REFERENCES signals.scans(scan_id) ON DELETE CASCADE,
|
||||
node_id TEXT NOT NULL,
|
||||
artifact_key TEXT,
|
||||
symbol_key TEXT NOT NULL,
|
||||
visibility TEXT NOT NULL DEFAULT 'unknown'
|
||||
CHECK (visibility IN ('public', 'internal', 'protected', 'private', 'unknown')),
|
||||
is_entrypoint_candidate BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
purl TEXT,
|
||||
symbol_digest TEXT,
|
||||
flags INT NOT NULL DEFAULT 0,
|
||||
attributes JSONB,
|
||||
|
||||
CONSTRAINT cg_nodes_scan_node_unique UNIQUE (scan_id, node_id)
|
||||
);
|
||||
|
||||
-- Primary lookup indexes
|
||||
CREATE INDEX idx_cg_nodes_scan ON signals.cg_nodes(scan_id);
|
||||
CREATE INDEX idx_cg_nodes_symbol_key ON signals.cg_nodes(symbol_key);
|
||||
CREATE INDEX idx_cg_nodes_purl ON signals.cg_nodes(purl) WHERE purl IS NOT NULL;
|
||||
CREATE INDEX idx_cg_nodes_entrypoint ON signals.cg_nodes(scan_id, is_entrypoint_candidate)
|
||||
WHERE is_entrypoint_candidate = TRUE;
|
||||
|
||||
-- Full-text search on symbol keys
|
||||
CREATE INDEX idx_cg_nodes_symbol_fts ON signals.cg_nodes
|
||||
USING gin(to_tsvector('simple', symbol_key));
|
||||
|
||||
-- =============================================================================
|
||||
-- CALL GRAPH EDGES
|
||||
-- =============================================================================
|
||||
|
||||
-- Call edges between nodes
|
||||
CREATE TABLE signals.cg_edges (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
scan_id UUID NOT NULL REFERENCES signals.scans(scan_id) ON DELETE CASCADE,
|
||||
from_node_id TEXT NOT NULL,
|
||||
to_node_id TEXT NOT NULL,
|
||||
kind SMALLINT NOT NULL DEFAULT 0, -- 0=static, 1=heuristic, 2=runtime
|
||||
reason SMALLINT NOT NULL DEFAULT 0, -- EdgeReason enum value
|
||||
weight REAL NOT NULL DEFAULT 1.0,
|
||||
offset_bytes INT,
|
||||
is_resolved BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
provenance TEXT,
|
||||
|
||||
-- Composite unique constraint
|
||||
CONSTRAINT cg_edges_unique UNIQUE (scan_id, from_node_id, to_node_id, kind, reason)
|
||||
);
|
||||
|
||||
-- Traversal indexes (critical for reachability queries)
|
||||
CREATE INDEX idx_cg_edges_scan ON signals.cg_edges(scan_id);
|
||||
CREATE INDEX idx_cg_edges_from ON signals.cg_edges(scan_id, from_node_id);
|
||||
CREATE INDEX idx_cg_edges_to ON signals.cg_edges(scan_id, to_node_id);
|
||||
|
||||
-- Covering index for common traversal pattern
|
||||
CREATE INDEX idx_cg_edges_traversal ON signals.cg_edges(scan_id, from_node_id)
|
||||
INCLUDE (to_node_id, kind, weight);
|
||||
|
||||
-- =============================================================================
|
||||
-- ENTRYPOINTS
|
||||
-- =============================================================================
|
||||
|
||||
-- Framework-aware entrypoints
|
||||
CREATE TABLE signals.entrypoints (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
scan_id UUID NOT NULL REFERENCES signals.scans(scan_id) ON DELETE CASCADE,
|
||||
node_id TEXT NOT NULL,
|
||||
kind TEXT NOT NULL CHECK (kind IN (
|
||||
'http', 'grpc', 'cli', 'job', 'event', 'message_queue',
|
||||
'timer', 'test', 'main', 'module_init', 'static_constructor', 'unknown'
|
||||
)),
|
||||
framework TEXT,
|
||||
route TEXT,
|
||||
http_method TEXT,
|
||||
phase TEXT NOT NULL DEFAULT 'runtime'
|
||||
CHECK (phase IN ('module_init', 'app_start', 'runtime', 'shutdown')),
|
||||
order_idx INT NOT NULL DEFAULT 0,
|
||||
|
||||
CONSTRAINT entrypoints_scan_node_unique UNIQUE (scan_id, node_id, kind)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_entrypoints_scan ON signals.entrypoints(scan_id);
|
||||
CREATE INDEX idx_entrypoints_kind ON signals.entrypoints(kind);
|
||||
CREATE INDEX idx_entrypoints_route ON signals.entrypoints(route) WHERE route IS NOT NULL;
|
||||
|
||||
-- =============================================================================
|
||||
-- SYMBOL-TO-COMPONENT MAPPING
|
||||
-- =============================================================================
|
||||
|
||||
-- Maps symbols to SBOM components (for vuln correlation)
|
||||
CREATE TABLE signals.symbol_component_map (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
scan_id UUID NOT NULL REFERENCES signals.scans(scan_id) ON DELETE CASCADE,
|
||||
node_id TEXT NOT NULL,
|
||||
purl TEXT NOT NULL,
|
||||
mapping_kind TEXT NOT NULL CHECK (mapping_kind IN (
|
||||
'exact', 'assembly', 'namespace', 'heuristic'
|
||||
)),
|
||||
confidence REAL NOT NULL DEFAULT 1.0,
|
||||
evidence JSONB,
|
||||
|
||||
CONSTRAINT symbol_component_map_unique UNIQUE (scan_id, node_id, purl)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_symbol_component_scan ON signals.symbol_component_map(scan_id);
|
||||
CREATE INDEX idx_symbol_component_purl ON signals.symbol_component_map(purl);
|
||||
CREATE INDEX idx_symbol_component_node ON signals.symbol_component_map(scan_id, node_id);
|
||||
|
||||
-- =============================================================================
|
||||
-- REACHABILITY RESULTS
|
||||
-- =============================================================================
|
||||
|
||||
-- Component-level reachability status
|
||||
CREATE TABLE signals.reachability_components (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
scan_id UUID NOT NULL REFERENCES signals.scans(scan_id) ON DELETE CASCADE,
|
||||
purl TEXT NOT NULL,
|
||||
status SMALLINT NOT NULL DEFAULT 0, -- ReachabilityStatus enum
|
||||
lattice_state TEXT,
|
||||
confidence REAL NOT NULL DEFAULT 0,
|
||||
why JSONB,
|
||||
evidence JSONB,
|
||||
computed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
|
||||
CONSTRAINT reachability_components_unique UNIQUE (scan_id, purl)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_reachability_components_scan ON signals.reachability_components(scan_id);
|
||||
CREATE INDEX idx_reachability_components_purl ON signals.reachability_components(purl);
|
||||
CREATE INDEX idx_reachability_components_status ON signals.reachability_components(status);
|
||||
|
||||
-- CVE-level reachability findings
|
||||
CREATE TABLE signals.reachability_findings (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
scan_id UUID NOT NULL REFERENCES signals.scans(scan_id) ON DELETE CASCADE,
|
||||
cve_id TEXT NOT NULL,
|
||||
purl TEXT NOT NULL,
|
||||
status SMALLINT NOT NULL DEFAULT 0,
|
||||
lattice_state TEXT,
|
||||
confidence REAL NOT NULL DEFAULT 0,
|
||||
path_witness TEXT[],
|
||||
why JSONB,
|
||||
evidence JSONB,
|
||||
spine_id UUID, -- Reference to proof spine
|
||||
computed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
|
||||
CONSTRAINT reachability_findings_unique UNIQUE (scan_id, cve_id, purl)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_reachability_findings_scan ON signals.reachability_findings(scan_id);
|
||||
CREATE INDEX idx_reachability_findings_cve ON signals.reachability_findings(cve_id);
|
||||
CREATE INDEX idx_reachability_findings_purl ON signals.reachability_findings(purl);
|
||||
CREATE INDEX idx_reachability_findings_status ON signals.reachability_findings(status);
|
||||
|
||||
-- =============================================================================
|
||||
-- RUNTIME SAMPLES
|
||||
-- =============================================================================
|
||||
|
||||
-- Stack trace samples from runtime evidence
|
||||
CREATE TABLE signals.runtime_samples (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
scan_id UUID NOT NULL REFERENCES signals.scans(scan_id) ON DELETE CASCADE,
|
||||
collected_at TIMESTAMPTZ NOT NULL,
|
||||
env_hash TEXT,
|
||||
timestamp TIMESTAMPTZ NOT NULL,
|
||||
pid INT,
|
||||
thread_id INT,
|
||||
frames TEXT[] NOT NULL,
|
||||
weight REAL NOT NULL DEFAULT 1.0,
|
||||
container_id TEXT,
|
||||
pod_name TEXT
|
||||
);
|
||||
|
||||
CREATE INDEX idx_runtime_samples_scan ON signals.runtime_samples(scan_id);
|
||||
CREATE INDEX idx_runtime_samples_collected ON signals.runtime_samples(collected_at DESC);
|
||||
|
||||
-- GIN index for frame array searches
|
||||
CREATE INDEX idx_runtime_samples_frames ON signals.runtime_samples USING gin(frames);
|
||||
|
||||
-- =============================================================================
|
||||
-- DEPLOYMENT REFERENCES (for popularity scoring)
|
||||
-- =============================================================================
|
||||
|
||||
CREATE TABLE signals.deploy_refs (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
purl TEXT NOT NULL,
|
||||
image_id TEXT NOT NULL,
|
||||
environment TEXT,
|
||||
first_seen_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
last_seen_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE (purl, image_id, environment)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_deploy_refs_purl ON signals.deploy_refs(purl);
|
||||
CREATE INDEX idx_deploy_refs_last_seen ON signals.deploy_refs(last_seen_at);
|
||||
|
||||
-- =============================================================================
|
||||
-- GRAPH METRICS (for centrality scoring)
|
||||
-- =============================================================================
|
||||
|
||||
CREATE TABLE signals.graph_metrics (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
symbol_id TEXT NOT NULL,
|
||||
callgraph_id TEXT NOT NULL,
|
||||
degree INT NOT NULL DEFAULT 0,
|
||||
betweenness FLOAT NOT NULL DEFAULT 0,
|
||||
last_computed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE (symbol_id, callgraph_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_graph_metrics_symbol ON signals.graph_metrics(symbol_id);
|
||||
|
||||
-- =============================================================================
|
||||
-- UNKNOWNS TRACKING (enhanced for scoring)
|
||||
-- =============================================================================
|
||||
|
||||
CREATE TABLE signals.unknowns (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
subject_key TEXT NOT NULL,
|
||||
callgraph_id TEXT,
|
||||
symbol_id TEXT,
|
||||
code_id TEXT,
|
||||
purl TEXT,
|
||||
purl_version TEXT,
|
||||
edge_from TEXT,
|
||||
edge_to TEXT,
|
||||
reason TEXT,
|
||||
|
||||
-- Scoring factors
|
||||
popularity_score FLOAT DEFAULT 0,
|
||||
deployment_count INT DEFAULT 0,
|
||||
exploit_potential_score FLOAT DEFAULT 0,
|
||||
uncertainty_score FLOAT DEFAULT 0,
|
||||
centrality_score FLOAT DEFAULT 0,
|
||||
degree_centrality INT DEFAULT 0,
|
||||
betweenness_centrality FLOAT DEFAULT 0,
|
||||
staleness_score FLOAT DEFAULT 0,
|
||||
days_since_last_analysis INT DEFAULT 0,
|
||||
|
||||
-- Composite score and band
|
||||
score FLOAT DEFAULT 0,
|
||||
band TEXT DEFAULT 'cold' CHECK (band IN ('hot', 'warm', 'cold')),
|
||||
|
||||
-- Flags and traces
|
||||
flags JSONB DEFAULT '{}',
|
||||
normalization_trace JSONB,
|
||||
graph_slice_hash TEXT,
|
||||
evidence_set_hash TEXT,
|
||||
callgraph_attempt_hash TEXT,
|
||||
|
||||
-- Rescan tracking
|
||||
rescan_attempts INT DEFAULT 0,
|
||||
last_rescan_result TEXT,
|
||||
next_scheduled_rescan TIMESTAMPTZ,
|
||||
last_analyzed_at TIMESTAMPTZ,
|
||||
|
||||
-- Timestamps
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_unknowns_subject ON signals.unknowns(subject_key);
|
||||
CREATE INDEX idx_unknowns_band ON signals.unknowns(band);
|
||||
CREATE INDEX idx_unknowns_score ON signals.unknowns(score DESC);
|
||||
CREATE INDEX idx_unknowns_next_rescan ON signals.unknowns(next_scheduled_rescan) WHERE next_scheduled_rescan IS NOT NULL;
|
||||
|
||||
-- =============================================================================
|
||||
-- MATERIALIZED VIEWS FOR ANALYTICS
|
||||
-- =============================================================================
|
||||
|
||||
-- Daily scan statistics
|
||||
CREATE MATERIALIZED VIEW signals.scan_stats_daily AS
|
||||
SELECT
|
||||
DATE_TRUNC('day', created_at) AS day,
|
||||
COUNT(*) AS total_scans,
|
||||
COUNT(*) FILTER (WHERE status = 'completed') AS completed_scans,
|
||||
COUNT(*) FILTER (WHERE status = 'failed') AS failed_scans,
|
||||
AVG(EXTRACT(EPOCH FROM (completed_at - created_at))) FILTER (WHERE status = 'completed') AS avg_duration_seconds
|
||||
FROM signals.scans
|
||||
GROUP BY DATE_TRUNC('day', created_at)
|
||||
ORDER BY day DESC;
|
||||
|
||||
CREATE UNIQUE INDEX idx_scan_stats_daily_day ON signals.scan_stats_daily(day);
|
||||
|
||||
-- CVE reachability summary
|
||||
CREATE MATERIALIZED VIEW signals.cve_reachability_summary AS
|
||||
SELECT
|
||||
cve_id,
|
||||
COUNT(DISTINCT scan_id) AS affected_scans,
|
||||
COUNT(DISTINCT purl) AS affected_components,
|
||||
COUNT(*) FILTER (WHERE status = 2) AS reachable_count, -- REACHABLE_STATIC
|
||||
COUNT(*) FILTER (WHERE status = 3) AS proven_count, -- REACHABLE_PROVEN
|
||||
COUNT(*) FILTER (WHERE status = 0) AS unreachable_count,
|
||||
AVG(confidence) AS avg_confidence,
|
||||
MAX(computed_at) AS last_updated
|
||||
FROM signals.reachability_findings
|
||||
GROUP BY cve_id;
|
||||
|
||||
CREATE UNIQUE INDEX idx_cve_reachability_summary_cve ON signals.cve_reachability_summary(cve_id);
|
||||
|
||||
-- Refresh function
|
||||
CREATE OR REPLACE FUNCTION signals.refresh_analytics_views()
|
||||
RETURNS void AS $$
|
||||
BEGIN
|
||||
REFRESH MATERIALIZED VIEW CONCURRENTLY signals.scan_stats_daily;
|
||||
REFRESH MATERIALIZED VIEW CONCURRENTLY signals.cve_reachability_summary;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- =============================================================================
|
||||
-- PROOF SPINE TABLES (SPRINT_3100)
|
||||
-- =============================================================================
|
||||
|
||||
-- Schema for proof spine storage
|
||||
CREATE SCHEMA IF NOT EXISTS scanner;
|
||||
|
||||
-- Main proof spine table
|
||||
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 UUID NOT NULL,
|
||||
segment_count INT NOT NULL,
|
||||
created_at 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 DESC);
|
||||
|
||||
-- Individual segments within a spine
|
||||
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 (
|
||||
'SBOM_SLICE', 'MATCH', 'REACHABILITY',
|
||||
'GUARD_ANALYSIS', 'RUNTIME_OBSERVATION', 'POLICY_EVAL'
|
||||
)),
|
||||
input_hash TEXT NOT NULL,
|
||||
result_hash TEXT NOT NULL,
|
||||
prev_segment_hash TEXT,
|
||||
envelope BYTEA NOT NULL, -- DSSE envelope (JSON or CBOR)
|
||||
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 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);
|
||||
|
||||
-- Audit trail for spine supersession
|
||||
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 TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_proof_spine_history_spine ON scanner.proof_spine_history(spine_id);
|
||||
458
docs/db/schemas/ttfs.sql
Normal file
458
docs/db/schemas/ttfs.sql
Normal file
@@ -0,0 +1,458 @@
|
||||
-- TTFS (Time-to-First-Signal) Schema
|
||||
-- Generated from SPRINT_0338_0001_0001_ttfs_foundation.md
|
||||
-- Tables are placed in scheduler schema to co-locate with runs/jobs data
|
||||
|
||||
-- ============================================================================
|
||||
-- FIRST SIGNAL SNAPSHOTS
|
||||
-- ============================================================================
|
||||
-- Caches the current signal state for each job, enabling sub-second lookups
|
||||
-- without querying live job state.
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.first_signal_snapshots (
|
||||
job_id UUID PRIMARY KEY,
|
||||
tenant_id UUID NOT NULL,
|
||||
run_id UUID REFERENCES scheduler.runs(id),
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
|
||||
-- Signal state
|
||||
kind TEXT NOT NULL CHECK (kind IN (
|
||||
'queued',
|
||||
'started',
|
||||
'phase',
|
||||
'blocked',
|
||||
'failed',
|
||||
'succeeded',
|
||||
'canceled',
|
||||
'unavailable'
|
||||
)),
|
||||
phase TEXT NOT NULL CHECK (phase IN (
|
||||
'resolve',
|
||||
'fetch',
|
||||
'restore',
|
||||
'analyze',
|
||||
'policy',
|
||||
'report',
|
||||
'unknown'
|
||||
)),
|
||||
summary TEXT NOT NULL,
|
||||
eta_seconds INT NULL,
|
||||
|
||||
-- Predictive context
|
||||
last_known_outcome JSONB NULL,
|
||||
-- Example: {"status": "succeeded", "finished_at": "2025-12-13T10:15:00Z", "findings_count": 12}
|
||||
|
||||
next_actions JSONB NULL,
|
||||
-- Example: [{"label": "View previous run", "href": "/runs/abc-123"}]
|
||||
|
||||
-- Diagnostics for debugging
|
||||
diagnostics JSONB NOT NULL DEFAULT '{}',
|
||||
-- Example: {"queue_position": 3, "worker_id": "worker-7", "retry_count": 0}
|
||||
|
||||
-- Flexible payload for future extensibility
|
||||
payload_json JSONB NOT NULL DEFAULT '{}'
|
||||
);
|
||||
|
||||
COMMENT ON TABLE scheduler.first_signal_snapshots IS 'Cached first-signal state for jobs, enabling sub-second TTFS lookups';
|
||||
COMMENT ON COLUMN scheduler.first_signal_snapshots.kind IS 'Current signal kind: queued, started, phase, blocked, failed, succeeded, canceled, unavailable';
|
||||
COMMENT ON COLUMN scheduler.first_signal_snapshots.phase IS 'Current execution phase: resolve, fetch, restore, analyze, policy, report, unknown';
|
||||
COMMENT ON COLUMN scheduler.first_signal_snapshots.eta_seconds IS 'Estimated seconds until completion, null if unknown';
|
||||
COMMENT ON COLUMN scheduler.first_signal_snapshots.last_known_outcome IS 'Previous run outcome for predictive context';
|
||||
COMMENT ON COLUMN scheduler.first_signal_snapshots.next_actions IS 'Suggested user actions with labels and hrefs';
|
||||
|
||||
-- Indexes for common query patterns
|
||||
CREATE INDEX IF NOT EXISTS idx_first_signal_snapshots_tenant
|
||||
ON scheduler.first_signal_snapshots(tenant_id);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_first_signal_snapshots_updated
|
||||
ON scheduler.first_signal_snapshots(updated_at DESC);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_first_signal_snapshots_kind
|
||||
ON scheduler.first_signal_snapshots(kind);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_first_signal_snapshots_run
|
||||
ON scheduler.first_signal_snapshots(run_id);
|
||||
|
||||
-- Composite index for tenant + kind queries (e.g., "all failed jobs for tenant")
|
||||
CREATE INDEX IF NOT EXISTS idx_first_signal_snapshots_tenant_kind
|
||||
ON scheduler.first_signal_snapshots(tenant_id, kind);
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
-- TTFS EVENTS
|
||||
-- ============================================================================
|
||||
-- Telemetry storage for TTFS metrics, supporting SLO analysis and alerting.
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.ttfs_events (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
ts TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
tenant_id UUID NOT NULL,
|
||||
job_id UUID NOT NULL,
|
||||
run_id UUID NULL,
|
||||
|
||||
-- Dimensions
|
||||
surface TEXT NOT NULL CHECK (surface IN ('ui', 'cli', 'ci')),
|
||||
event_type TEXT NOT NULL CHECK (event_type IN (
|
||||
'signal.start',
|
||||
'signal.rendered',
|
||||
'signal.timeout',
|
||||
'signal.error',
|
||||
'signal.cache_hit',
|
||||
'signal.cold_start'
|
||||
)),
|
||||
|
||||
-- Measurements
|
||||
ttfs_ms INT NOT NULL,
|
||||
cache_hit BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
|
||||
-- Signal context
|
||||
signal_source TEXT CHECK (signal_source IN ('snapshot', 'cold_start', 'failure_index')),
|
||||
kind TEXT CHECK (kind IN (
|
||||
'queued', 'started', 'phase', 'blocked',
|
||||
'failed', 'succeeded', 'canceled', 'unavailable'
|
||||
)),
|
||||
phase TEXT CHECK (phase IN (
|
||||
'resolve', 'fetch', 'restore', 'analyze',
|
||||
'policy', 'report', 'unknown'
|
||||
)),
|
||||
|
||||
-- Client context
|
||||
network_state TEXT NULL, -- e.g., '4g', 'wifi', 'offline'
|
||||
device TEXT NULL, -- e.g., 'desktop', 'mobile', 'cli'
|
||||
release TEXT NULL, -- Application version
|
||||
|
||||
-- Tracing
|
||||
correlation_id TEXT NULL,
|
||||
trace_id TEXT NULL,
|
||||
span_id TEXT NULL,
|
||||
|
||||
-- Error context
|
||||
error_code TEXT NULL,
|
||||
error_message TEXT NULL,
|
||||
|
||||
-- Extensible metadata
|
||||
metadata JSONB DEFAULT '{}'
|
||||
);
|
||||
|
||||
COMMENT ON TABLE scheduler.ttfs_events IS 'Telemetry events for Time-to-First-Signal metrics and SLO tracking';
|
||||
COMMENT ON COLUMN scheduler.ttfs_events.ttfs_ms IS 'Time-to-first-signal in milliseconds';
|
||||
COMMENT ON COLUMN scheduler.ttfs_events.signal_source IS 'Source of signal: snapshot (cache), cold_start (computed), failure_index (predicted)';
|
||||
COMMENT ON COLUMN scheduler.ttfs_events.event_type IS 'Type of TTFS event: start, rendered, timeout, error, cache_hit, cold_start';
|
||||
|
||||
-- Indexes for time-series queries
|
||||
CREATE INDEX IF NOT EXISTS idx_ttfs_events_ts
|
||||
ON scheduler.ttfs_events(ts DESC);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_ttfs_events_tenant_ts
|
||||
ON scheduler.ttfs_events(tenant_id, ts DESC);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_ttfs_events_surface
|
||||
ON scheduler.ttfs_events(surface, ts DESC);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_ttfs_events_job
|
||||
ON scheduler.ttfs_events(job_id);
|
||||
|
||||
-- Partial index for errors (for alerting queries)
|
||||
CREATE INDEX IF NOT EXISTS idx_ttfs_events_errors
|
||||
ON scheduler.ttfs_events(ts DESC, error_code)
|
||||
WHERE event_type = 'signal.error';
|
||||
|
||||
-- Composite index for SLO analysis
|
||||
CREATE INDEX IF NOT EXISTS idx_ttfs_events_surface_cache
|
||||
ON scheduler.ttfs_events(surface, cache_hit, ts DESC);
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
-- FAILURE SIGNATURES
|
||||
-- ============================================================================
|
||||
-- Historical failure patterns for predictive "last known outcome" enrichment.
|
||||
|
||||
CREATE TABLE IF NOT EXISTS scheduler.failure_signatures (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
tenant_id UUID NOT NULL,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
|
||||
-- Signature identification
|
||||
signature_hash TEXT NOT NULL, -- SHA-256 of pattern JSON
|
||||
signature_version INT NOT NULL DEFAULT 1,
|
||||
|
||||
-- Pattern matching criteria
|
||||
pattern JSONB NOT NULL,
|
||||
-- Example: {
|
||||
-- "phase": "analyze",
|
||||
-- "error_code": "LAYER_EXTRACT_FAILED",
|
||||
-- "image_pattern": "registry.io/.*:v1.*"
|
||||
-- }
|
||||
|
||||
-- Outcome prediction
|
||||
outcome JSONB NOT NULL,
|
||||
-- Example: {
|
||||
-- "likely_cause": "Registry rate limiting",
|
||||
-- "mttr_p50_seconds": 300,
|
||||
-- "mttr_p95_seconds": 900,
|
||||
-- "suggested_action": "Wait 5 minutes and retry",
|
||||
-- "remediation_url": "/docs/troubleshooting/rate-limits"
|
||||
-- }
|
||||
|
||||
-- Confidence metrics
|
||||
confidence NUMERIC(4,3) NOT NULL DEFAULT 0.5 CHECK (confidence >= 0 AND confidence <= 1),
|
||||
sample_count INT NOT NULL DEFAULT 0,
|
||||
last_matched_at TIMESTAMPTZ NULL,
|
||||
|
||||
-- Lifecycle
|
||||
enabled BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
expires_at TIMESTAMPTZ NULL,
|
||||
|
||||
-- Constraints
|
||||
UNIQUE (tenant_id, signature_hash)
|
||||
);
|
||||
|
||||
COMMENT ON TABLE scheduler.failure_signatures IS 'Historical failure patterns for predictive outcome enrichment';
|
||||
COMMENT ON COLUMN scheduler.failure_signatures.signature_hash IS 'SHA-256 hash of pattern JSON for deduplication';
|
||||
COMMENT ON COLUMN scheduler.failure_signatures.pattern IS 'JSON pattern for matching job failures';
|
||||
COMMENT ON COLUMN scheduler.failure_signatures.outcome IS 'Predicted outcome with cause, MTTR, and suggested actions';
|
||||
COMMENT ON COLUMN scheduler.failure_signatures.confidence IS 'Confidence score 0.0-1.0 based on sample count and recency';
|
||||
|
||||
-- Indexes for failure signature lookups
|
||||
CREATE INDEX IF NOT EXISTS idx_failure_signatures_tenant
|
||||
ON scheduler.failure_signatures(tenant_id)
|
||||
WHERE enabled = TRUE;
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_failure_signatures_hash
|
||||
ON scheduler.failure_signatures(signature_hash);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_failure_signatures_confidence
|
||||
ON scheduler.failure_signatures(tenant_id, confidence DESC)
|
||||
WHERE enabled = TRUE;
|
||||
|
||||
-- GIN index for JSONB pattern matching
|
||||
CREATE INDEX IF NOT EXISTS idx_failure_signatures_pattern
|
||||
ON scheduler.failure_signatures USING GIN (pattern);
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
-- HOURLY ROLLUP VIEW
|
||||
-- ============================================================================
|
||||
-- Pre-aggregated metrics for dashboard performance.
|
||||
|
||||
CREATE OR REPLACE VIEW scheduler.ttfs_hourly_summary AS
|
||||
SELECT
|
||||
date_trunc('hour', ts) AS hour,
|
||||
surface,
|
||||
cache_hit,
|
||||
COUNT(*) AS event_count,
|
||||
AVG(ttfs_ms) AS avg_ms,
|
||||
percentile_cont(0.50) WITHIN GROUP (ORDER BY ttfs_ms) AS p50_ms,
|
||||
percentile_cont(0.95) WITHIN GROUP (ORDER BY ttfs_ms) AS p95_ms,
|
||||
percentile_cont(0.99) WITHIN GROUP (ORDER BY ttfs_ms) AS p99_ms,
|
||||
MIN(ttfs_ms) AS min_ms,
|
||||
MAX(ttfs_ms) AS max_ms,
|
||||
COUNT(*) FILTER (WHERE ttfs_ms > 2000) AS over_p50_slo,
|
||||
COUNT(*) FILTER (WHERE ttfs_ms > 5000) AS over_p95_slo
|
||||
FROM scheduler.ttfs_events
|
||||
WHERE ts >= NOW() - INTERVAL '7 days'
|
||||
GROUP BY date_trunc('hour', ts), surface, cache_hit;
|
||||
|
||||
COMMENT ON VIEW scheduler.ttfs_hourly_summary IS 'Hourly rollup of TTFS metrics for dashboard queries';
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
-- DAILY ROLLUP VIEW (for long-term trending)
|
||||
-- ============================================================================
|
||||
|
||||
CREATE OR REPLACE VIEW scheduler.ttfs_daily_summary AS
|
||||
SELECT
|
||||
date_trunc('day', ts) AS day,
|
||||
tenant_id,
|
||||
surface,
|
||||
COUNT(*) AS event_count,
|
||||
AVG(ttfs_ms) AS avg_ms,
|
||||
percentile_cont(0.50) WITHIN GROUP (ORDER BY ttfs_ms) AS p50_ms,
|
||||
percentile_cont(0.95) WITHIN GROUP (ORDER BY ttfs_ms) AS p95_ms,
|
||||
SUM(CASE WHEN cache_hit THEN 1 ELSE 0 END)::FLOAT / NULLIF(COUNT(*), 0) AS cache_hit_rate,
|
||||
COUNT(*) FILTER (WHERE event_type = 'signal.error') AS error_count
|
||||
FROM scheduler.ttfs_events
|
||||
WHERE ts >= NOW() - INTERVAL '90 days'
|
||||
GROUP BY date_trunc('day', ts), tenant_id, surface;
|
||||
|
||||
COMMENT ON VIEW scheduler.ttfs_daily_summary IS 'Daily rollup of TTFS metrics for long-term trending';
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
-- SLO BREACH SUMMARY VIEW
|
||||
-- ============================================================================
|
||||
|
||||
CREATE OR REPLACE VIEW scheduler.ttfs_slo_breaches AS
|
||||
SELECT
|
||||
date_trunc('hour', ts) AS hour,
|
||||
tenant_id,
|
||||
surface,
|
||||
COUNT(*) AS total_signals,
|
||||
COUNT(*) FILTER (WHERE ttfs_ms > 2000) AS p50_breaches,
|
||||
COUNT(*) FILTER (WHERE ttfs_ms > 5000) AS p95_breaches,
|
||||
ROUND(100.0 * COUNT(*) FILTER (WHERE ttfs_ms <= 2000) / NULLIF(COUNT(*), 0), 2) AS p50_compliance_pct,
|
||||
ROUND(100.0 * COUNT(*) FILTER (WHERE ttfs_ms <= 5000) / NULLIF(COUNT(*), 0), 2) AS p95_compliance_pct
|
||||
FROM scheduler.ttfs_events
|
||||
WHERE ts >= NOW() - INTERVAL '24 hours'
|
||||
AND event_type = 'signal.rendered'
|
||||
GROUP BY date_trunc('hour', ts), tenant_id, surface
|
||||
HAVING COUNT(*) > 0;
|
||||
|
||||
COMMENT ON VIEW scheduler.ttfs_slo_breaches IS 'SLO compliance summary for alerting dashboards';
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
-- RETENTION POLICY (for cleanup jobs)
|
||||
-- ============================================================================
|
||||
-- Note: Implement as scheduled job, not as database trigger
|
||||
|
||||
-- Recommended retention periods:
|
||||
-- - ttfs_events: 90 days (telemetry data)
|
||||
-- - first_signal_snapshots: 24 hours after job completion (cache)
|
||||
-- - failure_signatures: indefinite (but expire low-confidence signatures)
|
||||
|
||||
-- Example cleanup queries (run via scheduler):
|
||||
--
|
||||
-- DELETE FROM scheduler.ttfs_events WHERE ts < NOW() - INTERVAL '90 days';
|
||||
--
|
||||
-- DELETE FROM scheduler.first_signal_snapshots
|
||||
-- WHERE updated_at < NOW() - INTERVAL '24 hours'
|
||||
-- AND kind IN ('succeeded', 'failed', 'canceled');
|
||||
--
|
||||
-- UPDATE scheduler.failure_signatures
|
||||
-- SET enabled = FALSE
|
||||
-- WHERE confidence < 0.3 AND updated_at < NOW() - INTERVAL '30 days';
|
||||
|
||||
|
||||
-- ============================================================================
|
||||
-- FUNCTIONS
|
||||
-- ============================================================================
|
||||
|
||||
-- Function to upsert first signal snapshot
|
||||
CREATE OR REPLACE FUNCTION scheduler.upsert_first_signal_snapshot(
|
||||
p_job_id UUID,
|
||||
p_tenant_id UUID,
|
||||
p_run_id UUID,
|
||||
p_kind TEXT,
|
||||
p_phase TEXT,
|
||||
p_summary TEXT,
|
||||
p_eta_seconds INT DEFAULT NULL,
|
||||
p_last_known_outcome JSONB DEFAULT NULL,
|
||||
p_next_actions JSONB DEFAULT NULL,
|
||||
p_diagnostics JSONB DEFAULT '{}'
|
||||
)
|
||||
RETURNS scheduler.first_signal_snapshots AS $$
|
||||
DECLARE
|
||||
result scheduler.first_signal_snapshots;
|
||||
BEGIN
|
||||
INSERT INTO scheduler.first_signal_snapshots (
|
||||
job_id, tenant_id, run_id, kind, phase, summary,
|
||||
eta_seconds, last_known_outcome, next_actions, diagnostics
|
||||
)
|
||||
VALUES (
|
||||
p_job_id, p_tenant_id, p_run_id, p_kind, p_phase, p_summary,
|
||||
p_eta_seconds, p_last_known_outcome, p_next_actions, p_diagnostics
|
||||
)
|
||||
ON CONFLICT (job_id) DO UPDATE SET
|
||||
kind = EXCLUDED.kind,
|
||||
phase = EXCLUDED.phase,
|
||||
summary = EXCLUDED.summary,
|
||||
eta_seconds = EXCLUDED.eta_seconds,
|
||||
last_known_outcome = COALESCE(EXCLUDED.last_known_outcome, scheduler.first_signal_snapshots.last_known_outcome),
|
||||
next_actions = EXCLUDED.next_actions,
|
||||
diagnostics = EXCLUDED.diagnostics,
|
||||
updated_at = NOW()
|
||||
RETURNING * INTO result;
|
||||
|
||||
-- Notify listeners for real-time updates (air-gap mode)
|
||||
PERFORM pg_notify(
|
||||
'ttfs_signal_update',
|
||||
json_build_object(
|
||||
'job_id', p_job_id,
|
||||
'tenant_id', p_tenant_id,
|
||||
'kind', p_kind,
|
||||
'phase', p_phase
|
||||
)::text
|
||||
);
|
||||
|
||||
RETURN result;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
COMMENT ON FUNCTION scheduler.upsert_first_signal_snapshot IS 'Upsert signal snapshot with NOTIFY for air-gap real-time updates';
|
||||
|
||||
|
||||
-- Function to record TTFS event
|
||||
CREATE OR REPLACE FUNCTION scheduler.record_ttfs_event(
|
||||
p_tenant_id UUID,
|
||||
p_job_id UUID,
|
||||
p_surface TEXT,
|
||||
p_event_type TEXT,
|
||||
p_ttfs_ms INT,
|
||||
p_cache_hit BOOLEAN DEFAULT FALSE,
|
||||
p_signal_source TEXT DEFAULT NULL,
|
||||
p_kind TEXT DEFAULT NULL,
|
||||
p_phase TEXT DEFAULT NULL,
|
||||
p_run_id UUID DEFAULT NULL,
|
||||
p_correlation_id TEXT DEFAULT NULL,
|
||||
p_error_code TEXT DEFAULT NULL,
|
||||
p_metadata JSONB DEFAULT '{}'
|
||||
)
|
||||
RETURNS scheduler.ttfs_events AS $$
|
||||
DECLARE
|
||||
result scheduler.ttfs_events;
|
||||
BEGIN
|
||||
INSERT INTO scheduler.ttfs_events (
|
||||
tenant_id, job_id, run_id, surface, event_type, ttfs_ms,
|
||||
cache_hit, signal_source, kind, phase, correlation_id,
|
||||
error_code, metadata
|
||||
)
|
||||
VALUES (
|
||||
p_tenant_id, p_job_id, p_run_id, p_surface, p_event_type, p_ttfs_ms,
|
||||
p_cache_hit, p_signal_source, p_kind, p_phase, p_correlation_id,
|
||||
p_error_code, p_metadata
|
||||
)
|
||||
RETURNING * INTO result;
|
||||
|
||||
RETURN result;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
COMMENT ON FUNCTION scheduler.record_ttfs_event IS 'Record TTFS telemetry event for metrics and SLO analysis';
|
||||
|
||||
|
||||
-- Function to match failure signatures
|
||||
CREATE OR REPLACE FUNCTION scheduler.match_failure_signature(
|
||||
p_tenant_id UUID,
|
||||
p_phase TEXT,
|
||||
p_error_code TEXT,
|
||||
p_image_reference TEXT DEFAULT NULL
|
||||
)
|
||||
RETURNS TABLE (
|
||||
signature_id UUID,
|
||||
outcome JSONB,
|
||||
confidence NUMERIC
|
||||
) AS $$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
fs.id,
|
||||
fs.outcome,
|
||||
fs.confidence
|
||||
FROM scheduler.failure_signatures fs
|
||||
WHERE fs.tenant_id = p_tenant_id
|
||||
AND fs.enabled = TRUE
|
||||
AND (fs.expires_at IS NULL OR fs.expires_at > NOW())
|
||||
AND (fs.pattern->>'phase' IS NULL OR fs.pattern->>'phase' = p_phase)
|
||||
AND (fs.pattern->>'error_code' IS NULL OR fs.pattern->>'error_code' = p_error_code)
|
||||
AND (
|
||||
fs.pattern->>'image_pattern' IS NULL
|
||||
OR (p_image_reference IS NOT NULL AND p_image_reference ~ (fs.pattern->>'image_pattern'))
|
||||
)
|
||||
ORDER BY fs.confidence DESC, fs.sample_count DESC
|
||||
LIMIT 1;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
COMMENT ON FUNCTION scheduler.match_failure_signature IS 'Find best matching failure signature for predictive outcome';
|
||||
Reference in New Issue
Block a user