tests fixes and sprints work

This commit is contained in:
master
2026-01-22 19:08:46 +02:00
parent c32fff8f86
commit 726d70dc7f
881 changed files with 134434 additions and 6228 deletions

View File

@@ -295,6 +295,7 @@ CREATE TABLE IF NOT EXISTS analytics.artifacts (
CREATE INDEX IF NOT EXISTS ix_artifacts_name_version ON analytics.artifacts (name, version);
CREATE INDEX IF NOT EXISTS ix_artifacts_environment ON analytics.artifacts (environment);
CREATE INDEX IF NOT EXISTS ix_artifacts_environment_name ON analytics.artifacts (environment, name);
CREATE INDEX IF NOT EXISTS ix_artifacts_team ON analytics.artifacts (team);
CREATE INDEX IF NOT EXISTS ix_artifacts_deployed ON analytics.artifacts (deployed_at DESC);
CREATE INDEX IF NOT EXISTS ix_artifacts_digest ON analytics.artifacts (digest);
@@ -368,6 +369,7 @@ CREATE INDEX IF NOT EXISTS ix_component_vulns_severity ON analytics.component_vu
CREATE INDEX IF NOT EXISTS ix_component_vulns_fixable ON analytics.component_vulns (fix_available) WHERE fix_available = TRUE;
CREATE INDEX IF NOT EXISTS ix_component_vulns_kev ON analytics.component_vulns (kev_listed) WHERE kev_listed = TRUE;
CREATE INDEX IF NOT EXISTS ix_component_vulns_epss ON analytics.component_vulns (epss_score DESC) WHERE epss_score IS NOT NULL;
CREATE INDEX IF NOT EXISTS ix_component_vulns_published ON analytics.component_vulns (published_at DESC) WHERE published_at IS NOT NULL;
COMMENT ON TABLE analytics.component_vulns IS 'Component-to-vulnerability mapping with severity and remediation data';
@@ -416,6 +418,7 @@ CREATE TABLE IF NOT EXISTS analytics.attestations (
CREATE INDEX IF NOT EXISTS ix_attestations_artifact ON analytics.attestations (artifact_id);
CREATE INDEX IF NOT EXISTS ix_attestations_type ON analytics.attestations (predicate_type);
CREATE INDEX IF NOT EXISTS ix_attestations_artifact_type ON analytics.attestations (artifact_id, predicate_type);
CREATE INDEX IF NOT EXISTS ix_attestations_issuer ON analytics.attestations (issuer_normalized);
CREATE INDEX IF NOT EXISTS ix_attestations_rekor ON analytics.attestations (rekor_log_id) WHERE rekor_log_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS ix_attestations_slsa ON analytics.attestations (slsa_level) WHERE slsa_level IS NOT NULL;
@@ -461,8 +464,10 @@ CREATE TABLE IF NOT EXISTS analytics.vex_overrides (
CREATE INDEX IF NOT EXISTS ix_vex_overrides_artifact_vuln ON analytics.vex_overrides (artifact_id, vuln_id);
CREATE INDEX IF NOT EXISTS ix_vex_overrides_vuln ON analytics.vex_overrides (vuln_id);
CREATE INDEX IF NOT EXISTS ix_vex_overrides_status ON analytics.vex_overrides (status);
CREATE INDEX IF NOT EXISTS ix_vex_overrides_active ON analytics.vex_overrides (artifact_id, vuln_id)
WHERE valid_until IS NULL OR valid_until > now();
CREATE INDEX IF NOT EXISTS ix_vex_overrides_active ON analytics.vex_overrides (artifact_id, vuln_id, valid_from, valid_until)
WHERE status = 'not_affected';
CREATE INDEX IF NOT EXISTS ix_vex_overrides_vuln_active ON analytics.vex_overrides (vuln_id, valid_from, valid_until)
WHERE status = 'not_affected';
COMMENT ON TABLE analytics.vex_overrides IS 'VEX status overrides with justifications and validity periods';
@@ -570,6 +575,7 @@ CREATE TABLE IF NOT EXISTS analytics.daily_component_counts (
);
CREATE INDEX IF NOT EXISTS ix_daily_comp_counts_date ON analytics.daily_component_counts (snapshot_date DESC);
CREATE INDEX IF NOT EXISTS ix_daily_comp_counts_env ON analytics.daily_component_counts (environment, snapshot_date DESC);
COMMENT ON TABLE analytics.daily_component_counts IS 'Daily component count rollups by license and type';
@@ -584,7 +590,7 @@ SELECT
COUNT(DISTINCT c.component_id) AS component_count,
COUNT(DISTINCT ac.artifact_id) AS artifact_count,
COUNT(DISTINCT a.team) AS team_count,
ARRAY_AGG(DISTINCT a.environment) FILTER (WHERE a.environment IS NOT NULL) AS environments,
ARRAY_AGG(DISTINCT a.environment ORDER BY a.environment) FILTER (WHERE a.environment IS NOT NULL) AS environments,
SUM(CASE WHEN cv.severity = 'critical' THEN 1 ELSE 0 END) AS critical_vuln_count,
SUM(CASE WHEN cv.severity = 'high' THEN 1 ELSE 0 END) AS high_vuln_count,
MAX(c.last_seen_at) AS last_seen_at
@@ -598,6 +604,8 @@ WITH DATA;
CREATE UNIQUE INDEX IF NOT EXISTS ix_mv_supplier_concentration_supplier
ON analytics.mv_supplier_concentration (supplier);
CREATE INDEX IF NOT EXISTS ix_mv_supplier_concentration_component_count
ON analytics.mv_supplier_concentration (component_count DESC);
COMMENT ON MATERIALIZED VIEW analytics.mv_supplier_concentration IS 'Pre-computed supplier concentration metrics';
@@ -608,7 +616,7 @@ SELECT
c.license_category,
COUNT(*) AS component_count,
COUNT(DISTINCT ac.artifact_id) AS artifact_count,
ARRAY_AGG(DISTINCT c.purl_type) FILTER (WHERE c.purl_type IS NOT NULL) AS ecosystems
ARRAY_AGG(DISTINCT c.purl_type ORDER BY c.purl_type) FILTER (WHERE c.purl_type IS NOT NULL) AS ecosystems
FROM analytics.components c
LEFT JOIN analytics.artifact_components ac ON ac.component_id = c.component_id
GROUP BY c.license_concluded, c.license_category
@@ -616,6 +624,8 @@ WITH DATA;
CREATE UNIQUE INDEX IF NOT EXISTS ix_mv_license_distribution_license
ON analytics.mv_license_distribution (COALESCE(license_concluded, ''), license_category);
CREATE INDEX IF NOT EXISTS ix_mv_license_distribution_component_count
ON analytics.mv_license_distribution (component_count DESC);
COMMENT ON MATERIALIZED VIEW analytics.mv_license_distribution IS 'Pre-computed license distribution metrics';
@@ -636,6 +646,7 @@ SELECT
WHERE vo.artifact_id = ac.artifact_id
AND vo.vuln_id = cv.vuln_id
AND vo.status = 'not_affected'
AND vo.valid_from <= now()
AND (vo.valid_until IS NULL OR vo.valid_until > now())
)
) AS effective_component_count,
@@ -645,6 +656,7 @@ SELECT
WHERE vo.artifact_id = ac.artifact_id
AND vo.vuln_id = cv.vuln_id
AND vo.status = 'not_affected'
AND vo.valid_from <= now()
AND (vo.valid_until IS NULL OR vo.valid_until > now())
)
) AS effective_artifact_count
@@ -654,8 +666,10 @@ WHERE cv.affects = TRUE
GROUP BY cv.vuln_id, cv.severity, cv.cvss_score, cv.epss_score, cv.kev_listed, cv.fix_available
WITH DATA;
CREATE UNIQUE INDEX IF NOT EXISTS ix_mv_vuln_exposure_vuln
ON analytics.mv_vuln_exposure (vuln_id);
CREATE UNIQUE INDEX IF NOT EXISTS ix_mv_vuln_exposure_key
ON analytics.mv_vuln_exposure (vuln_id, severity, cvss_score, epss_score, kev_listed, fix_available);
CREATE INDEX IF NOT EXISTS ix_mv_vuln_exposure_severity_count
ON analytics.mv_vuln_exposure (severity, effective_artifact_count DESC);
COMMENT ON MATERIALIZED VIEW analytics.mv_vuln_exposure IS 'CVE exposure with VEX-adjusted impact counts';
@@ -684,6 +698,8 @@ WITH DATA;
CREATE UNIQUE INDEX IF NOT EXISTS ix_mv_attestation_coverage_env_team
ON analytics.mv_attestation_coverage (COALESCE(environment, ''), COALESCE(team, ''));
CREATE INDEX IF NOT EXISTS ix_mv_attestation_coverage_provenance
ON analytics.mv_attestation_coverage (provenance_pct ASC);
COMMENT ON MATERIALIZED VIEW analytics.mv_attestation_coverage IS 'Attestation coverage percentages by environment and team';
@@ -692,22 +708,53 @@ COMMENT ON MATERIALIZED VIEW analytics.mv_attestation_coverage IS 'Attestation c
-- =============================================================================
-- Top suppliers by component count
CREATE OR REPLACE FUNCTION analytics.sp_top_suppliers(p_limit INT DEFAULT 20)
CREATE OR REPLACE FUNCTION analytics.sp_top_suppliers(
p_limit INT DEFAULT 20,
p_environment TEXT DEFAULT NULL
)
RETURNS JSON AS $$
DECLARE
env TEXT;
BEGIN
env := NULLIF(BTRIM(p_environment), '');
IF env IS NULL THEN
RETURN (
SELECT json_agg(row_to_json(t))
FROM (
SELECT
supplier,
component_count,
artifact_count,
team_count,
critical_vuln_count,
high_vuln_count,
environments
FROM analytics.mv_supplier_concentration
ORDER BY component_count DESC, supplier ASC
LIMIT p_limit
) t
);
END IF;
RETURN (
SELECT json_agg(row_to_json(t))
FROM (
SELECT
supplier,
component_count,
artifact_count,
team_count,
critical_vuln_count,
high_vuln_count,
environments
FROM analytics.mv_supplier_concentration
ORDER BY component_count DESC
c.supplier_normalized AS supplier,
COUNT(DISTINCT c.component_id) AS component_count,
COUNT(DISTINCT ac.artifact_id) AS artifact_count,
COUNT(DISTINCT a.team) AS team_count,
ARRAY_AGG(DISTINCT a.environment ORDER BY a.environment) FILTER (WHERE a.environment IS NOT NULL) AS environments,
SUM(CASE WHEN cv.severity = 'critical' THEN 1 ELSE 0 END) AS critical_vuln_count,
SUM(CASE WHEN cv.severity = 'high' THEN 1 ELSE 0 END) AS high_vuln_count
FROM analytics.components c
JOIN analytics.artifact_components ac ON ac.component_id = c.component_id
JOIN analytics.artifacts a ON a.artifact_id = ac.artifact_id
LEFT JOIN analytics.component_vulns cv ON cv.component_id = c.component_id AND cv.affects = TRUE
WHERE c.supplier_normalized IS NOT NULL
AND a.environment = env
GROUP BY c.supplier_normalized
ORDER BY component_count DESC, supplier ASC
LIMIT p_limit
) t
);
@@ -717,20 +764,43 @@ $$ LANGUAGE plpgsql STABLE;
COMMENT ON FUNCTION analytics.sp_top_suppliers IS 'Get top suppliers by component count for supply chain risk analysis';
-- License distribution heatmap
CREATE OR REPLACE FUNCTION analytics.sp_license_heatmap()
CREATE OR REPLACE FUNCTION analytics.sp_license_heatmap(p_environment TEXT DEFAULT NULL)
RETURNS JSON AS $$
DECLARE
env TEXT;
BEGIN
env := NULLIF(BTRIM(p_environment), '');
IF env IS NULL THEN
RETURN (
SELECT json_agg(row_to_json(t))
FROM (
SELECT
license_category,
license_concluded,
component_count,
artifact_count,
ecosystems
FROM analytics.mv_license_distribution
ORDER BY component_count DESC, license_category, COALESCE(license_concluded, '')
) t
);
END IF;
RETURN (
SELECT json_agg(row_to_json(t))
FROM (
SELECT
license_category,
license_concluded,
component_count,
artifact_count,
ecosystems
FROM analytics.mv_license_distribution
ORDER BY component_count DESC
c.license_category,
c.license_concluded,
COUNT(*) AS component_count,
COUNT(DISTINCT ac.artifact_id) AS artifact_count,
ARRAY_AGG(DISTINCT c.purl_type ORDER BY c.purl_type) FILTER (WHERE c.purl_type IS NOT NULL) AS ecosystems
FROM analytics.components c
JOIN analytics.artifact_components ac ON ac.component_id = c.component_id
JOIN analytics.artifacts a ON a.artifact_id = ac.artifact_id
WHERE a.environment = env
GROUP BY c.license_concluded, c.license_category
ORDER BY component_count DESC, license_category, COALESCE(c.license_concluded, '')
) t
);
END;
@@ -744,7 +814,62 @@ CREATE OR REPLACE FUNCTION analytics.sp_vuln_exposure(
p_min_severity TEXT DEFAULT 'low'
)
RETURNS JSON AS $$
DECLARE
min_rank INT;
env TEXT;
BEGIN
env := NULLIF(BTRIM(p_environment), '');
min_rank := CASE LOWER(COALESCE(NULLIF(p_min_severity, ''), 'low'))
WHEN 'critical' THEN 1
WHEN 'high' THEN 2
WHEN 'medium' THEN 3
WHEN 'low' THEN 4
WHEN 'none' THEN 5
ELSE 6
END;
IF env IS NULL THEN
RETURN (
SELECT json_agg(row_to_json(t))
FROM (
SELECT
vuln_id,
severity::TEXT,
cvss_score,
epss_score,
kev_listed,
fix_available,
raw_component_count,
raw_artifact_count,
effective_component_count,
effective_artifact_count,
raw_artifact_count - effective_artifact_count AS vex_mitigated
FROM analytics.mv_vuln_exposure
WHERE effective_artifact_count > 0
AND CASE severity
WHEN 'critical' THEN 1
WHEN 'high' THEN 2
WHEN 'medium' THEN 3
WHEN 'low' THEN 4
WHEN 'none' THEN 5
ELSE 6
END <= min_rank
ORDER BY
CASE severity
WHEN 'critical' THEN 1
WHEN 'high' THEN 2
WHEN 'medium' THEN 3
WHEN 'low' THEN 4
WHEN 'none' THEN 5
ELSE 6
END,
effective_artifact_count DESC,
vuln_id
LIMIT 50
) t
);
END IF;
RETURN (
SELECT json_agg(row_to_json(t))
FROM (
@@ -760,30 +885,79 @@ BEGIN
effective_component_count,
effective_artifact_count,
raw_artifact_count - effective_artifact_count AS vex_mitigated
FROM analytics.mv_vuln_exposure
FROM (
SELECT
cv.vuln_id,
cv.severity,
cv.cvss_score,
cv.epss_score,
cv.kev_listed,
cv.fix_available,
COUNT(DISTINCT cv.component_id) AS raw_component_count,
COUNT(DISTINCT ac.artifact_id) AS raw_artifact_count,
COUNT(DISTINCT cv.component_id) FILTER (
WHERE NOT EXISTS (
SELECT 1 FROM analytics.vex_overrides vo
WHERE vo.artifact_id = ac.artifact_id
AND vo.vuln_id = cv.vuln_id
AND vo.status = 'not_affected'
AND vo.valid_from <= now()
AND (vo.valid_until IS NULL OR vo.valid_until > now())
)
) AS effective_component_count,
COUNT(DISTINCT ac.artifact_id) FILTER (
WHERE NOT EXISTS (
SELECT 1 FROM analytics.vex_overrides vo
WHERE vo.artifact_id = ac.artifact_id
AND vo.vuln_id = cv.vuln_id
AND vo.status = 'not_affected'
AND vo.valid_from <= now()
AND (vo.valid_until IS NULL OR vo.valid_until > now())
)
) AS effective_artifact_count
FROM analytics.component_vulns cv
JOIN analytics.artifact_components ac ON ac.component_id = cv.component_id
JOIN analytics.artifacts a ON a.artifact_id = ac.artifact_id
WHERE cv.affects = TRUE
AND a.environment = env
GROUP BY cv.vuln_id, cv.severity, cv.cvss_score, cv.epss_score, cv.kev_listed, cv.fix_available
) exposure
WHERE effective_artifact_count > 0
AND severity::TEXT >= p_min_severity
AND CASE severity
WHEN 'critical' THEN 1
WHEN 'high' THEN 2
WHEN 'medium' THEN 3
WHEN 'low' THEN 4
WHEN 'none' THEN 5
ELSE 6
END <= min_rank
ORDER BY
CASE severity
WHEN 'critical' THEN 1
WHEN 'high' THEN 2
WHEN 'medium' THEN 3
WHEN 'low' THEN 4
ELSE 5
WHEN 'none' THEN 5
ELSE 6
END,
effective_artifact_count DESC
effective_artifact_count DESC,
vuln_id
LIMIT 50
) t
);
END;
$$ LANGUAGE plpgsql STABLE;
COMMENT ON FUNCTION analytics.sp_vuln_exposure IS 'Get CVE exposure with VEX-adjusted counts';
COMMENT ON FUNCTION analytics.sp_vuln_exposure IS
'Get CVE exposure with VEX-adjusted counts, optional environment filter, and severity threshold';
-- Fixable backlog
CREATE OR REPLACE FUNCTION analytics.sp_fixable_backlog(p_environment TEXT DEFAULT NULL)
RETURNS JSON AS $$
DECLARE
env TEXT;
BEGIN
env := NULLIF(BTRIM(p_environment), '');
RETURN (
SELECT json_agg(row_to_json(t))
FROM (
@@ -802,18 +976,22 @@ BEGIN
LEFT JOIN analytics.vex_overrides vo ON vo.artifact_id = a.artifact_id
AND vo.vuln_id = cv.vuln_id
AND vo.status = 'not_affected'
AND vo.valid_from <= now()
AND (vo.valid_until IS NULL OR vo.valid_until > now())
WHERE cv.affects = TRUE
AND cv.fix_available = TRUE
AND vo.override_id IS NULL
AND (p_environment IS NULL OR a.environment = p_environment)
AND (env IS NULL OR a.environment = env)
ORDER BY
CASE cv.severity
WHEN 'critical' THEN 1
WHEN 'high' THEN 2
ELSE 3
END,
a.name
a.name,
c.name,
c.version,
cv.vuln_id
LIMIT 100
) t
);
@@ -825,7 +1003,10 @@ COMMENT ON FUNCTION analytics.sp_fixable_backlog IS 'Get vulnerabilities with av
-- Attestation coverage gaps
CREATE OR REPLACE FUNCTION analytics.sp_attestation_gaps(p_environment TEXT DEFAULT NULL)
RETURNS JSON AS $$
DECLARE
env TEXT;
BEGIN
env := NULLIF(BTRIM(p_environment), '');
RETURN (
SELECT json_agg(row_to_json(t))
FROM (
@@ -839,8 +1020,8 @@ BEGIN
slsa2_pct,
total_artifacts - with_provenance AS missing_provenance
FROM analytics.mv_attestation_coverage
WHERE (p_environment IS NULL OR environment = p_environment)
ORDER BY provenance_pct ASC
WHERE (env IS NULL OR environment = env)
ORDER BY provenance_pct ASC, COALESCE(environment, ''), COALESCE(team, '')
) t
);
END;
@@ -862,6 +1043,8 @@ BEGIN
FROM analytics.component_vulns cv
JOIN analytics.vex_overrides vo ON vo.vuln_id = cv.vuln_id
AND vo.status = 'not_affected'
AND vo.valid_from <= now()
AND (vo.valid_until IS NULL OR vo.valid_until > now())
WHERE cv.published_at >= now() - (p_days || ' days')::INTERVAL
AND cv.published_at IS NOT NULL
GROUP BY severity
@@ -871,7 +1054,8 @@ BEGIN
WHEN 'high' THEN 2
WHEN 'medium' THEN 3
ELSE 4
END
END,
severity::TEXT
) t
);
END;
@@ -887,14 +1071,14 @@ COMMENT ON FUNCTION analytics.sp_mttr_by_severity IS 'Get mean time to remediate
CREATE OR REPLACE FUNCTION analytics.refresh_all_views()
RETURNS VOID AS $$
BEGIN
REFRESH MATERIALIZED VIEW CONCURRENTLY analytics.mv_supplier_concentration;
REFRESH MATERIALIZED VIEW CONCURRENTLY analytics.mv_license_distribution;
REFRESH MATERIALIZED VIEW CONCURRENTLY analytics.mv_vuln_exposure;
REFRESH MATERIALIZED VIEW CONCURRENTLY analytics.mv_attestation_coverage;
REFRESH MATERIALIZED VIEW analytics.mv_supplier_concentration;
REFRESH MATERIALIZED VIEW analytics.mv_license_distribution;
REFRESH MATERIALIZED VIEW analytics.mv_vuln_exposure;
REFRESH MATERIALIZED VIEW analytics.mv_attestation_coverage;
END;
$$ LANGUAGE plpgsql;
COMMENT ON FUNCTION analytics.refresh_all_views IS 'Refresh all analytics materialized views (run daily)';
COMMENT ON FUNCTION analytics.refresh_all_views IS 'Refresh all analytics materialized views (non-concurrent; run off-peak or use PlatformAnalyticsMaintenanceService for concurrent refresh)';
-- Daily rollup procedure
CREATE OR REPLACE FUNCTION analytics.compute_daily_rollups(p_date DATE DEFAULT CURRENT_DATE)
@@ -915,8 +1099,11 @@ BEGIN
COUNT(*) FILTER (WHERE cv.fix_available = TRUE) AS fixable_vulns,
COUNT(*) FILTER (WHERE EXISTS (
SELECT 1 FROM analytics.vex_overrides vo
WHERE vo.artifact_id = a.artifact_id AND vo.vuln_id = cv.vuln_id
WHERE vo.artifact_id = a.artifact_id
AND vo.vuln_id = cv.vuln_id
AND vo.status = 'not_affected'
AND vo.valid_from::DATE <= p_date
AND (vo.valid_until IS NULL OR vo.valid_until::DATE >= p_date)
)) AS vex_mitigated,
COUNT(*) FILTER (WHERE cv.kev_listed = TRUE) AS kev_vulns,
COUNT(DISTINCT cv.vuln_id) AS unique_cves,
@@ -959,6 +1146,12 @@ BEGIN
total_components = EXCLUDED.total_components,
unique_suppliers = EXCLUDED.unique_suppliers,
created_at = now();
DELETE FROM analytics.daily_vulnerability_counts
WHERE snapshot_date < (p_date - INTERVAL '90 days');
DELETE FROM analytics.daily_component_counts
WHERE snapshot_date < (p_date - INTERVAL '90 days');
END;
$$ LANGUAGE plpgsql;