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
This commit is contained in:
parent
3e35032d79
commit
2b24323f7f
@ -2,6 +2,7 @@
|
|||||||
-- Description: Adds blacklist/whitelist public sources with auto-sync support
|
-- Description: Adds blacklist/whitelist public sources with auto-sync support
|
||||||
-- Author: IDS System
|
-- Author: IDS System
|
||||||
-- Date: 2024-11-26
|
-- Date: 2024-11-26
|
||||||
|
-- NOTE: Fully idempotent - safe to run multiple times
|
||||||
|
|
||||||
BEGIN;
|
BEGIN;
|
||||||
|
|
||||||
@ -26,8 +27,8 @@ CREATE TABLE IF NOT EXISTS public_lists (
|
|||||||
created_at TIMESTAMP NOT NULL DEFAULT NOW()
|
created_at TIMESTAMP NOT NULL DEFAULT NOW()
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE INDEX public_lists_type_idx ON public_lists(type);
|
CREATE INDEX IF NOT EXISTS public_lists_type_idx ON public_lists(type);
|
||||||
CREATE INDEX public_lists_enabled_idx ON public_lists(enabled);
|
CREATE INDEX IF NOT EXISTS public_lists_enabled_idx ON public_lists(enabled);
|
||||||
|
|
||||||
-- Public blacklist IPs from external sources
|
-- Public blacklist IPs from external sources
|
||||||
CREATE TABLE IF NOT EXISTS public_blacklist_ips (
|
CREATE TABLE IF NOT EXISTS public_blacklist_ips (
|
||||||
@ -40,10 +41,20 @@ CREATE TABLE IF NOT EXISTS public_blacklist_ips (
|
|||||||
is_active BOOLEAN NOT NULL DEFAULT true
|
is_active BOOLEAN NOT NULL DEFAULT true
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE INDEX public_blacklist_ip_idx ON public_blacklist_ips(ip_address);
|
CREATE INDEX IF NOT EXISTS public_blacklist_ip_idx ON public_blacklist_ips(ip_address);
|
||||||
CREATE INDEX public_blacklist_list_idx ON public_blacklist_ips(list_id);
|
CREATE INDEX IF NOT EXISTS public_blacklist_list_idx ON public_blacklist_ips(list_id);
|
||||||
CREATE INDEX public_blacklist_active_idx ON public_blacklist_ips(is_active);
|
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);
|
CREATE UNIQUE INDEX public_blacklist_ip_list_key ON public_blacklist_ips(ip_address, list_id);
|
||||||
|
END IF;
|
||||||
|
END $$;
|
||||||
|
|
||||||
-- ============================================================================
|
-- ============================================================================
|
||||||
-- 2. ALTER EXISTING TABLES
|
-- 2. ALTER EXISTING TABLES
|
||||||
@ -93,7 +104,6 @@ END $$;
|
|||||||
-- 3. UPDATE SCHEMA VERSION
|
-- 3. UPDATE SCHEMA VERSION
|
||||||
-- ============================================================================
|
-- ============================================================================
|
||||||
|
|
||||||
-- Insert new version record
|
|
||||||
INSERT INTO schema_version (id, version, description)
|
INSERT INTO schema_version (id, version, description)
|
||||||
VALUES (1, 6, 'Add public lists integration (blacklist/whitelist sources)')
|
VALUES (1, 6, 'Add public lists integration (blacklist/whitelist sources)')
|
||||||
ON CONFLICT (id) DO UPDATE
|
ON CONFLICT (id) DO UPDATE
|
||||||
@ -101,46 +111,6 @@ SET version = 6,
|
|||||||
description = 'Add public lists integration (blacklist/whitelist sources)',
|
description = 'Add public lists integration (blacklist/whitelist sources)',
|
||||||
applied_at = NOW();
|
applied_at = NOW();
|
||||||
|
|
||||||
-- ============================================================================
|
|
||||||
-- 4. SEED DEFAULT PUBLIC LISTS (OPTIONAL - commented for manual execution)
|
|
||||||
-- ============================================================================
|
|
||||||
|
|
||||||
/*
|
|
||||||
-- Blacklist sources
|
|
||||||
INSERT INTO public_lists (name, type, url, enabled, fetch_interval_minutes) VALUES
|
|
||||||
('Spamhaus DROP', 'blacklist', 'https://www.spamhaus.org/drop/drop.txt', true, 10),
|
|
||||||
('Talos Intelligence', 'blacklist', 'https://talosintelligence.com/documents/ip-blacklist', false, 10);
|
|
||||||
|
|
||||||
-- Whitelist sources
|
|
||||||
INSERT INTO public_lists (name, type, url, enabled, fetch_interval_minutes) VALUES
|
|
||||||
('AWS IP Ranges', 'whitelist', 'https://ip-ranges.amazonaws.com/ip-ranges.json', true, 10),
|
|
||||||
('Google Cloud IP Ranges', 'whitelist', 'https://www.gstatic.com/ipranges/cloud.json', true, 10),
|
|
||||||
('Cloudflare IPs', 'whitelist', 'https://www.cloudflare.com/ips-v4', true, 10),
|
|
||||||
('IANA Root Servers', 'whitelist', 'https://www.iana.org/domains/root/servers', true, 10),
|
|
||||||
('NTP Pool', 'whitelist', 'https://www.ntppool.org/zone/@', false, 10);
|
|
||||||
*/
|
|
||||||
|
|
||||||
COMMIT;
|
COMMIT;
|
||||||
|
|
||||||
-- ============================================================================
|
SELECT 'Migration 006 completed successfully' as status;
|
||||||
-- ROLLBACK PROCEDURE (if needed)
|
|
||||||
-- ============================================================================
|
|
||||||
|
|
||||||
/*
|
|
||||||
BEGIN;
|
|
||||||
|
|
||||||
-- Remove new columns from existing tables
|
|
||||||
ALTER TABLE detections DROP COLUMN IF EXISTS detection_source;
|
|
||||||
ALTER TABLE detections DROP COLUMN IF EXISTS blacklist_id;
|
|
||||||
ALTER TABLE whitelist DROP COLUMN IF EXISTS source;
|
|
||||||
ALTER TABLE whitelist DROP COLUMN IF EXISTS list_id;
|
|
||||||
|
|
||||||
-- Drop new tables (CASCADE removes FK constraints)
|
|
||||||
DROP TABLE IF EXISTS public_blacklist_ips CASCADE;
|
|
||||||
DROP TABLE IF EXISTS public_lists CASCADE;
|
|
||||||
|
|
||||||
-- Revert schema version
|
|
||||||
UPDATE schema_version SET version = 5, description = 'Rollback from public lists integration' WHERE id = 1;
|
|
||||||
|
|
||||||
COMMIT;
|
|
||||||
*/
|
|
||||||
|
|||||||
@ -1,39 +1,42 @@
|
|||||||
-- Migration 007: Add INET/CIDR support for proper network range matching
|
-- Migration 007: Add INET/CIDR support for proper network range matching
|
||||||
-- Required for public lists integration (Spamhaus /24, AWS ranges, etc.)
|
-- Required for public lists integration (Spamhaus /24, AWS ranges, etc.)
|
||||||
-- Date: 2025-11-26
|
-- Date: 2025-11-26
|
||||||
|
-- NOTE: Fully idempotent - safe to run multiple times
|
||||||
|
|
||||||
BEGIN;
|
BEGIN;
|
||||||
|
|
||||||
-- Add INET/CIDR columns to public_blacklist_ips
|
-- Add INET/CIDR columns to public_blacklist_ips (if not exist)
|
||||||
ALTER TABLE public_blacklist_ips
|
ALTER TABLE public_blacklist_ips
|
||||||
ADD COLUMN ip_inet inet,
|
ADD COLUMN IF NOT EXISTS ip_inet inet,
|
||||||
ADD COLUMN cidr_inet cidr;
|
ADD COLUMN IF NOT EXISTS cidr_inet cidr;
|
||||||
|
|
||||||
-- Populate new columns from existing text data
|
-- Populate new columns from existing text data (only for NULL values)
|
||||||
UPDATE public_blacklist_ips
|
UPDATE public_blacklist_ips
|
||||||
SET ip_inet = ip_address::inet,
|
SET ip_inet = ip_address::inet,
|
||||||
cidr_inet = CASE
|
cidr_inet = CASE
|
||||||
WHEN cidr_range IS NOT NULL THEN cidr_range::cidr
|
WHEN cidr_range IS NOT NULL THEN cidr_range::cidr
|
||||||
ELSE (ip_address || '/32')::cidr
|
ELSE (ip_address || '/32')::cidr
|
||||||
END;
|
END
|
||||||
|
WHERE ip_inet IS NULL OR cidr_inet IS NULL;
|
||||||
|
|
||||||
-- Create indexes for INET operators (critical for performance)
|
-- Create indexes for INET operators (idempotent)
|
||||||
CREATE INDEX public_blacklist_ip_inet_idx ON public_blacklist_ips USING gist(ip_inet inet_ops);
|
CREATE INDEX IF NOT EXISTS 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);
|
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
|
-- Add INET column to whitelist for CIDR matching
|
||||||
ALTER TABLE whitelist
|
ALTER TABLE whitelist
|
||||||
ADD COLUMN ip_inet inet;
|
ADD COLUMN IF NOT EXISTS ip_inet inet;
|
||||||
|
|
||||||
-- Populate whitelist INET column
|
-- Populate whitelist INET column (only for NULL values)
|
||||||
UPDATE whitelist
|
UPDATE whitelist
|
||||||
SET ip_inet = CASE
|
SET ip_inet = CASE
|
||||||
WHEN ip_address ~ '/' THEN ip_address::inet
|
WHEN ip_address ~ '/' THEN ip_address::inet
|
||||||
ELSE ip_address::inet
|
ELSE ip_address::inet
|
||||||
END;
|
END
|
||||||
|
WHERE ip_inet IS NULL;
|
||||||
|
|
||||||
-- Create index for whitelist INET matching
|
-- Create index for whitelist INET matching (idempotent)
|
||||||
CREATE INDEX whitelist_ip_inet_idx ON whitelist USING gist(ip_inet inet_ops);
|
CREATE INDEX IF NOT EXISTS whitelist_ip_inet_idx ON whitelist USING gist(ip_inet inet_ops);
|
||||||
|
|
||||||
-- Update schema version
|
-- Update schema version
|
||||||
UPDATE schema_version SET version = 7, applied_at = NOW() WHERE id = 1;
|
UPDATE schema_version SET version = 7, applied_at = NOW() WHERE id = 1;
|
||||||
|
|||||||
Loading…
Reference in New Issue
Block a user