up
This commit is contained in:
@@ -0,0 +1,261 @@
|
||||
-- Vulnerability Schema Migration 001: Initial Schema
|
||||
-- Creates the vuln schema for advisories and vulnerability data
|
||||
|
||||
-- Create schema
|
||||
CREATE SCHEMA IF NOT EXISTS vuln;
|
||||
|
||||
-- Enable pg_trgm for fuzzy text search
|
||||
CREATE EXTENSION IF NOT EXISTS pg_trgm;
|
||||
|
||||
-- Sources table (feed sources)
|
||||
CREATE TABLE IF NOT EXISTS vuln.sources (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
key TEXT NOT NULL UNIQUE,
|
||||
name TEXT NOT NULL,
|
||||
source_type TEXT NOT NULL,
|
||||
url TEXT,
|
||||
priority INT NOT NULL DEFAULT 0,
|
||||
enabled BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
config JSONB NOT NULL DEFAULT '{}',
|
||||
metadata JSONB NOT NULL DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_sources_enabled ON vuln.sources(enabled, priority DESC);
|
||||
|
||||
-- Feed snapshots table
|
||||
CREATE TABLE IF NOT EXISTS vuln.feed_snapshots (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
source_id UUID NOT NULL REFERENCES vuln.sources(id),
|
||||
snapshot_id TEXT NOT NULL,
|
||||
advisory_count INT NOT NULL DEFAULT 0,
|
||||
checksum TEXT,
|
||||
metadata JSONB NOT NULL DEFAULT '{}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(source_id, snapshot_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_feed_snapshots_source ON vuln.feed_snapshots(source_id);
|
||||
CREATE INDEX idx_feed_snapshots_created ON vuln.feed_snapshots(created_at);
|
||||
|
||||
-- Advisory snapshots table (point-in-time snapshots)
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_snapshots (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
feed_snapshot_id UUID NOT NULL REFERENCES vuln.feed_snapshots(id),
|
||||
advisory_key TEXT NOT NULL,
|
||||
content_hash TEXT NOT NULL,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(feed_snapshot_id, advisory_key)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_snapshots_feed ON vuln.advisory_snapshots(feed_snapshot_id);
|
||||
CREATE INDEX idx_advisory_snapshots_key ON vuln.advisory_snapshots(advisory_key);
|
||||
|
||||
-- Advisories table (main vulnerability data)
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisories (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_key TEXT NOT NULL UNIQUE,
|
||||
primary_vuln_id TEXT NOT NULL,
|
||||
source_id UUID REFERENCES vuln.sources(id),
|
||||
title TEXT,
|
||||
summary TEXT,
|
||||
description TEXT,
|
||||
severity TEXT CHECK (severity IN ('critical', 'high', 'medium', 'low', 'unknown')),
|
||||
published_at TIMESTAMPTZ,
|
||||
modified_at TIMESTAMPTZ,
|
||||
withdrawn_at TIMESTAMPTZ,
|
||||
provenance JSONB NOT NULL DEFAULT '{}',
|
||||
raw_payload JSONB,
|
||||
search_vector TSVECTOR,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisories_vuln_id ON vuln.advisories(primary_vuln_id);
|
||||
CREATE INDEX idx_advisories_source ON vuln.advisories(source_id);
|
||||
CREATE INDEX idx_advisories_severity ON vuln.advisories(severity);
|
||||
CREATE INDEX idx_advisories_published ON vuln.advisories(published_at);
|
||||
CREATE INDEX idx_advisories_modified ON vuln.advisories(modified_at);
|
||||
CREATE INDEX idx_advisories_search ON vuln.advisories USING GIN(search_vector);
|
||||
|
||||
-- Advisory aliases table (CVE, GHSA, etc.)
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_aliases (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
alias_type TEXT NOT NULL,
|
||||
alias_value TEXT NOT NULL,
|
||||
is_primary BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(advisory_id, alias_type, alias_value)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_aliases_advisory ON vuln.advisory_aliases(advisory_id);
|
||||
CREATE INDEX idx_advisory_aliases_value ON vuln.advisory_aliases(alias_type, alias_value);
|
||||
CREATE INDEX idx_advisory_aliases_cve ON vuln.advisory_aliases(alias_value)
|
||||
WHERE alias_type = 'CVE';
|
||||
|
||||
-- Advisory CVSS scores table
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_cvss (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
cvss_version TEXT NOT NULL,
|
||||
vector_string TEXT NOT NULL,
|
||||
base_score NUMERIC(3,1) NOT NULL,
|
||||
base_severity TEXT,
|
||||
exploitability_score NUMERIC(3,1),
|
||||
impact_score NUMERIC(3,1),
|
||||
source TEXT,
|
||||
is_primary BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(advisory_id, cvss_version, source)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_cvss_advisory ON vuln.advisory_cvss(advisory_id);
|
||||
CREATE INDEX idx_advisory_cvss_score ON vuln.advisory_cvss(base_score DESC);
|
||||
|
||||
-- Advisory affected packages table
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_affected (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
ecosystem TEXT NOT NULL,
|
||||
package_name TEXT NOT NULL,
|
||||
purl TEXT,
|
||||
version_range JSONB NOT NULL DEFAULT '{}',
|
||||
versions_affected TEXT[],
|
||||
versions_fixed TEXT[],
|
||||
database_specific JSONB,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_affected_advisory ON vuln.advisory_affected(advisory_id);
|
||||
CREATE INDEX idx_advisory_affected_ecosystem ON vuln.advisory_affected(ecosystem, package_name);
|
||||
CREATE INDEX idx_advisory_affected_purl ON vuln.advisory_affected(purl);
|
||||
CREATE INDEX idx_advisory_affected_purl_trgm ON vuln.advisory_affected USING GIN(purl gin_trgm_ops);
|
||||
|
||||
-- Advisory references table
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_references (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
ref_type TEXT NOT NULL,
|
||||
url TEXT NOT NULL,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_references_advisory ON vuln.advisory_references(advisory_id);
|
||||
|
||||
-- Advisory credits table
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_credits (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
name TEXT NOT NULL,
|
||||
contact TEXT,
|
||||
credit_type TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_credits_advisory ON vuln.advisory_credits(advisory_id);
|
||||
|
||||
-- Advisory weaknesses table (CWE)
|
||||
CREATE TABLE IF NOT EXISTS vuln.advisory_weaknesses (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
cwe_id TEXT NOT NULL,
|
||||
description TEXT,
|
||||
source TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(advisory_id, cwe_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_advisory_weaknesses_advisory ON vuln.advisory_weaknesses(advisory_id);
|
||||
CREATE INDEX idx_advisory_weaknesses_cwe ON vuln.advisory_weaknesses(cwe_id);
|
||||
|
||||
-- KEV flags table (Known Exploited Vulnerabilities)
|
||||
CREATE TABLE IF NOT EXISTS vuln.kev_flags (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id) ON DELETE CASCADE,
|
||||
cve_id TEXT NOT NULL,
|
||||
vendor_project TEXT,
|
||||
product TEXT,
|
||||
vulnerability_name TEXT,
|
||||
date_added DATE NOT NULL,
|
||||
due_date DATE,
|
||||
known_ransomware_use BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
notes TEXT,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
UNIQUE(advisory_id, cve_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_kev_flags_advisory ON vuln.kev_flags(advisory_id);
|
||||
CREATE INDEX idx_kev_flags_cve ON vuln.kev_flags(cve_id);
|
||||
CREATE INDEX idx_kev_flags_date ON vuln.kev_flags(date_added);
|
||||
|
||||
-- Source states table (cursor tracking)
|
||||
CREATE TABLE IF NOT EXISTS vuln.source_states (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
source_id UUID NOT NULL REFERENCES vuln.sources(id) UNIQUE,
|
||||
cursor TEXT,
|
||||
last_sync_at TIMESTAMPTZ,
|
||||
last_success_at TIMESTAMPTZ,
|
||||
last_error TEXT,
|
||||
sync_count BIGINT NOT NULL DEFAULT 0,
|
||||
error_count INT NOT NULL DEFAULT 0,
|
||||
metadata JSONB NOT NULL DEFAULT '{}',
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_source_states_source ON vuln.source_states(source_id);
|
||||
|
||||
-- Merge events table (advisory merge audit)
|
||||
CREATE TABLE IF NOT EXISTS vuln.merge_events (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
advisory_id UUID NOT NULL REFERENCES vuln.advisories(id),
|
||||
source_id UUID REFERENCES vuln.sources(id),
|
||||
event_type TEXT NOT NULL,
|
||||
old_value JSONB,
|
||||
new_value JSONB,
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_merge_events_advisory ON vuln.merge_events(advisory_id);
|
||||
CREATE INDEX idx_merge_events_created ON vuln.merge_events(created_at);
|
||||
|
||||
-- Function to update search vector
|
||||
CREATE OR REPLACE FUNCTION vuln.update_advisory_search_vector()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.search_vector =
|
||||
setweight(to_tsvector('english', COALESCE(NEW.primary_vuln_id, '')), 'A') ||
|
||||
setweight(to_tsvector('english', COALESCE(NEW.title, '')), 'B') ||
|
||||
setweight(to_tsvector('english', COALESCE(NEW.summary, '')), 'C') ||
|
||||
setweight(to_tsvector('english', COALESCE(NEW.description, '')), 'D');
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Trigger for search vector
|
||||
CREATE TRIGGER trg_advisories_search_vector
|
||||
BEFORE INSERT OR UPDATE ON vuln.advisories
|
||||
FOR EACH ROW EXECUTE FUNCTION vuln.update_advisory_search_vector();
|
||||
|
||||
-- Update timestamp function
|
||||
CREATE OR REPLACE FUNCTION vuln.update_updated_at()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = NOW();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Triggers
|
||||
CREATE TRIGGER trg_sources_updated_at
|
||||
BEFORE UPDATE ON vuln.sources
|
||||
FOR EACH ROW EXECUTE FUNCTION vuln.update_updated_at();
|
||||
|
||||
CREATE TRIGGER trg_advisories_updated_at
|
||||
BEFORE UPDATE ON vuln.advisories
|
||||
FOR EACH ROW EXECUTE FUNCTION vuln.update_updated_at();
|
||||
|
||||
CREATE TRIGGER trg_source_states_updated_at
|
||||
BEFORE UPDATE ON vuln.source_states
|
||||
FOR EACH ROW EXECUTE FUNCTION vuln.update_updated_at();
|
||||
Reference in New Issue
Block a user