Files
node-monitor/app/database/schema.sql
2025-04-05 22:41:26 +03:00

151 lines
5.2 KiB
SQL

-- Table for node authentication information (unchanged)
CREATE TABLE IF NOT EXISTS node_auth (
node_id INTEGER PRIMARY KEY AUTOINCREMENT,
node_name TEXT NOT NULL UNIQUE,
api_key TEXT NOT NULL,
auth_token TEXT,
last_auth_timestamp DATETIME,
status TEXT CHECK(status IN ('active', 'inactive', 'pending')) DEFAULT 'pending'
);
CREATE TABLE IF NOT EXISTS admin_keys (
key_id INTEGER PRIMARY KEY AUTOINCREMENT,
api_key TEXT NOT NULL UNIQUE,
description TEXT,
created_at TEXT DEFAULT (datetime('now'))
);
-- Updated table for basic node information with new fields
CREATE TABLE IF NOT EXISTS node_info (
node_id INTEGER PRIMARY KEY,
hostname TEXT NOT NULL,
node_nickname TEXT,
ip_address TEXT,
os_type TEXT,
cpu_cores INTEGER,
total_memory_mb INTEGER,
total_disk_gb INTEGER,
manufacturer TEXT,
model TEXT,
location TEXT,
first_seen DATETIME DEFAULT CURRENT_TIMESTAMP,
last_updated DATETIME,
FOREIGN KEY (node_id) REFERENCES node_auth(node_id) ON DELETE CASCADE
);
-- Table for node-to-node connection metrics
CREATE TABLE IF NOT EXISTS node_connections (
connection_id INTEGER PRIMARY KEY AUTOINCREMENT,
source_node_id INTEGER,
target_node_id INTEGER,
ping_latency_ms REAL,
packet_loss_percent REAL,
timestamp DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (source_node_id) REFERENCES node_auth(node_id),
FOREIGN KEY (target_node_id) REFERENCES node_auth(node_id)
);
-- Timeseries table for CPU usage
CREATE TABLE IF NOT EXISTS cpu_usage (
measurement_id INTEGER PRIMARY KEY AUTOINCREMENT,
node_id INTEGER,
cpu_percent REAL,
cpu_temp_celsius REAL,
timestamp DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (node_id) REFERENCES node_auth(node_id)
);
-- Timeseries table for memory usage
CREATE TABLE IF NOT EXISTS memory_usage (
measurement_id INTEGER PRIMARY KEY AUTOINCREMENT,
node_id INTEGER,
memory_used_mb INTEGER,
memory_free_mb INTEGER,
memory_percent REAL,
timestamp DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (node_id) REFERENCES node_auth(node_id)
);
-- Timeseries table for disk usage
CREATE TABLE IF NOT EXISTS disk_usage (
measurement_id INTEGER PRIMARY KEY AUTOINCREMENT,
node_id INTEGER,
disk_used_gb INTEGER,
disk_free_gb INTEGER,
disk_percent REAL,
partition_name TEXT,
timestamp DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (node_id) REFERENCES node_auth(node_id)
);
-- Table for network usage
CREATE TABLE IF NOT EXISTS network_usage (
measurement_id INTEGER PRIMARY KEY AUTOINCREMENT,
node_id INTEGER,
bytes_sent INTEGER,
bytes_received INTEGER,
packets_sent INTEGER,
packets_received INTEGER,
timestamp DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (node_id) REFERENCES node_auth(node_id)
);
-- Table process monitoring
CREATE TABLE IF NOT EXISTS process_stats (
measurement_id INTEGER PRIMARY KEY AUTOINCREMENT,
node_id INTEGER,
process_count INTEGER,
zombie_process_count INTEGER,
timestamp DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (node_id) REFERENCES node_auth(node_id)
);
-- Table for monitoring configuration and alarm thresholds
CREATE TABLE IF NOT EXISTS monitoring_config (
config_id INTEGER PRIMARY KEY AUTOINCREMENT,
node_id INTEGER,
cpu_threshold_percent REAL,
memory_threshold_percent REAL,
disk_threshold_percent REAL,
temp_threshold_celsius REAL,
network_bytes_threshold INTEGER,
process_count_threshold INTEGER,
ping_latency_threshold_ms REAL,
check_interval_seconds INTEGER DEFAULT 60,
FOREIGN KEY (node_id) REFERENCES node_auth(node_id)
);
-- Table for alarm history
CREATE TABLE IF NOT EXISTS alarm_history (
alarm_id INTEGER PRIMARY KEY AUTOINCREMENT,
node_id INTEGER,
alarm_type TEXT CHECK(alarm_type IN ('cpu', 'memory', 'disk', 'temperature',
'network', 'process', 'latency')),
threshold_value REAL,
actual_value REAL,
alarm_message TEXT,
timestamp DATETIME DEFAULT CURRENT_TIMESTAMP,
acknowledged BOOLEAN DEFAULT FALSE,
FOREIGN KEY (node_id) REFERENCES node_auth(node_id)
);
-- Table for node status events
CREATE TABLE IF NOT EXISTS node_events (
event_id INTEGER PRIMARY KEY AUTOINCREMENT,
node_id INTEGER,
event_type TEXT CHECK(event_type IN ('online', 'offline', 'error', 'warning')),
event_message TEXT,
timestamp DATETIME DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (node_id) REFERENCES node_auth(node_id)
);
-- Updated indexes for better query performance
CREATE INDEX idx_cpu_usage_node_timestamp ON cpu_usage(node_id, timestamp);
CREATE INDEX idx_memory_usage_node_timestamp ON memory_usage(node_id, timestamp);
CREATE INDEX idx_disk_usage_node_timestamp ON disk_usage(node_id, timestamp);
CREATE INDEX idx_network_usage_node_timestamp ON network_usage(node_id, timestamp);
CREATE INDEX idx_process_stats_node_timestamp ON process_stats(node_id, timestamp);
CREATE INDEX idx_node_connections_nodes ON node_connections(source_node_id, target_node_id);
CREATE INDEX idx_node_events_node_timestamp ON node_events(node_id, timestamp);
CREATE INDEX idx_alarm_history_node_timestamp ON alarm_history(node_id, timestamp);