ids.alfacom.it/extracted_idf/create_whitelist_globale.sql
marco370 0bfe3258b5 Saved progress at the end of the loop
Replit-Commit-Author: Agent
Replit-Commit-Session-Id: 7a657272-55ba-4a79-9a2e-f1ed9bc7a528
Replit-Commit-Checkpoint-Type: full_checkpoint
Replit-Commit-Event-Id: 1c71ce6e-1a3e-4f53-bb5d-77cdd22b8ea3
2025-11-11 09:15:10 +00:00

149 lines
5.2 KiB
SQL

-- ===================================================================
-- CREAZIONE TABELLA whitelistGlobale
-- ===================================================================
-- Tabella per IP in whitelist validi per TUTTI i router
-- Risolve il problema dei falsi positivi in ddos_detect_v03
CREATE TABLE IF NOT EXISTS `whitelistGlobale` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`ip_address` varchar(45) NOT NULL,
`comment` text DEFAULT NULL,
`created_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
`created_by` varchar(100) DEFAULT 'System',
`active` tinyint(1) NOT NULL DEFAULT 1,
`reason` varchar(255) DEFAULT NULL,
`last_sync` timestamp NULL DEFAULT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `idx_ip_address` (`ip_address`),
KEY `idx_active` (`active`),
KEY `idx_created_at` (`created_at`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- ===================================================================
-- INDICI PER PERFORMANCE
-- ===================================================================
CREATE INDEX `idx_ip_active` ON `whitelistGlobale` (`ip_address`, `active`);
CREATE INDEX `idx_sync_status` ON `whitelistGlobale` (`active`, `last_sync`);
-- ===================================================================
-- INSERIMENTI DI ESEMPIO (OPZIONALI)
-- ===================================================================
-- IP interni aziendali
INSERT IGNORE INTO `whitelistGlobale` (`ip_address`, `comment`, `reason`, `created_by`) VALUES
('192.168.1.1', 'Gateway interno aziendale', 'IP infrastruttura critica', 'Admin'),
('10.0.0.1', 'Server principale', 'Server aziendale', 'Admin'),
('172.16.0.1', 'Router interno', 'Infrastruttura di rete', 'Admin');
-- ===================================================================
-- VISTA PER MONITORAGGIO
-- ===================================================================
CREATE OR REPLACE VIEW `v_whitelist_stats` AS
SELECT
COUNT(*) as total_ips,
COUNT(CASE WHEN active = 1 THEN 1 END) as active_ips,
COUNT(CASE WHEN active = 0 THEN 1 END) as disabled_ips,
COUNT(CASE WHEN last_sync IS NULL THEN 1 END) as never_synced,
MAX(created_at) as last_added,
MAX(last_sync) as last_sync_time
FROM `whitelistGlobale`;
-- ===================================================================
-- STORED PROCEDURE PER AGGIUNTA RAPIDA
-- ===================================================================
DELIMITER $$
CREATE PROCEDURE `add_global_whitelist`(
IN p_ip_address VARCHAR(45),
IN p_comment TEXT,
IN p_reason VARCHAR(255),
IN p_created_by VARCHAR(100)
)
BEGIN
DECLARE EXIT HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
RESIGNAL;
END;
START TRANSACTION;
-- Inserisci nella whitelist globale
INSERT INTO `whitelistGlobale` (`ip_address`, `comment`, `reason`, `created_by`)
VALUES (p_ip_address, p_comment, p_reason, IFNULL(p_created_by, 'System'))
ON DUPLICATE KEY UPDATE
`comment` = VALUES(`comment`),
`reason` = VALUES(`reason`),
`active` = 1,
`created_by` = VALUES(`created_by`);
-- Rimuovi dalla blacklist se presente
DELETE FROM `ip_list` WHERE `ip_address` = p_ip_address AND `list_name` = 'ddos_detect_v03';
SELECT CONCAT('✅ IP ', p_ip_address, ' aggiunto alla whitelist globale') as result;
COMMIT;
END$$
DELIMITER ;
-- ===================================================================
-- STORED PROCEDURE PER RIMOZIONE SICURA
-- ===================================================================
DELIMITER $$
CREATE PROCEDURE `remove_global_whitelist`(
IN p_ip_address VARCHAR(45),
IN p_disable_only BOOLEAN DEFAULT TRUE
)
BEGIN
DECLARE EXIT HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
RESIGNAL;
END;
START TRANSACTION;
IF p_disable_only THEN
-- Disabilita senza cancellare (più sicuro)
UPDATE `whitelistGlobale`
SET `active` = 0, `last_sync` = NOW()
WHERE `ip_address` = p_ip_address;
SELECT CONCAT('⚠️ IP ', p_ip_address, ' disabilitato dalla whitelist globale') as result;
ELSE
-- Cancellazione completa
DELETE FROM `whitelistGlobale` WHERE `ip_address` = p_ip_address;
SELECT CONCAT('❌ IP ', p_ip_address, ' rimosso completamente dalla whitelist globale') as result;
END IF;
COMMIT;
END$$
DELIMITER ;
-- ===================================================================
-- COMANDI RAPIDI DI UTILIZZO
-- ===================================================================
/*
-- Aggiungere IP alla whitelist globale:
CALL add_global_whitelist('203.45.67.89', 'Server partner fidato', 'Falso positivo DDoS', 'Admin');
-- Disabilitare IP dalla whitelist:
CALL remove_global_whitelist('203.45.67.89', TRUE);
-- Rimuovere completamente IP:
CALL remove_global_whitelist('203.45.67.89', FALSE);
-- Visualizzare statistiche:
SELECT * FROM v_whitelist_stats;
-- Visualizzare tutti gli IP attivi:
SELECT ip_address, comment, reason, created_at
FROM whitelistGlobale
WHERE active = 1
ORDER BY created_at DESC;
*/