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
420 lines
16 KiB
SQL
420 lines
16 KiB
SQL
-- ============================================
|
||
-- SCRIPT PULIZIA AUTOMATICA IP - DATABASE SERVER
|
||
-- Sistema DDoS Detection - Pulizia tabella ip_list
|
||
-- ============================================
|
||
|
||
-- Abilita eventi se non già attivi
|
||
SET GLOBAL event_scheduler = ON;
|
||
|
||
-- ============================================
|
||
-- 1. STORED PROCEDURE PER PULIZIA IP (GIORNI)
|
||
-- ============================================
|
||
|
||
DELIMITER //
|
||
|
||
DROP PROCEDURE IF EXISTS cleanup_ddos_ips//
|
||
|
||
CREATE PROCEDURE cleanup_ddos_ips(
|
||
IN retention_days INT DEFAULT 7,
|
||
IN list_name_filter VARCHAR(100) DEFAULT 'ddos_detect_v03',
|
||
IN dry_run BOOLEAN DEFAULT FALSE
|
||
)
|
||
BEGIN
|
||
DECLARE done INT DEFAULT FALSE;
|
||
DECLARE total_ips INT DEFAULT 0;
|
||
DECLARE old_ips INT DEFAULT 0;
|
||
DECLARE deleted_count INT DEFAULT 0;
|
||
|
||
-- Variabili per il report
|
||
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: ', @p2));
|
||
END;
|
||
|
||
-- 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: ', retention_days, ' giorni - Dry run: ', dry_run));
|
||
|
||
-- 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: ', total_ips,
|
||
' | IP da rimuovere: ', old_ips,
|
||
' | Ritenzione: ', retention_days, ' 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: ', deleted_count));
|
||
|
||
SELECT CONCAT('✅ PULIZIA COMPLETATA: Rimossi ', deleted_count, ' 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 ', old_ips, ' 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//
|
||
|
||
-- ============================================
|
||
-- 1.2 STORED PROCEDURE PER PULIZIA IP (ORE) - NUOVA!
|
||
-- ============================================
|
||
|
||
DROP PROCEDURE IF EXISTS cleanup_ddos_ips_hours//
|
||
|
||
CREATE PROCEDURE cleanup_ddos_ips_hours(
|
||
IN retention_hours INT DEFAULT 24,
|
||
IN list_name_filter VARCHAR(100) DEFAULT 'ddos_detect_v03',
|
||
IN dry_run BOOLEAN DEFAULT FALSE
|
||
)
|
||
BEGIN
|
||
DECLARE done INT DEFAULT FALSE;
|
||
DECLARE total_ips INT DEFAULT 0;
|
||
DECLARE old_ips INT DEFAULT 0;
|
||
DECLARE deleted_count INT DEFAULT 0;
|
||
|
||
-- Variabili per il report
|
||
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: ', @p2));
|
||
END;
|
||
|
||
-- 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: ', retention_hours, ' ore - Dry run: ', dry_run));
|
||
|
||
-- 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: ', total_ips,
|
||
' | IP da rimuovere: ', old_ips,
|
||
' | Ritenzione: ', retention_hours, ' 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: ', deleted_count));
|
||
|
||
SELECT CONCAT('✅ PULIZIA ORARIA COMPLETATA: Rimossi ', deleted_count, ' IP dalla lista ', list_name_filter, ' (>', retention_hours, '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 ', old_ips, ' IP dalla lista ', list_name_filter, ' (>', retention_hours, '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 ', retention_hours, ' ore') as result;
|
||
END IF;
|
||
|
||
-- Commit transazione
|
||
COMMIT;
|
||
|
||
END//
|
||
|
||
DELIMITER ;
|
||
|
||
-- ============================================
|
||
-- 2. TABELLA LOG OPERAZIONI PULIZIA (AGGIORNATA)
|
||
-- ============================================
|
||
|
||
DROP TABLE IF EXISTS ip_cleanup_log;
|
||
CREATE TABLE IF NOT EXISTS ip_cleanup_log (
|
||
id INT AUTO_INCREMENT PRIMARY KEY,
|
||
operation_time DATETIME NOT NULL,
|
||
operation_type ENUM('CLEANUP', 'DRY_RUN', 'MAINTENANCE', 'CLEANUP_HOURS', 'DRY_RUN_HOURS') NOT NULL,
|
||
list_name VARCHAR(100) NOT NULL,
|
||
records_before INT DEFAULT 0,
|
||
records_removed INT DEFAULT 0,
|
||
records_after INT DEFAULT 0,
|
||
status ENUM('START', 'SUCCESS', 'ERROR', 'INFO', 'WARNING') NOT NULL,
|
||
message TEXT,
|
||
INDEX idx_operation_time (operation_time),
|
||
INDEX idx_list_name (list_name),
|
||
INDEX idx_status (status),
|
||
INDEX idx_operation_type (operation_type)
|
||
);
|
||
|
||
-- ============================================
|
||
-- 3. EVENTI AUTOMATICI MYSQL
|
||
-- ============================================
|
||
|
||
-- Evento principale: pulizia giornaliera alle 02:00
|
||
DROP EVENT IF EXISTS daily_ddos_cleanup;
|
||
|
||
CREATE EVENT daily_ddos_cleanup
|
||
ON SCHEDULE EVERY 1 DAY
|
||
STARTS TIMESTAMP(CURDATE() + INTERVAL 1 DAY, '02:00:00')
|
||
DO
|
||
BEGIN
|
||
-- Pulizia lista principale (7 giorni)
|
||
CALL cleanup_ddos_ips(7, 'ddos_detect_v03', FALSE);
|
||
|
||
-- Pulizia altre liste se esistono
|
||
CALL cleanup_ddos_ips(10, 'ddos_ia', FALSE);
|
||
CALL cleanup_ddos_ips(15, 'ddos2-attackers', FALSE);
|
||
CALL cleanup_ddos_ips(20, 'ddos3-attackers', FALSE);
|
||
END;
|
||
|
||
-- Evento settimanale: pulizia log vecchi (domenica alle 03:00)
|
||
DROP EVENT IF EXISTS weekly_log_cleanup;
|
||
|
||
CREATE EVENT weekly_log_cleanup
|
||
ON SCHEDULE EVERY 1 WEEK
|
||
STARTS TIMESTAMP(CURDATE() + INTERVAL (7 - WEEKDAY(CURDATE())) DAY, '03:00:00')
|
||
DO
|
||
BEGIN
|
||
-- Rimuovi log di pulizia più vecchi di 30 giorni
|
||
DELETE FROM ip_cleanup_log
|
||
WHERE operation_time < DATE_SUB(NOW(), INTERVAL 30 DAY);
|
||
|
||
-- Log pulizia log
|
||
INSERT INTO ip_cleanup_log (operation_time, operation_type, list_name, status, message)
|
||
VALUES (NOW(), 'MAINTENANCE', 'SYSTEM', 'SUCCESS',
|
||
CONCAT('Pulizia log vecchi completata. Rimossi log più vecchi di 30 giorni.'));
|
||
END;
|
||
|
||
-- ============================================
|
||
-- 4. FUNZIONI DI UTILITÀ (AGGIORNATE)
|
||
-- ============================================
|
||
|
||
DELIMITER //
|
||
|
||
-- Funzione per ottenere statistiche IP con info orarie
|
||
DROP FUNCTION IF EXISTS get_ip_stats//
|
||
|
||
CREATE FUNCTION get_ip_stats(list_name_param VARCHAR(100))
|
||
RETURNS TEXT
|
||
READS SQL DATA
|
||
DETERMINISTIC
|
||
BEGIN
|
||
DECLARE total_count INT DEFAULT 0;
|
||
DECLARE old_count INT DEFAULT 0;
|
||
DECLARE hour_1_count INT DEFAULT 0;
|
||
DECLARE hour_12_count INT DEFAULT 0;
|
||
DECLARE hour_24_count INT DEFAULT 0;
|
||
DECLARE newest_date DATETIME;
|
||
DECLARE oldest_date DATETIME;
|
||
DECLARE result_text TEXT;
|
||
|
||
SELECT COUNT(*),
|
||
MIN(retrieved_at),
|
||
MAX(retrieved_at)
|
||
INTO total_count, oldest_date, newest_date
|
||
FROM ip_list
|
||
WHERE list_name = list_name_param;
|
||
|
||
-- Conta per diverse finestre temporali
|
||
SELECT COUNT(*) INTO old_count
|
||
FROM ip_list
|
||
WHERE list_name = list_name_param
|
||
AND retrieved_at < DATE_SUB(NOW(), INTERVAL 7 DAY);
|
||
|
||
SELECT COUNT(*) INTO hour_1_count
|
||
FROM ip_list
|
||
WHERE list_name = list_name_param
|
||
AND retrieved_at < DATE_SUB(NOW(), INTERVAL 1 HOUR);
|
||
|
||
SELECT COUNT(*) INTO hour_12_count
|
||
FROM ip_list
|
||
WHERE list_name = list_name_param
|
||
AND retrieved_at < DATE_SUB(NOW(), INTERVAL 12 HOUR);
|
||
|
||
SELECT COUNT(*) INTO hour_24_count
|
||
FROM ip_list
|
||
WHERE list_name = list_name_param
|
||
AND retrieved_at < DATE_SUB(NOW(), INTERVAL 24 HOUR);
|
||
|
||
SET result_text = CONCAT(
|
||
'Lista: ', list_name_param,
|
||
' | Totale: ', IFNULL(total_count, 0),
|
||
' | >1h: ', IFNULL(hour_1_count, 0),
|
||
' | >12h: ', IFNULL(hour_12_count, 0),
|
||
' | >24h: ', IFNULL(hour_24_count, 0),
|
||
' | >7gg: ', IFNULL(old_count, 0),
|
||
' | Range: ', IFNULL(oldest_date, 'N/A'), ' - ', IFNULL(newest_date, 'N/A')
|
||
);
|
||
|
||
RETURN result_text;
|
||
END//
|
||
|
||
DELIMITER ;
|
||
|
||
-- ============================================
|
||
-- 5. VISTE DI MONITORAGGIO (AGGIORNATE)
|
||
-- ============================================
|
||
|
||
-- Vista per monitoraggio IP per lista con dettagli orari
|
||
CREATE OR REPLACE VIEW ip_list_summary AS
|
||
SELECT
|
||
list_name,
|
||
COUNT(*) as total_ips,
|
||
COUNT(CASE WHEN retrieved_at >= DATE_SUB(NOW(), INTERVAL 1 HOUR) THEN 1 END) as last_1h,
|
||
COUNT(CASE WHEN retrieved_at >= DATE_SUB(NOW(), INTERVAL 12 HOUR) THEN 1 END) as last_12h,
|
||
COUNT(CASE WHEN retrieved_at >= DATE_SUB(NOW(), INTERVAL 1 DAY) THEN 1 END) as last_24h,
|
||
COUNT(CASE WHEN retrieved_at >= DATE_SUB(NOW(), INTERVAL 7 DAY) THEN 1 END) as last_7d,
|
||
COUNT(CASE WHEN retrieved_at < DATE_SUB(NOW(), INTERVAL 1 HOUR) THEN 1 END) as older_1h,
|
||
COUNT(CASE WHEN retrieved_at < DATE_SUB(NOW(), INTERVAL 12 HOUR) THEN 1 END) as older_12h,
|
||
COUNT(CASE WHEN retrieved_at < DATE_SUB(NOW(), INTERVAL 1 DAY) THEN 1 END) as older_24h,
|
||
COUNT(CASE WHEN retrieved_at < DATE_SUB(NOW(), INTERVAL 7 DAY) THEN 1 END) as older_7d,
|
||
MIN(retrieved_at) as oldest_entry,
|
||
MAX(retrieved_at) as newest_entry,
|
||
risk_level,
|
||
COUNT(*) as count_by_risk
|
||
FROM ip_list
|
||
GROUP BY list_name, risk_level
|
||
ORDER BY list_name, risk_level;
|
||
|
||
-- Vista per log operazioni recenti (include operazioni orarie)
|
||
CREATE OR REPLACE VIEW recent_cleanup_operations AS
|
||
SELECT
|
||
operation_time,
|
||
operation_type,
|
||
list_name,
|
||
records_before,
|
||
records_removed,
|
||
records_after,
|
||
status,
|
||
message
|
||
FROM ip_cleanup_log
|
||
WHERE operation_time >= DATE_SUB(NOW(), INTERVAL 7 DAY)
|
||
ORDER BY operation_time DESC;
|
||
|
||
-- ============================================
|
||
-- 6. QUERY DI VERIFICA E MONITORAGGIO
|
||
-- ============================================
|
||
|
||
-- Query per verificare stato attuale
|
||
SELECT 'STATO ATTUALE IP_LIST CON DETTAGLI ORARI' as info;
|
||
SELECT * FROM ip_list_summary;
|
||
|
||
SELECT '' as spacer;
|
||
SELECT 'EVENTI ATTIVI' as info;
|
||
SHOW EVENTS LIKE '%cleanup%';
|
||
|
||
SELECT '' as spacer;
|
||
SELECT 'ULTIME OPERAZIONI PULIZIA (include orarie)' as info;
|
||
SELECT * FROM recent_cleanup_operations LIMIT 10;
|
||
|
||
-- ============================================
|
||
-- 7. COMANDI DI TEST (AGGIORNATI)
|
||
-- ============================================
|
||
|
||
-- Test dry run per vedere cosa verrebbe pulito (giorni)
|
||
-- CALL cleanup_ddos_ips(7, 'ddos_detect_v03', TRUE);
|
||
|
||
-- Test dry run per vedere cosa verrebbe pulito (ore)
|
||
-- CALL cleanup_ddos_ips_hours(1, 'ddos_detect_v03', TRUE);
|
||
-- CALL cleanup_ddos_ips_hours(12, 'ddos_detect_v03', TRUE);
|
||
-- CALL cleanup_ddos_ips_hours(24, 'ddos_detect_v03', TRUE);
|
||
|
||
-- Esecuzione manuale pulizia
|
||
-- CALL cleanup_ddos_ips(7, 'ddos_detect_v03', FALSE);
|
||
-- CALL cleanup_ddos_ips_hours(1, 'ddos_detect_v03', FALSE);
|
||
|
||
-- Statistiche per lista specifica (con info orarie)
|
||
-- SELECT get_ip_stats('ddos_detect_v03') as stats;
|
||
|
||
-- ============================================
|
||
-- FINE SCRIPT
|
||
-- ============================================ |