-- 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 BEGIN; -- Add INET/CIDR columns to public_blacklist_ips (if not exist) 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) UPDATE public_blacklist_ips SET ip_inet = ip_address::inet, cidr_inet = CASE WHEN cidr_range IS NOT NULL THEN cidr_range::cidr ELSE (ip_address || '/32')::cidr END WHERE ip_inet IS NULL OR cidr_inet IS NULL; -- Create indexes for INET operators (idempotent) 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 ALTER TABLE whitelist ADD COLUMN IF NOT EXISTS ip_inet inet; -- Populate whitelist INET column (only for NULL values) UPDATE whitelist SET ip_inet = CASE WHEN ip_address ~ '/' THEN ip_address::inet ELSE ip_address::inet END WHERE ip_inet IS NULL; -- Create index for whitelist INET matching (idempotent) CREATE INDEX IF NOT EXISTS whitelist_ip_inet_idx ON whitelist USING gist(ip_inet inet_ops); -- Update schema version UPDATE schema_version SET version = 7, applied_at = NOW() WHERE id = 1; COMMIT; -- Verification queries 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;