Files
claudetools/projects/msp-tools/guru-rmm/server/migrations/001_initial.sql
Mike Swanson 6c316aa701 Add VPN configuration tools and agent documentation
Created comprehensive VPN setup tooling for Peaceful Spirit L2TP/IPsec connection
and enhanced agent documentation framework.

VPN Configuration (PST-NW-VPN):
- Setup-PST-L2TP-VPN.ps1: Automated L2TP/IPsec setup with split-tunnel and DNS
- Connect-PST-VPN.ps1: Connection helper with PPP adapter detection, DNS (192.168.0.2), and route config (192.168.0.0/24)
- Connect-PST-VPN-Standalone.ps1: Self-contained connection script for remote deployment
- Fix-PST-VPN-Auth.ps1: Authentication troubleshooting for CHAP/MSChapv2
- Diagnose-VPN-Interface.ps1: Comprehensive VPN interface and routing diagnostic
- Quick-Test-VPN.ps1: Fast connectivity verification (DNS/router/routes)
- Add-PST-VPN-Route-Manual.ps1: Manual route configuration helper
- vpn-connect.bat, vpn-disconnect.bat: Simple batch file shortcuts
- OpenVPN config files (Windows-compatible, abandoned for L2TP)

Key VPN Implementation Details:
- L2TP creates PPP adapter with connection name as interface description
- UniFi auto-configures DNS (192.168.0.2) but requires manual route to 192.168.0.0/24
- Split-tunnel enabled (only remote traffic through VPN)
- All-user connection for pre-login auto-connect via scheduled task
- Authentication: CHAP + MSChapv2 for UniFi compatibility

Agent Documentation:
- AGENT_QUICK_REFERENCE.md: Quick reference for all specialized agents
- documentation-squire.md: Documentation and task management specialist agent
- Updated all agent markdown files with standardized formatting

Project Organization:
- Moved conversation logs to dedicated directories (guru-connect-conversation-logs, guru-rmm-conversation-logs)
- Cleaned up old session JSONL files from projects/msp-tools/
- Added guru-connect infrastructure (agent, dashboard, proto, scripts, .gitea workflows)
- Added guru-rmm server components and deployment configs

Technical Notes:
- VPN IP pool: 192.168.4.x (client gets 192.168.4.6)
- Remote network: 192.168.0.0/24 (router at 192.168.0.10)
- PSK: rrClvnmUeXEFo90Ol+z7tfsAZHeSK6w7
- Credentials: pst-admin / 24Hearts$

Files: 15 VPN scripts, 2 agent docs, conversation log reorganization,
guru-connect/guru-rmm infrastructure additions

Co-Authored-By: Claude Sonnet 4.5 <noreply@anthropic.com>
2026-01-18 11:51:47 -07:00

123 lines
3.6 KiB
PL/PgSQL

-- 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();