ids.alfacom.it/extracted_idf/cleanup_ddos_ips_mariadb.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

300 lines
11 KiB
SQL
Raw Blame History

This file contains invisible Unicode characters

This file contains invisible Unicode characters that are indistinguishable to humans but may be processed differently by a computer. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- ============================================
-- STORED PROCEDURE PULIZIA IP ORARIA - MARIADB
-- Versione corretta per MariaDB con sintassi appropriata
-- ============================================
-- Impostazione delimiter
DELIMITER $$
-- Rimuovi procedure esistenti
DROP PROCEDURE IF EXISTS cleanup_ddos_ips_hours_fixed$$
-- Procedura principale per pulizia oraria
CREATE PROCEDURE cleanup_ddos_ips_hours_fixed(
IN retention_hours INT,
IN list_name_filter VARCHAR(100),
IN dry_run BOOLEAN
)
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE total_ips INT DEFAULT 0;
DECLARE old_ips INT DEFAULT 0;
DECLARE deleted_count INT DEFAULT 0;
DECLARE report_message TEXT DEFAULT '';
-- Gestione errori
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
GET DIAGNOSTICS CONDITION 1
@p1 = RETURNED_SQLSTATE, @p2 = MESSAGE_TEXT;
INSERT INTO ip_cleanup_log (operation_time, operation_type, list_name, status, message)
VALUES (NOW(), 'CLEANUP_HOURS', list_name_filter, 'ERROR',
CONCAT('ERRORE: ', CAST(@p1 AS CHAR), ' - ', CAST(@p2 AS CHAR)));
END;
-- Gestione valori default
IF retention_hours IS NULL THEN
SET retention_hours = 24;
END IF;
IF list_name_filter IS NULL OR list_name_filter = '' THEN
SET list_name_filter = 'ddos_detect_v03';
END IF;
IF dry_run IS NULL THEN
SET dry_run = FALSE;
END IF;
-- Inizio transazione
START TRANSACTION;
-- Log inizio operazione
INSERT INTO ip_cleanup_log (operation_time, operation_type, list_name, status, message)
VALUES (NOW(), 'CLEANUP_HOURS', list_name_filter, 'START',
CONCAT('Inizio pulizia ORARIA - Ritenzione: ', CAST(retention_hours AS CHAR), ' ore - Dry run: ', CAST(dry_run AS CHAR)));
-- Conta totale IP nella lista
SELECT COUNT(*) INTO total_ips
FROM ip_list
WHERE list_name = list_name_filter;
-- Conta IP da rimuovere (basato su ore)
SELECT COUNT(*) INTO old_ips
FROM ip_list
WHERE list_name = list_name_filter
AND retrieved_at < DATE_SUB(NOW(), INTERVAL retention_hours HOUR);
-- Prepara messaggio report
SET report_message = CONCAT(
'Lista: ', list_name_filter,
' | Totale IP: ', CAST(total_ips AS CHAR),
' | IP da rimuovere: ', CAST(old_ips AS CHAR),
' | Ritenzione: ', CAST(retention_hours AS CHAR), ' ore'
);
IF old_ips > 0 THEN
IF dry_run = FALSE THEN
-- Esegui pulizia reale
DELETE FROM ip_list
WHERE list_name = list_name_filter
AND retrieved_at < DATE_SUB(NOW(), INTERVAL retention_hours HOUR);
-- Ottieni numero righe eliminate
SET deleted_count = ROW_COUNT();
-- Log successo
INSERT INTO ip_cleanup_log (operation_time, operation_type, list_name,
records_before, records_removed, records_after, status, message)
VALUES (NOW(), 'CLEANUP_HOURS', list_name_filter,
total_ips, deleted_count, (total_ips - deleted_count), 'SUCCESS',
CONCAT(report_message, ' | Rimossi: ', CAST(deleted_count AS CHAR)));
SELECT CONCAT('✅ PULIZIA ORARIA COMPLETATA: Rimossi ', CAST(deleted_count AS CHAR), ' IP dalla lista ', list_name_filter, ' (>', CAST(retention_hours AS CHAR), 'h)') as result;
ELSE
-- Modalità dry run - solo log
INSERT INTO ip_cleanup_log (operation_time, operation_type, list_name,
records_before, records_removed, status, message)
VALUES (NOW(), 'DRY_RUN_HOURS', list_name_filter,
total_ips, old_ips, 'INFO',
CONCAT(report_message, ' | SIMULAZIONE - Nessuna modifica eseguita'));
SELECT CONCAT('🔍 DRY RUN ORARIO: Verrebbero rimossi ', CAST(old_ips AS CHAR), ' IP dalla lista ', list_name_filter, ' (>', CAST(retention_hours AS CHAR), 'h)') as result;
END IF;
ELSE
-- Nessun IP da rimuovere
INSERT INTO ip_cleanup_log (operation_time, operation_type, list_name,
records_before, records_removed, status, message)
VALUES (NOW(), 'CLEANUP_HOURS', list_name_filter,
total_ips, 0, 'INFO',
CONCAT(report_message, ' | Nessun IP da rimuovere'));
SELECT CONCAT(' NESSUNA PULIZIA ORARIA NECESSARIA: Tutti gli IP in ', list_name_filter, ' sono più recenti di ', CAST(retention_hours AS CHAR), ' ore') as result;
END IF;
-- Commit transazione
COMMIT;
END$$
-- Rimuovi procedure esistenti per pulizia giorni
DROP PROCEDURE IF EXISTS cleanup_ddos_ips_fixed$$
-- Procedura per pulizia basata su giorni
CREATE PROCEDURE cleanup_ddos_ips_fixed(
IN retention_days INT,
IN list_name_filter VARCHAR(100),
IN dry_run BOOLEAN
)
BEGIN
DECLARE done INT DEFAULT FALSE;
DECLARE total_ips INT DEFAULT 0;
DECLARE old_ips INT DEFAULT 0;
DECLARE deleted_count INT DEFAULT 0;
DECLARE report_message TEXT DEFAULT '';
-- Gestione errori
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
GET DIAGNOSTICS CONDITION 1
@p1 = RETURNED_SQLSTATE, @p2 = MESSAGE_TEXT;
INSERT INTO ip_cleanup_log (operation_time, operation_type, list_name, status, message)
VALUES (NOW(), 'CLEANUP', list_name_filter, 'ERROR',
CONCAT('ERRORE: ', CAST(@p1 AS CHAR), ' - ', CAST(@p2 AS CHAR)));
END;
-- Gestione valori default
IF retention_days IS NULL THEN
SET retention_days = 7;
END IF;
IF list_name_filter IS NULL OR list_name_filter = '' THEN
SET list_name_filter = 'ddos_detect_v03';
END IF;
IF dry_run IS NULL THEN
SET dry_run = FALSE;
END IF;
-- Inizio transazione
START TRANSACTION;
-- Log inizio operazione
INSERT INTO ip_cleanup_log (operation_time, operation_type, list_name, status, message)
VALUES (NOW(), 'CLEANUP', list_name_filter, 'START',
CONCAT('Inizio pulizia - Ritenzione: ', CAST(retention_days AS CHAR), ' giorni - Dry run: ', CAST(dry_run AS CHAR)));
-- Conta totale IP nella lista
SELECT COUNT(*) INTO total_ips
FROM ip_list
WHERE list_name = list_name_filter;
-- Conta IP da rimuovere
SELECT COUNT(*) INTO old_ips
FROM ip_list
WHERE list_name = list_name_filter
AND retrieved_at < DATE_SUB(NOW(), INTERVAL retention_days DAY);
-- Prepara messaggio report
SET report_message = CONCAT(
'Lista: ', list_name_filter,
' | Totale IP: ', CAST(total_ips AS CHAR),
' | IP da rimuovere: ', CAST(old_ips AS CHAR),
' | Ritenzione: ', CAST(retention_days AS CHAR), ' giorni'
);
IF old_ips > 0 THEN
IF dry_run = FALSE THEN
-- Esegui pulizia reale
DELETE FROM ip_list
WHERE list_name = list_name_filter
AND retrieved_at < DATE_SUB(NOW(), INTERVAL retention_days DAY);
-- Ottieni numero righe eliminate
SET deleted_count = ROW_COUNT();
-- Log successo
INSERT INTO ip_cleanup_log (operation_time, operation_type, list_name,
records_before, records_removed, records_after, status, message)
VALUES (NOW(), 'CLEANUP', list_name_filter,
total_ips, deleted_count, (total_ips - deleted_count), 'SUCCESS',
CONCAT(report_message, ' | Rimossi: ', CAST(deleted_count AS CHAR)));
SELECT CONCAT('✅ PULIZIA COMPLETATA: Rimossi ', CAST(deleted_count AS CHAR), ' IP dalla lista ', list_name_filter) as result;
ELSE
-- Modalità dry run - solo log
INSERT INTO ip_cleanup_log (operation_time, operation_type, list_name,
records_before, records_removed, status, message)
VALUES (NOW(), 'DRY_RUN', list_name_filter,
total_ips, old_ips, 'INFO',
CONCAT(report_message, ' | SIMULAZIONE - Nessuna modifica eseguita'));
SELECT CONCAT('🔍 DRY RUN: Verrebbero rimossi ', CAST(old_ips AS CHAR), ' IP dalla lista ', list_name_filter) as result;
END IF;
ELSE
-- Nessun IP da rimuovere
INSERT INTO ip_cleanup_log (operation_time, operation_type, list_name,
records_before, records_removed, status, message)
VALUES (NOW(), 'CLEANUP', list_name_filter,
total_ips, 0, 'INFO',
CONCAT(report_message, ' | Nessun IP da rimuovere'));
SELECT CONCAT(' NESSUNA PULIZIA NECESSARIA: Tutti gli IP in ', list_name_filter, ' sono recenti') as result;
END IF;
-- Commit transazione
COMMIT;
END$$
-- Procedure wrapper per comandi rapidi
DROP PROCEDURE IF EXISTS cleanup_1h$$
CREATE PROCEDURE cleanup_1h()
BEGIN
CALL cleanup_ddos_ips_hours_fixed(1, 'ddos_detect_v03', FALSE);
END$$
DROP PROCEDURE IF EXISTS cleanup_12h$$
CREATE PROCEDURE cleanup_12h()
BEGIN
CALL cleanup_ddos_ips_hours_fixed(12, 'ddos_detect_v03', FALSE);
END$$
DROP PROCEDURE IF EXISTS cleanup_24h$$
CREATE PROCEDURE cleanup_24h()
BEGIN
CALL cleanup_ddos_ips_hours_fixed(24, 'ddos_detect_v03', FALSE);
END$$
DROP PROCEDURE IF EXISTS cleanup_1h_dry$$
CREATE PROCEDURE cleanup_1h_dry()
BEGIN
CALL cleanup_ddos_ips_hours_fixed(1, 'ddos_detect_v03', TRUE);
END$$
DROP PROCEDURE IF EXISTS cleanup_12h_dry$$
CREATE PROCEDURE cleanup_12h_dry()
BEGIN
CALL cleanup_ddos_ips_hours_fixed(12, 'ddos_detect_v03', TRUE);
END$$
DROP PROCEDURE IF EXISTS cleanup_24h_dry$$
CREATE PROCEDURE cleanup_24h_dry()
BEGIN
CALL cleanup_ddos_ips_hours_fixed(24, 'ddos_detect_v03', TRUE);
END$$
-- Ripristina delimiter originale
DELIMITER ;
-- ============================================
-- ISTRUZIONI POST-INSTALLAZIONE
-- ============================================
-- Verifica installazione
SELECT 'Installazione completata! Procedure disponibili:' as status;
-- Mostra procedure create
SHOW PROCEDURE STATUS WHERE Db = DATABASE() AND Name LIKE 'cleanup%';
-- Comandi di test suggeriti
SELECT '
TEST RAPIDI DISPONIBILI:
-- Simulazioni (dry run):
CALL cleanup_1h_dry();
CALL cleanup_12h_dry();
CALL cleanup_24h_dry();
-- Pulizie reali:
CALL cleanup_1h();
CALL cleanup_12h();
CALL cleanup_24h();
-- Comandi completi:
CALL cleanup_ddos_ips_hours_fixed(6, "ddos_detect_v03", TRUE);
CALL cleanup_ddos_ips_fixed(7, "ddos_detect_v03", FALSE);
' as comandi_test;