ids.alfacom.it/deployment/migrations/007_add_cidr_support.sql
marco370 83468619ff Add full CIDR support for IP address matching in lists
Updates IP address handling to include CIDR notation for more comprehensive network range matching, enhances database schema with INET/CIDR types, and refactors logic for accurate IP detection and whitelisting.

Replit-Commit-Author: Agent
Replit-Commit-Session-Id: 7a657272-55ba-4a79-9a2e-f1ed9bc7a528
Replit-Commit-Checkpoint-Type: intermediate_checkpoint
Replit-Commit-Event-Id: 49a5a4b7-82b5-4dd4-84c1-9f0e855bea8a
Replit-Commit-Screenshot-Url: https://storage.googleapis.com/screenshot-production-us-central1/449cf7c4-c97a-45ae-8234-e5c5b8d6a84f/7a657272-55ba-4a79-9a2e-f1ed9bc7a528/qHCi0Qg
2025-11-26 09:54:57 +00:00

48 lines
1.6 KiB
PL/PgSQL

-- 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
BEGIN;
-- Add INET/CIDR columns to public_blacklist_ips
ALTER TABLE public_blacklist_ips
ADD COLUMN ip_inet inet,
ADD COLUMN 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;
-- Create indexes for INET operators (critical for performance)
CREATE INDEX public_blacklist_ip_inet_idx ON public_blacklist_ips USING gist(ip_inet inet_ops);
CREATE INDEX 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 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;
-- Create index for whitelist INET matching
CREATE INDEX 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;