ids.alfacom.it/deployment/migrations/006_add_public_lists.sql
marco370 2b24323f7f Make database migrations more robust and repeatable
Update SQL migration scripts to be idempotent, ensuring they can be run multiple times without errors by using `IF NOT EXISTS` clauses for index and column creation.

Replit-Commit-Author: Agent
Replit-Commit-Session-Id: 7a657272-55ba-4a79-9a2e-f1ed9bc7a528
Replit-Commit-Checkpoint-Type: full_checkpoint
Replit-Commit-Event-Id: 7fe65eff-e75c-4ad2-9348-9df209d4ad11
Replit-Commit-Screenshot-Url: https://storage.googleapis.com/screenshot-production-us-central1/449cf7c4-c97a-45ae-8234-e5c5b8d6a84f/7a657272-55ba-4a79-9a2e-f1ed9bc7a528/zauptjn
2025-11-27 18:24:30 +00:00

117 lines
4.1 KiB
PL/PgSQL

-- Migration 006: Add Public Lists Integration
-- Description: Adds blacklist/whitelist public sources with auto-sync support
-- Author: IDS System
-- Date: 2024-11-26
-- NOTE: Fully idempotent - safe to run multiple times
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 IF NOT EXISTS public_lists_type_idx ON public_lists(type);
CREATE INDEX IF NOT EXISTS 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 IF NOT EXISTS public_blacklist_ip_idx ON public_blacklist_ips(ip_address);
CREATE INDEX IF NOT EXISTS public_blacklist_list_idx ON public_blacklist_ips(list_id);
CREATE INDEX IF NOT EXISTS public_blacklist_active_idx ON public_blacklist_ips(is_active);
-- Create unique constraint only if not exists
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM pg_indexes
WHERE indexname = 'public_blacklist_ip_list_key'
) THEN
CREATE UNIQUE INDEX public_blacklist_ip_list_key ON public_blacklist_ips(ip_address, list_id);
END IF;
END $$;
-- ============================================================================
-- 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 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();
COMMIT;
SELECT 'Migration 006 completed successfully' as status;