doctor enhancements, setup, enhancements, ui functionality and design consolidation and , test projects fixes , product advisory attestation/rekor and delta verfications enhancements

This commit is contained in:
master
2026-01-19 09:02:59 +02:00
parent 8c4bf54aed
commit 17419ba7c4
809 changed files with 170738 additions and 12244 deletions

View File

@@ -0,0 +1,139 @@
-- -----------------------------------------------------------------------------
-- V20260119_001__Add_UnderReview_Escalated_Rejected_States.sql
-- Sprint: SPRINT_20260118_018_Unknowns_queue_enhancement
-- Task: UQ-005 - Migration for existing entries (map to new states)
-- Description: Adds new state machine states and required columns
-- -----------------------------------------------------------------------------
-- Add new columns for UnderReview and Escalated states
ALTER TABLE grey_queue_entries
ADD COLUMN IF NOT EXISTS assignee VARCHAR(255) NULL,
ADD COLUMN IF NOT EXISTS assigned_at TIMESTAMPTZ NULL,
ADD COLUMN IF NOT EXISTS escalated_at TIMESTAMPTZ NULL,
ADD COLUMN IF NOT EXISTS escalation_reason TEXT NULL;
-- Add new enum values to grey_queue_status
-- Note: PostgreSQL requires special handling for enum additions
-- First, check if we need to add the values (idempotent)
DO $$
BEGIN
-- Add 'under_review' if not exists
IF NOT EXISTS (
SELECT 1 FROM pg_enum
WHERE enumlabel = 'under_review'
AND enumtypid = 'grey_queue_status'::regtype
) THEN
ALTER TYPE grey_queue_status ADD VALUE 'under_review' AFTER 'retrying';
END IF;
-- Add 'escalated' if not exists
IF NOT EXISTS (
SELECT 1 FROM pg_enum
WHERE enumlabel = 'escalated'
AND enumtypid = 'grey_queue_status'::regtype
) THEN
ALTER TYPE grey_queue_status ADD VALUE 'escalated' AFTER 'under_review';
END IF;
-- Add 'rejected' if not exists
IF NOT EXISTS (
SELECT 1 FROM pg_enum
WHERE enumlabel = 'rejected'
AND enumtypid = 'grey_queue_status'::regtype
) THEN
ALTER TYPE grey_queue_status ADD VALUE 'rejected' AFTER 'resolved';
END IF;
EXCEPTION
WHEN others THEN
-- Enum values may already exist, which is fine
NULL;
END $$;
-- Add indexes for new query patterns
CREATE INDEX IF NOT EXISTS idx_grey_queue_assignee
ON grey_queue_entries(assignee)
WHERE assignee IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_grey_queue_status_assignee
ON grey_queue_entries(status, assignee)
WHERE status IN ('under_review', 'escalated');
CREATE INDEX IF NOT EXISTS idx_grey_queue_escalated_at
ON grey_queue_entries(escalated_at DESC)
WHERE escalated_at IS NOT NULL;
-- Add audit trigger for state transitions
CREATE TABLE IF NOT EXISTS grey_queue_state_transitions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
entry_id UUID NOT NULL REFERENCES grey_queue_entries(id),
tenant_id VARCHAR(128) NOT NULL,
from_state VARCHAR(32) NOT NULL,
to_state VARCHAR(32) NOT NULL,
transitioned_by VARCHAR(255),
reason TEXT,
transitioned_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
metadata JSONB
);
CREATE INDEX IF NOT EXISTS idx_grey_queue_transitions_entry
ON grey_queue_state_transitions(entry_id);
CREATE INDEX IF NOT EXISTS idx_grey_queue_transitions_tenant_time
ON grey_queue_state_transitions(tenant_id, transitioned_at DESC);
-- Function to record state transitions
CREATE OR REPLACE FUNCTION record_grey_queue_transition()
RETURNS TRIGGER AS $$
BEGIN
IF OLD.status IS DISTINCT FROM NEW.status THEN
INSERT INTO grey_queue_state_transitions (
entry_id, tenant_id, from_state, to_state,
transitioned_by, transitioned_at
) VALUES (
NEW.id,
NEW.tenant_id,
OLD.status::text,
NEW.status::text,
COALESCE(NEW.assignee, current_user),
NOW()
);
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Create trigger if not exists
DROP TRIGGER IF EXISTS trg_grey_queue_state_transition ON grey_queue_entries;
CREATE TRIGGER trg_grey_queue_state_transition
AFTER UPDATE ON grey_queue_entries
FOR EACH ROW
EXECUTE FUNCTION record_grey_queue_transition();
-- Update summary view to include new states
CREATE OR REPLACE VIEW grey_queue_summary AS
SELECT
tenant_id,
COUNT(*) FILTER (WHERE status = 'pending') as pending_count,
COUNT(*) FILTER (WHERE status = 'processing') as processing_count,
COUNT(*) FILTER (WHERE status = 'retrying') as retrying_count,
COUNT(*) FILTER (WHERE status = 'under_review') as under_review_count,
COUNT(*) FILTER (WHERE status = 'escalated') as escalated_count,
COUNT(*) FILTER (WHERE status = 'resolved') as resolved_count,
COUNT(*) FILTER (WHERE status = 'rejected') as rejected_count,
COUNT(*) FILTER (WHERE status = 'failed') as failed_count,
COUNT(*) FILTER (WHERE status = 'expired') as expired_count,
COUNT(*) FILTER (WHERE status = 'dismissed') as dismissed_count,
COUNT(*) as total_count
FROM grey_queue_entries
GROUP BY tenant_id;
-- Comment for documentation
COMMENT ON COLUMN grey_queue_entries.assignee IS
'Assignee for entries in UnderReview state (Sprint UQ-005)';
COMMENT ON COLUMN grey_queue_entries.assigned_at IS
'When the entry was assigned for review (Sprint UQ-005)';
COMMENT ON COLUMN grey_queue_entries.escalated_at IS
'When the entry was escalated to security team (Sprint UQ-005)';
COMMENT ON COLUMN grey_queue_entries.escalation_reason IS
'Reason for escalation (Sprint UQ-005)';

View File

@@ -0,0 +1,130 @@
-- Migration: Add diff_id column to scanner layers table
-- Sprint: SPRINT_025_Scanner_layer_manifest_infrastructure
-- Task: TASK-025-03
-- Add diff_id column to layers table (sha256:64hex = 71 chars)
ALTER TABLE scanner.layers
ADD COLUMN IF NOT EXISTS diff_id VARCHAR(71);
-- Add timestamp for when diffID was computed
ALTER TABLE scanner.layers
ADD COLUMN IF NOT EXISTS diff_id_computed_at_utc TIMESTAMP;
-- Create index on diff_id for fast lookups
CREATE INDEX IF NOT EXISTS idx_layers_diff_id
ON scanner.layers (diff_id)
WHERE diff_id IS NOT NULL;
-- Create image_layers junction table if it doesn't exist
-- This tracks which layers belong to which images
CREATE TABLE IF NOT EXISTS scanner.image_layers (
image_reference VARCHAR(512) NOT NULL,
layer_digest VARCHAR(71) NOT NULL,
layer_index INT NOT NULL,
created_at_utc TIMESTAMP NOT NULL DEFAULT NOW(),
PRIMARY KEY (image_reference, layer_digest)
);
CREATE INDEX IF NOT EXISTS idx_image_layers_digest
ON scanner.image_layers (layer_digest);
-- DiffID cache table for resolved diffIDs
CREATE TABLE IF NOT EXISTS scanner.scanner_diffid_cache (
layer_digest VARCHAR(71) PRIMARY KEY,
diff_id VARCHAR(71) NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Base image fingerprint tables for layer reuse detection
CREATE TABLE IF NOT EXISTS scanner.scanner_base_image_fingerprints (
image_reference VARCHAR(512) PRIMARY KEY,
layer_count INT NOT NULL,
registered_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
detection_count BIGINT NOT NULL DEFAULT 0
);
CREATE TABLE IF NOT EXISTS scanner.scanner_base_image_layers (
image_reference VARCHAR(512) NOT NULL REFERENCES scanner.scanner_base_image_fingerprints(image_reference) ON DELETE CASCADE,
layer_index INT NOT NULL,
diff_id VARCHAR(71) NOT NULL,
PRIMARY KEY (image_reference, layer_index)
);
CREATE INDEX IF NOT EXISTS idx_base_image_layers_diff_id
ON scanner.scanner_base_image_layers (diff_id);
-- Manifest snapshots table for IOciManifestSnapshotService
CREATE TABLE IF NOT EXISTS scanner.manifest_snapshots (
id UUID PRIMARY KEY,
image_reference VARCHAR(512) NOT NULL,
registry VARCHAR(256) NOT NULL,
repository VARCHAR(256) NOT NULL,
tag VARCHAR(128),
manifest_digest VARCHAR(71) NOT NULL,
config_digest VARCHAR(71) NOT NULL,
media_type VARCHAR(128) NOT NULL,
layers JSONB NOT NULL,
diff_ids JSONB NOT NULL,
platform JSONB,
total_size BIGINT NOT NULL,
captured_at TIMESTAMPTZ NOT NULL,
snapshot_version VARCHAR(32),
UNIQUE (manifest_digest)
);
CREATE INDEX IF NOT EXISTS idx_manifest_snapshots_image_ref
ON scanner.manifest_snapshots (image_reference);
CREATE INDEX IF NOT EXISTS idx_manifest_snapshots_repository
ON scanner.manifest_snapshots (registry, repository);
CREATE INDEX IF NOT EXISTS idx_manifest_snapshots_captured_at
ON scanner.manifest_snapshots (captured_at DESC);
-- Layer scan history for reuse detection (TASK-025-04)
CREATE TABLE IF NOT EXISTS scanner.layer_scans (
diff_id VARCHAR(71) PRIMARY KEY,
scanned_at TIMESTAMPTZ NOT NULL,
finding_count INT,
scanned_by VARCHAR(128) NOT NULL,
scanner_version VARCHAR(64)
);
-- Layer reuse counts for statistics
CREATE TABLE IF NOT EXISTS scanner.layer_reuse_counts (
diff_id VARCHAR(71) PRIMARY KEY,
reuse_count INT NOT NULL DEFAULT 1,
first_seen_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
CREATE INDEX IF NOT EXISTS idx_layer_reuse_counts_count
ON scanner.layer_reuse_counts (reuse_count DESC);
COMMENT ON COLUMN scanner.layers.diff_id IS 'Uncompressed layer content hash (sha256:hex64). Immutable once computed.';
COMMENT ON TABLE scanner.scanner_diffid_cache IS 'Cache of layer digest to diffID mappings. Layer digests are immutable so cache entries never expire.';
COMMENT ON TABLE scanner.scanner_base_image_fingerprints IS 'Known base image fingerprints for layer reuse detection.';
COMMENT ON TABLE scanner.manifest_snapshots IS 'Point-in-time captures of OCI image manifests for delta scanning.';
COMMENT ON TABLE scanner.layer_scans IS 'History of layer scans for deduplication. One entry per diffID.';
COMMENT ON TABLE scanner.layer_reuse_counts IS 'Counts of how many times each layer appears across images.';
-- Layer SBOM CAS for per-layer SBOM storage (TASK-026-02)
CREATE TABLE IF NOT EXISTS scanner.layer_sbom_cas (
diff_id VARCHAR(71) NOT NULL,
format VARCHAR(20) NOT NULL,
content BYTEA NOT NULL,
size_bytes BIGINT NOT NULL,
compressed BOOLEAN NOT NULL DEFAULT TRUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
last_accessed_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
PRIMARY KEY (diff_id, format)
);
CREATE INDEX IF NOT EXISTS idx_layer_sbom_cas_last_accessed
ON scanner.layer_sbom_cas (last_accessed_at);
CREATE INDEX IF NOT EXISTS idx_layer_sbom_cas_format
ON scanner.layer_sbom_cas (format);
COMMENT ON TABLE scanner.layer_sbom_cas IS 'Content-addressable storage for per-layer SBOMs. Keyed by diffID (immutable).';
COMMENT ON COLUMN scanner.layer_sbom_cas.content IS 'Compressed (gzip) SBOM content.';
COMMENT ON COLUMN scanner.layer_sbom_cas.last_accessed_at IS 'For TTL-based eviction of cold entries.';