-- Migration 005: Create network_analytics table for permanent traffic statistics -- This table stores aggregated traffic data (normal + attacks) with hourly and daily granularity -- Data persists beyond the 3-day log retention for long-term analytics CREATE TABLE IF NOT EXISTS network_analytics ( id VARCHAR PRIMARY KEY DEFAULT gen_random_uuid(), date TIMESTAMP NOT NULL, hour INT, -- NULL = daily aggregation, 0-23 = hourly -- Total traffic metrics total_packets INT NOT NULL DEFAULT 0, total_bytes BIGINT NOT NULL DEFAULT 0, unique_ips INT NOT NULL DEFAULT 0, -- Normal traffic (non-anomalous) normal_packets INT NOT NULL DEFAULT 0, normal_bytes BIGINT NOT NULL DEFAULT 0, normal_unique_ips INT NOT NULL DEFAULT 0, top_normal_ips TEXT, -- JSON: [{ip, packets, bytes, country}] -- Attack/Anomaly traffic attack_packets INT NOT NULL DEFAULT 0, attack_bytes BIGINT NOT NULL DEFAULT 0, attack_unique_ips INT NOT NULL DEFAULT 0, attacks_by_country TEXT, -- JSON: {IT: 5, RU: 30, ...} attacks_by_type TEXT, -- JSON: {ddos: 10, port_scan: 5, ...} top_attackers TEXT, -- JSON: [{ip, country, risk_score, packets}] -- Geographic distribution (all traffic) traffic_by_country TEXT, -- JSON: {IT: {normal: 100, attacks: 5}, ...} created_at TIMESTAMP NOT NULL DEFAULT NOW(), -- Ensure unique aggregation per date/hour UNIQUE(date, hour) ); -- Indexes for fast queries CREATE INDEX IF NOT EXISTS network_analytics_date_hour_idx ON network_analytics(date, hour); CREATE INDEX IF NOT EXISTS network_analytics_date_idx ON network_analytics(date); -- Update schema version INSERT INTO schema_version (version, description) VALUES (5, 'Create network_analytics table for traffic statistics') ON CONFLICT (id) DO UPDATE SET version = 5, description = 'Create network_analytics table for traffic statistics', applied_at = NOW();