-- Migration 006: Add Public Lists Integration -- Description: Adds blacklist/whitelist public sources with auto-sync support -- Author: IDS System -- Date: 2024-11-26 BEGIN; -- ============================================================================ -- 1. CREATE NEW TABLES -- ============================================================================ -- Public threat/whitelist sources configuration CREATE TABLE IF NOT EXISTS public_lists ( id VARCHAR PRIMARY KEY DEFAULT gen_random_uuid(), name TEXT NOT NULL, type TEXT NOT NULL CHECK (type IN ('blacklist', 'whitelist')), url TEXT NOT NULL, enabled BOOLEAN NOT NULL DEFAULT true, fetch_interval_minutes INTEGER NOT NULL DEFAULT 10, last_fetch TIMESTAMP, last_success TIMESTAMP, total_ips INTEGER NOT NULL DEFAULT 0, active_ips INTEGER NOT NULL DEFAULT 0, error_count INTEGER NOT NULL DEFAULT 0, last_error TEXT, created_at TIMESTAMP NOT NULL DEFAULT NOW() ); CREATE INDEX public_lists_type_idx ON public_lists(type); CREATE INDEX public_lists_enabled_idx ON public_lists(enabled); -- Public blacklist IPs from external sources CREATE TABLE IF NOT EXISTS public_blacklist_ips ( id VARCHAR PRIMARY KEY DEFAULT gen_random_uuid(), ip_address TEXT NOT NULL, cidr_range TEXT, list_id VARCHAR NOT NULL REFERENCES public_lists(id) ON DELETE CASCADE, first_seen TIMESTAMP NOT NULL DEFAULT NOW(), last_seen TIMESTAMP NOT NULL DEFAULT NOW(), is_active BOOLEAN NOT NULL DEFAULT true ); CREATE INDEX public_blacklist_ip_idx ON public_blacklist_ips(ip_address); CREATE INDEX public_blacklist_list_idx ON public_blacklist_ips(list_id); CREATE INDEX public_blacklist_active_idx ON public_blacklist_ips(is_active); CREATE UNIQUE INDEX public_blacklist_ip_list_key ON public_blacklist_ips(ip_address, list_id); -- ============================================================================ -- 2. ALTER EXISTING TABLES -- ============================================================================ -- Extend detections table with public list source tracking ALTER TABLE detections ADD COLUMN IF NOT EXISTS detection_source TEXT NOT NULL DEFAULT 'ml_model', ADD COLUMN IF NOT EXISTS blacklist_id VARCHAR; CREATE INDEX IF NOT EXISTS detection_source_idx ON detections(detection_source); -- Add check constraint for valid detection sources DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_constraint WHERE conname = 'detections_source_check' ) THEN ALTER TABLE detections ADD CONSTRAINT detections_source_check CHECK (detection_source IN ('ml_model', 'public_blacklist', 'hybrid')); END IF; END $$; -- Extend whitelist table with source tracking ALTER TABLE whitelist ADD COLUMN IF NOT EXISTS source TEXT NOT NULL DEFAULT 'manual', ADD COLUMN IF NOT EXISTS list_id VARCHAR; CREATE INDEX IF NOT EXISTS whitelist_source_idx ON whitelist(source); -- Add check constraint for valid whitelist sources DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM pg_constraint WHERE conname = 'whitelist_source_check' ) THEN ALTER TABLE whitelist ADD CONSTRAINT whitelist_source_check CHECK (source IN ('manual', 'aws', 'gcp', 'cloudflare', 'iana', 'ntp', 'other')); END IF; END $$; -- ============================================================================ -- 3. UPDATE SCHEMA VERSION -- ============================================================================ -- Insert new version record INSERT INTO schema_version (id, version, description) VALUES (1, 6, 'Add public lists integration (blacklist/whitelist sources)') ON CONFLICT (id) DO UPDATE SET version = 6, description = 'Add public lists integration (blacklist/whitelist sources)', applied_at = NOW(); -- ============================================================================ -- 4. SEED DEFAULT PUBLIC LISTS (OPTIONAL - commented for manual execution) -- ============================================================================ /* -- Blacklist sources INSERT INTO public_lists (name, type, url, enabled, fetch_interval_minutes) VALUES ('Spamhaus DROP', 'blacklist', 'https://www.spamhaus.org/drop/drop.txt', true, 10), ('Talos Intelligence', 'blacklist', 'https://talosintelligence.com/documents/ip-blacklist', false, 10); -- Whitelist sources INSERT INTO public_lists (name, type, url, enabled, fetch_interval_minutes) VALUES ('AWS IP Ranges', 'whitelist', 'https://ip-ranges.amazonaws.com/ip-ranges.json', true, 10), ('Google Cloud IP Ranges', 'whitelist', 'https://www.gstatic.com/ipranges/cloud.json', true, 10), ('Cloudflare IPs', 'whitelist', 'https://www.cloudflare.com/ips-v4', true, 10), ('IANA Root Servers', 'whitelist', 'https://www.iana.org/domains/root/servers', true, 10), ('NTP Pool', 'whitelist', 'https://www.ntppool.org/zone/@', false, 10); */ COMMIT; -- ============================================================================ -- ROLLBACK PROCEDURE (if needed) -- ============================================================================ /* BEGIN; -- Remove new columns from existing tables ALTER TABLE detections DROP COLUMN IF EXISTS detection_source; ALTER TABLE detections DROP COLUMN IF EXISTS blacklist_id; ALTER TABLE whitelist DROP COLUMN IF EXISTS source; ALTER TABLE whitelist DROP COLUMN IF EXISTS list_id; -- Drop new tables (CASCADE removes FK constraints) DROP TABLE IF EXISTS public_blacklist_ips CASCADE; DROP TABLE IF EXISTS public_lists CASCADE; -- Revert schema version UPDATE schema_version SET version = 5, description = 'Rollback from public lists integration' WHERE id = 1; COMMIT; */