-- ============================================ -- TABELLA IP_LIST_TEST PER SISTEMA DDoS v04 -- Sistema di test e comparazione avanzato -- ============================================ DROP TABLE IF EXISTS ip_list_test; CREATE TABLE ip_list_test ( id INT AUTO_INCREMENT PRIMARY KEY, list_name VARCHAR(50) NOT NULL, ip_address VARCHAR(45) NOT NULL, risk_level VARCHAR(20) DEFAULT 'MEDIUM', risk_score DECIMAL(5,2) DEFAULT 0.00, -- Score 0-100 confidence_score DECIMAL(5,2) DEFAULT 0.00, -- Confidence 0-100 -- Nuovi campi per sistema avanzato v04 detection_method VARCHAR(100), -- Metodo di detection utilizzato feature_importance TEXT, -- JSON con importance delle feature behavioral_score DECIMAL(5,2) DEFAULT 0.00, context_score DECIMAL(5,2) DEFAULT 0.00, anomaly_type VARCHAR(50), -- Tipo di anomalia rilevata attack_pattern VARCHAR(100), -- Pattern di attacco identificato -- Metadata per analisi source_model VARCHAR(50) DEFAULT 'v04_ensemble', model_version VARCHAR(20) DEFAULT '4.0.0', processing_time_ms INT DEFAULT 0, -- Feedback e learning feedback_status ENUM('pending', 'confirmed_tp', 'confirmed_fp', 'confirmed_tn', 'confirmed_fn') DEFAULT 'pending', feedback_comment TEXT, feedback_operator VARCHAR(50), feedback_timestamp TIMESTAMP NULL, -- Correlazione e context subnet_reputation_score DECIMAL(5,2) DEFAULT 0.00, geo_risk_factor DECIMAL(5,2) DEFAULT 0.00, threat_intel_match BOOLEAN DEFAULT FALSE, related_ips TEXT, -- JSON array di IP correlati -- Tracking temporale avanzato first_seen TIMESTAMP DEFAULT CURRENT_TIMESTAMP, last_seen TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, retrieved_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, expires_at TIMESTAMP NULL, -- Indici per performance UNIQUE KEY unique_ip_list (ip_address, list_name), INDEX idx_risk_score (risk_score DESC), INDEX idx_confidence (confidence_score DESC), INDEX idx_feedback (feedback_status), INDEX idx_retrieved_at (retrieved_at), INDEX idx_expires_at (expires_at), INDEX idx_list_name (list_name), INDEX idx_detection_method (detection_method), INDEX idx_anomaly_type (anomaly_type) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ============================================ -- VISTA PER STATISTICHE AVANZATE -- ============================================ CREATE OR REPLACE VIEW v_ip_test_stats AS SELECT list_name, COUNT(*) as total_ips, AVG(risk_score) as avg_risk_score, AVG(confidence_score) as avg_confidence, AVG(behavioral_score) as avg_behavioral_score, AVG(context_score) as avg_context_score, -- Distribuzione livelli di rischio SUM(CASE WHEN risk_level = 'CRITICO' THEN 1 ELSE 0 END) as critical_count, SUM(CASE WHEN risk_level = 'ALTO' THEN 1 ELSE 0 END) as high_count, SUM(CASE WHEN risk_level = 'MEDIO' THEN 1 ELSE 0 END) as medium_count, SUM(CASE WHEN risk_level = 'BASSO' THEN 1 ELSE 0 END) as low_count, -- Feedback status SUM(CASE WHEN feedback_status = 'confirmed_tp' THEN 1 ELSE 0 END) as true_positives, SUM(CASE WHEN feedback_status = 'confirmed_fp' THEN 1 ELSE 0 END) as false_positives, SUM(CASE WHEN feedback_status = 'pending' THEN 1 ELSE 0 END) as pending_review, -- Performance metrics AVG(processing_time_ms) as avg_processing_time, MAX(processing_time_ms) as max_processing_time, -- Temporal stats MIN(first_seen) as earliest_detection, MAX(last_seen) as latest_activity, COUNT(DISTINCT DATE(first_seen)) as active_days FROM ip_list_test GROUP BY list_name; -- ============================================ -- VISTA PER COMPARAZIONE MODELLI -- ============================================ CREATE OR REPLACE VIEW v_model_comparison AS SELECT model_version, detection_method, COUNT(*) as detections, AVG(risk_score) as avg_risk, AVG(confidence_score) as avg_confidence, AVG(processing_time_ms) as avg_time_ms, -- Accuracy metrics (richiedono feedback) CASE WHEN SUM(CASE WHEN feedback_status IN ('confirmed_tp', 'confirmed_fp') THEN 1 ELSE 0 END) > 0 THEN SUM(CASE WHEN feedback_status = 'confirmed_tp' THEN 1 ELSE 0 END) * 100.0 / SUM(CASE WHEN feedback_status IN ('confirmed_tp', 'confirmed_fp') THEN 1 ELSE 0 END) ELSE NULL END as precision_percentage, SUM(CASE WHEN feedback_status = 'confirmed_tp' THEN 1 ELSE 0 END) as true_positives, SUM(CASE WHEN feedback_status = 'confirmed_fp' THEN 1 ELSE 0 END) as false_positives, SUM(CASE WHEN feedback_status = 'pending' THEN 1 ELSE 0 END) as pending_feedback FROM ip_list_test GROUP BY model_version, detection_method ORDER BY avg_risk DESC, precision_percentage DESC; -- ============================================ -- STORED PROCEDURES PER GESTIONE TEST -- ============================================ DELIMITER $$ CREATE PROCEDURE add_test_detection( IN p_ip_address VARCHAR(45), IN p_list_name VARCHAR(50), IN p_risk_score DECIMAL(5,2), IN p_confidence_score DECIMAL(5,2), IN p_detection_method VARCHAR(100), IN p_anomaly_type VARCHAR(50), IN p_processing_time_ms INT ) BEGIN DECLARE risk_level_calc VARCHAR(20); -- Calcola livello di rischio basato su score SET risk_level_calc = CASE WHEN p_risk_score >= 85 THEN 'CRITICO' WHEN p_risk_score >= 70 THEN 'ALTO' WHEN p_risk_score >= 55 THEN 'MEDIO' WHEN p_risk_score >= 40 THEN 'BASSO' ELSE 'NORMALE' END; INSERT INTO ip_list_test ( ip_address, list_name, risk_score, confidence_score, risk_level, detection_method, anomaly_type, processing_time_ms ) VALUES ( p_ip_address, p_list_name, p_risk_score, p_confidence_score, risk_level_calc, p_detection_method, p_anomaly_type, p_processing_time_ms ) ON DUPLICATE KEY UPDATE risk_score = p_risk_score, confidence_score = p_confidence_score, risk_level = risk_level_calc, detection_method = p_detection_method, anomaly_type = p_anomaly_type, processing_time_ms = p_processing_time_ms, last_seen = CURRENT_TIMESTAMP; END$$ CREATE PROCEDURE add_feedback_test( IN p_ip_address VARCHAR(45), IN p_list_name VARCHAR(50), IN p_feedback_status VARCHAR(20), IN p_feedback_comment TEXT, IN p_operator VARCHAR(50) ) BEGIN UPDATE ip_list_test SET feedback_status = p_feedback_status, feedback_comment = p_feedback_comment, feedback_operator = p_operator, feedback_timestamp = CURRENT_TIMESTAMP WHERE ip_address = p_ip_address AND list_name = p_list_name; SELECT ROW_COUNT() as updated_rows; END$$ CREATE PROCEDURE cleanup_test_data( IN p_hours_old INT DEFAULT 48 ) BEGIN DECLARE rows_deleted INT; DELETE FROM ip_list_test WHERE retrieved_at < DATE_SUB(NOW(), INTERVAL p_hours_old HOUR); SET rows_deleted = ROW_COUNT(); SELECT CONCAT('Deleted ', rows_deleted, ' test records older than ', p_hours_old, ' hours') as result; END$$ DELIMITER ; -- ============================================ -- DATI DI TEST INIZIALI -- ============================================ INSERT INTO ip_list_test (ip_address, list_name, risk_score, confidence_score, detection_method, anomaly_type) VALUES ('192.168.100.1', 'ddos_detect_v04_test', 92.5, 87.3, 'ensemble_behavioral', 'syn_flood'), ('10.0.0.50', 'ddos_detect_v04_test', 78.2, 82.1, 'lstm_sequence', 'port_scan'), ('172.16.1.100', 'ddos_detect_v04_test', 65.8, 75.5, 'isolation_forest_context', 'volume_anomaly'), ('203.45.67.89', 'ddos_detect_v04_test', 43.2, 68.9, 'behavioral_profiling', 'suspicious_pattern'); -- Mostra statistiche iniziali SELECT 'Test table created successfully!' as status; SELECT * FROM v_ip_test_stats WHERE list_name = 'ddos_detect_v04_test';