Fix build and code structure improvements. New but essential UI functionality. CI improvements. Documentation improvements. AI module improvements.

This commit is contained in:
StellaOps Bot
2025-12-26 21:54:17 +02:00
parent 335ff7da16
commit c2b9cd8d1f
3717 changed files with 264714 additions and 48202 deletions

View File

@@ -0,0 +1,319 @@
-- SBOM Lineage Graph Database Schema
-- Version: 1.0.0
-- Created: 2025-12-28
-- ============================================================================
-- TABLE: sbom_lineage_edges
-- Purpose: Stores relationships between SBOM versions (parent/child, build, base)
-- ============================================================================
CREATE TABLE IF NOT EXISTS sbom_lineage_edges (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
-- Edge endpoints (using artifact digest as stable identifier)
parent_digest TEXT NOT NULL,
child_digest TEXT NOT NULL,
-- Relationship type
relationship TEXT NOT NULL CHECK (relationship IN ('parent', 'build', 'base')),
-- Tenant isolation
tenant_id UUID NOT NULL,
-- Audit
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
-- Prevent duplicate edges
CONSTRAINT uq_lineage_edge UNIQUE (parent_digest, child_digest, tenant_id)
);
-- Index for traversing from parent to children
CREATE INDEX IF NOT EXISTS idx_lineage_edges_parent
ON sbom_lineage_edges(parent_digest, tenant_id);
-- Index for traversing from child to parents
CREATE INDEX IF NOT EXISTS idx_lineage_edges_child
ON sbom_lineage_edges(child_digest, tenant_id);
-- Index for time-based queries
CREATE INDEX IF NOT EXISTS idx_lineage_edges_created
ON sbom_lineage_edges(tenant_id, created_at DESC);
-- Index for relationship filtering
CREATE INDEX IF NOT EXISTS idx_lineage_edges_relationship
ON sbom_lineage_edges(tenant_id, relationship);
COMMENT ON TABLE sbom_lineage_edges IS 'Stores directed edges between SBOM versions representing lineage relationships';
COMMENT ON COLUMN sbom_lineage_edges.parent_digest IS 'SHA256 digest of parent artifact';
COMMENT ON COLUMN sbom_lineage_edges.child_digest IS 'SHA256 digest of child artifact';
COMMENT ON COLUMN sbom_lineage_edges.relationship IS 'Type of relationship: parent (version succession), build (same CI build), base (FROM instruction)';
-- ============================================================================
-- TABLE: vex_deltas
-- Purpose: Tracks VEX status changes between artifact versions
-- ============================================================================
CREATE TABLE IF NOT EXISTS vex_deltas (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
-- Artifact pair
from_artifact_digest TEXT NOT NULL,
to_artifact_digest TEXT NOT NULL,
-- Vulnerability
cve TEXT NOT NULL,
-- Status transition
from_status TEXT NOT NULL,
to_status TEXT NOT NULL,
-- Explanation
rationale JSONB NOT NULL DEFAULT '{}',
-- Determinism
replay_hash TEXT NOT NULL,
-- Signed attestation reference (if signed)
attestation_digest TEXT,
-- Tenant isolation
tenant_id UUID NOT NULL,
-- Audit
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
-- Prevent duplicate deltas
CONSTRAINT uq_vex_delta UNIQUE (from_artifact_digest, to_artifact_digest, cve, tenant_id)
);
-- Index for querying deltas by target artifact
CREATE INDEX IF NOT EXISTS idx_vex_deltas_to
ON vex_deltas(to_artifact_digest, tenant_id);
-- Index for querying deltas by CVE
CREATE INDEX IF NOT EXISTS idx_vex_deltas_cve
ON vex_deltas(cve, tenant_id);
-- Index for time-based queries
CREATE INDEX IF NOT EXISTS idx_vex_deltas_created
ON vex_deltas(tenant_id, created_at DESC);
-- Index for finding status transitions
CREATE INDEX IF NOT EXISTS idx_vex_deltas_status
ON vex_deltas(tenant_id, from_status, to_status);
-- GIN index for rationale JSON queries
CREATE INDEX IF NOT EXISTS idx_vex_deltas_rationale
ON vex_deltas USING GIN (rationale);
COMMENT ON TABLE vex_deltas IS 'Tracks VEX status changes between artifact versions with rationale';
COMMENT ON COLUMN vex_deltas.rationale IS 'JSON object with reason, evidenceLink, and metadata';
COMMENT ON COLUMN vex_deltas.replay_hash IS 'SHA256 hash of inputs for deterministic replay verification';
COMMENT ON COLUMN vex_deltas.attestation_digest IS 'SHA256 digest of signed delta verdict attestation';
-- ============================================================================
-- TABLE: sbom_verdict_links
-- Purpose: Links SBOM versions to VEX consensus decisions
-- ============================================================================
CREATE TABLE IF NOT EXISTS sbom_verdict_links (
-- SBOM version reference
sbom_version_id UUID NOT NULL,
-- Vulnerability
cve TEXT NOT NULL,
-- Consensus reference
consensus_projection_id UUID NOT NULL,
-- Verdict snapshot
verdict_status TEXT NOT NULL,
confidence_score DECIMAL(5,4) NOT NULL CHECK (confidence_score >= 0 AND confidence_score <= 1),
-- Tenant isolation
tenant_id UUID NOT NULL,
-- Audit
linked_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
-- Composite primary key
PRIMARY KEY (sbom_version_id, cve, tenant_id)
);
-- Index for querying by CVE
CREATE INDEX IF NOT EXISTS idx_verdict_links_cve
ON sbom_verdict_links(cve, tenant_id);
-- Index for querying by consensus projection
CREATE INDEX IF NOT EXISTS idx_verdict_links_projection
ON sbom_verdict_links(consensus_projection_id);
-- Index for time-based queries
CREATE INDEX IF NOT EXISTS idx_verdict_links_linked
ON sbom_verdict_links(tenant_id, linked_at DESC);
-- Index for finding specific statuses
CREATE INDEX IF NOT EXISTS idx_verdict_links_status
ON sbom_verdict_links(tenant_id, verdict_status);
COMMENT ON TABLE sbom_verdict_links IS 'Links SBOM versions to VEX consensus decisions for traceability';
COMMENT ON COLUMN sbom_verdict_links.confidence_score IS 'Consensus confidence score (0.0-1.0)';
-- ============================================================================
-- TABLE: vex_consensus_projections (migrated from in-memory VexLens)
-- Purpose: Persistent storage for VEX consensus projections
-- ============================================================================
CREATE TABLE IF NOT EXISTS vex_consensus_projections (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
-- Target
vulnerability_id TEXT NOT NULL,
product_key TEXT NOT NULL,
-- Tenant isolation
tenant_id UUID NOT NULL,
-- Consensus result
status TEXT NOT NULL,
confidence_score DECIMAL(5,4) NOT NULL CHECK (confidence_score >= 0 AND confidence_score <= 1),
outcome TEXT NOT NULL,
-- Statistics
statement_count INT NOT NULL DEFAULT 0,
conflict_count INT NOT NULL DEFAULT 0,
-- Timestamps
computed_at TIMESTAMPTZ NOT NULL,
stored_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
-- History linkage
previous_projection_id UUID REFERENCES vex_consensus_projections(id),
status_changed BOOLEAN NOT NULL DEFAULT FALSE
);
-- Unique constraint for latest projection per (vuln, product, tenant, time)
CREATE UNIQUE INDEX IF NOT EXISTS idx_consensus_unique
ON vex_consensus_projections(tenant_id, vulnerability_id, product_key, computed_at);
-- Index for finding status changes
CREATE INDEX IF NOT EXISTS idx_consensus_status_changed
ON vex_consensus_projections(tenant_id, status_changed, computed_at DESC)
WHERE status_changed = TRUE;
-- Index for history traversal
CREATE INDEX IF NOT EXISTS idx_consensus_previous
ON vex_consensus_projections(previous_projection_id)
WHERE previous_projection_id IS NOT NULL;
-- Index for product queries
CREATE INDEX IF NOT EXISTS idx_consensus_product
ON vex_consensus_projections(product_key, tenant_id);
COMMENT ON TABLE vex_consensus_projections IS 'Persistent VEX consensus projections with full history';
COMMENT ON COLUMN vex_consensus_projections.outcome IS 'Consensus outcome: Unanimous, Majority, Plurality, ConflictResolved, NoData';
COMMENT ON COLUMN vex_consensus_projections.status_changed IS 'True if status differs from previous projection';
-- ============================================================================
-- EXTENSION: Add replay_hash to sbom_snapshots (alter existing table)
-- ============================================================================
-- Note: This ALTER should be applied to existing sbom_snapshots table
-- ALTER TABLE sbom_snapshots ADD COLUMN IF NOT EXISTS replay_hash TEXT;
-- CREATE INDEX IF NOT EXISTS idx_sbom_snapshots_replay ON sbom_snapshots(replay_hash) WHERE replay_hash IS NOT NULL;
-- ============================================================================
-- FUNCTIONS: Helper functions for lineage queries
-- ============================================================================
-- Function to get lineage depth from a starting node
CREATE OR REPLACE FUNCTION get_lineage_depth(
p_artifact_digest TEXT,
p_tenant_id UUID,
p_max_depth INT DEFAULT 10
) RETURNS INT AS $$
DECLARE
v_depth INT := 0;
v_current_count INT;
BEGIN
WITH RECURSIVE lineage AS (
SELECT child_digest, 1 as depth
FROM sbom_lineage_edges
WHERE parent_digest = p_artifact_digest AND tenant_id = p_tenant_id
UNION ALL
SELECT e.child_digest, l.depth + 1
FROM sbom_lineage_edges e
JOIN lineage l ON e.parent_digest = l.child_digest
WHERE e.tenant_id = p_tenant_id AND l.depth < p_max_depth
)
SELECT COALESCE(MAX(depth), 0) INTO v_depth FROM lineage;
RETURN v_depth;
END;
$$ LANGUAGE plpgsql STABLE;
-- Function to get all ancestors of an artifact
CREATE OR REPLACE FUNCTION get_ancestors(
p_artifact_digest TEXT,
p_tenant_id UUID,
p_max_depth INT DEFAULT 10
) RETURNS TABLE (
ancestor_digest TEXT,
depth INT,
relationship TEXT
) AS $$
BEGIN
RETURN QUERY
WITH RECURSIVE ancestors AS (
SELECT parent_digest, 1 as depth, e.relationship
FROM sbom_lineage_edges e
WHERE child_digest = p_artifact_digest AND tenant_id = p_tenant_id
UNION ALL
SELECT e.parent_digest, a.depth + 1, e.relationship
FROM sbom_lineage_edges e
JOIN ancestors a ON e.child_digest = a.parent_digest
WHERE e.tenant_id = p_tenant_id AND a.depth < p_max_depth
)
SELECT parent_digest, ancestors.depth, ancestors.relationship
FROM ancestors
ORDER BY depth, parent_digest;
END;
$$ LANGUAGE plpgsql STABLE;
-- Function to get all descendants of an artifact
CREATE OR REPLACE FUNCTION get_descendants(
p_artifact_digest TEXT,
p_tenant_id UUID,
p_max_depth INT DEFAULT 10
) RETURNS TABLE (
descendant_digest TEXT,
depth INT,
relationship TEXT
) AS $$
BEGIN
RETURN QUERY
WITH RECURSIVE descendants AS (
SELECT child_digest, 1 as depth, e.relationship
FROM sbom_lineage_edges e
WHERE parent_digest = p_artifact_digest AND tenant_id = p_tenant_id
UNION ALL
SELECT e.child_digest, d.depth + 1, e.relationship
FROM sbom_lineage_edges e
JOIN descendants d ON e.parent_digest = d.child_digest
WHERE e.tenant_id = p_tenant_id AND d.depth < p_max_depth
)
SELECT child_digest, descendants.depth, descendants.relationship
FROM descendants
ORDER BY depth, child_digest;
END;
$$ LANGUAGE plpgsql STABLE;
COMMENT ON FUNCTION get_lineage_depth IS 'Returns the maximum depth of descendants from an artifact';
COMMENT ON FUNCTION get_ancestors IS 'Returns all ancestor artifacts up to max_depth';
COMMENT ON FUNCTION get_descendants IS 'Returns all descendant artifacts up to max_depth';