diff --git a/deployment/migrations/007_add_cidr_support.sql b/deployment/migrations/007_add_cidr_support.sql index f014374..912454b 100644 --- a/deployment/migrations/007_add_cidr_support.sql +++ b/deployment/migrations/007_add_cidr_support.sql @@ -1,16 +1,38 @@ -- Migration 007: Add INET/CIDR support for proper network range matching -- Required for public lists integration (Spamhaus /24, AWS ranges, etc.) -- Date: 2025-11-26 --- NOTE: Fully idempotent - safe to run multiple times +-- NOTE: Handles case where columns exist as TEXT type (from Drizzle) BEGIN; --- Add INET/CIDR columns to public_blacklist_ips (if not exist) +-- ============================================================================ +-- FIX: Drop TEXT columns and recreate as proper INET/CIDR types +-- ============================================================================ + +-- Check column type and fix if needed for public_blacklist_ips +DO $$ +DECLARE + col_type text; +BEGIN + -- Check ip_inet column type + SELECT data_type INTO col_type + FROM information_schema.columns + WHERE table_name = 'public_blacklist_ips' AND column_name = 'ip_inet'; + + IF col_type = 'text' THEN + -- Drop the wrong type columns + ALTER TABLE public_blacklist_ips DROP COLUMN IF EXISTS ip_inet; + ALTER TABLE public_blacklist_ips DROP COLUMN IF EXISTS cidr_inet; + RAISE NOTICE 'Dropped TEXT columns, will recreate as INET/CIDR'; + END IF; +END $$; + +-- Add INET/CIDR columns with correct types ALTER TABLE public_blacklist_ips ADD COLUMN IF NOT EXISTS ip_inet inet, ADD COLUMN IF NOT EXISTS cidr_inet cidr; --- Populate new columns from existing text data (only for NULL values) +-- Populate new columns from existing text data UPDATE public_blacklist_ips SET ip_inet = ip_address::inet, cidr_inet = CASE @@ -19,15 +41,33 @@ SET ip_inet = ip_address::inet, END WHERE ip_inet IS NULL OR cidr_inet IS NULL; --- Create indexes for INET operators (idempotent) +-- Create GiST indexes for INET operators CREATE INDEX IF NOT EXISTS public_blacklist_ip_inet_idx ON public_blacklist_ips USING gist(ip_inet inet_ops); CREATE INDEX IF NOT EXISTS public_blacklist_cidr_inet_idx ON public_blacklist_ips USING gist(cidr_inet inet_ops); --- Add INET column to whitelist for CIDR matching +-- ============================================================================ +-- Fix whitelist table +-- ============================================================================ + +DO $$ +DECLARE + col_type text; +BEGIN + SELECT data_type INTO col_type + FROM information_schema.columns + WHERE table_name = 'whitelist' AND column_name = 'ip_inet'; + + IF col_type = 'text' THEN + ALTER TABLE whitelist DROP COLUMN IF EXISTS ip_inet; + RAISE NOTICE 'Dropped TEXT column from whitelist, will recreate as INET'; + END IF; +END $$; + +-- Add INET column to whitelist ALTER TABLE whitelist ADD COLUMN IF NOT EXISTS ip_inet inet; --- Populate whitelist INET column (only for NULL values) +-- Populate whitelist INET column UPDATE whitelist SET ip_inet = CASE WHEN ip_address ~ '/' THEN ip_address::inet @@ -35,7 +75,7 @@ SET ip_inet = CASE END WHERE ip_inet IS NULL; --- Create index for whitelist INET matching (idempotent) +-- Create index for whitelist INET matching CREATE INDEX IF NOT EXISTS whitelist_ip_inet_idx ON whitelist USING gist(ip_inet inet_ops); -- Update schema version @@ -43,8 +83,6 @@ UPDATE schema_version SET version = 7, applied_at = NOW() WHERE id = 1; COMMIT; --- Verification queries +-- Verification SELECT 'Migration 007 completed successfully' as status; SELECT version, applied_at FROM schema_version WHERE id = 1; -SELECT COUNT(*) as blacklist_with_cidr FROM public_blacklist_ips WHERE cidr_inet IS NOT NULL; -SELECT COUNT(*) as whitelist_with_inet FROM whitelist WHERE ip_inet IS NOT NULL;