-- GuruRMM Initial Schema -- Creates tables for agents, metrics, commands, watchdog events, and users -- Enable UUID extension CREATE EXTENSION IF NOT EXISTS "pgcrypto"; -- Agents table -- Stores registered agents and their current status CREATE TABLE agents ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), hostname VARCHAR(255) NOT NULL, api_key_hash VARCHAR(255) NOT NULL, os_type VARCHAR(50) NOT NULL, os_version VARCHAR(100), agent_version VARCHAR(50), last_seen TIMESTAMPTZ, status VARCHAR(20) DEFAULT 'offline', created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); -- Index for looking up agents by hostname CREATE INDEX idx_agents_hostname ON agents(hostname); -- Index for finding online agents CREATE INDEX idx_agents_status ON agents(status); -- Metrics table -- Time-series data for system metrics from agents CREATE TABLE metrics ( id BIGSERIAL PRIMARY KEY, agent_id UUID NOT NULL REFERENCES agents(id) ON DELETE CASCADE, timestamp TIMESTAMPTZ DEFAULT NOW(), cpu_percent REAL, memory_percent REAL, memory_used_bytes BIGINT, disk_percent REAL, disk_used_bytes BIGINT, network_rx_bytes BIGINT, network_tx_bytes BIGINT ); -- Index for querying metrics by agent and time CREATE INDEX idx_metrics_agent_time ON metrics(agent_id, timestamp DESC); -- Index for finding recent metrics CREATE INDEX idx_metrics_timestamp ON metrics(timestamp DESC); -- Users table -- Dashboard users for authentication CREATE TABLE users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), email VARCHAR(255) UNIQUE NOT NULL, password_hash VARCHAR(255), name VARCHAR(255), role VARCHAR(50) DEFAULT 'user', sso_provider VARCHAR(50), sso_id VARCHAR(255), created_at TIMESTAMPTZ DEFAULT NOW(), last_login TIMESTAMPTZ ); -- Index for email lookups during login CREATE INDEX idx_users_email ON users(email); -- Index for SSO lookups CREATE INDEX idx_users_sso ON users(sso_provider, sso_id); -- Commands table -- Commands sent to agents and their results CREATE TABLE commands ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), agent_id UUID NOT NULL REFERENCES agents(id) ON DELETE CASCADE, command_type VARCHAR(50) NOT NULL, command_text TEXT NOT NULL, status VARCHAR(20) DEFAULT 'pending', exit_code INTEGER, stdout TEXT, stderr TEXT, created_at TIMESTAMPTZ DEFAULT NOW(), started_at TIMESTAMPTZ, completed_at TIMESTAMPTZ, created_by UUID REFERENCES users(id) ON DELETE SET NULL ); -- Index for finding pending commands for an agent CREATE INDEX idx_commands_agent_status ON commands(agent_id, status); -- Index for command history queries CREATE INDEX idx_commands_created ON commands(created_at DESC); -- Watchdog events table -- Events from agent watchdog monitoring CREATE TABLE watchdog_events ( id BIGSERIAL PRIMARY KEY, agent_id UUID NOT NULL REFERENCES agents(id) ON DELETE CASCADE, timestamp TIMESTAMPTZ DEFAULT NOW(), service_name VARCHAR(255) NOT NULL, event_type VARCHAR(50) NOT NULL, details TEXT ); -- Index for querying events by agent and time CREATE INDEX idx_watchdog_agent_time ON watchdog_events(agent_id, timestamp DESC); -- Index for finding recent events CREATE INDEX idx_watchdog_timestamp ON watchdog_events(timestamp DESC); -- Function to update updated_at timestamp CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Trigger for agents table CREATE TRIGGER update_agents_updated_at BEFORE UPDATE ON agents FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();