-- 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: Handles case where columns exist as TEXT type (from Drizzle) BEGIN; -- ============================================================================ -- 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 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 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); -- ============================================================================ -- 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 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 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 SELECT 'Migration 007 completed successfully' as status; SELECT version, applied_at FROM schema_version WHERE id = 1;