136 lines
5.3 KiB
PL/PgSQL
Executable File
136 lines
5.3 KiB
PL/PgSQL
Executable File
--
|
|
-- API Schema for Remote Access Platform
|
|
-- Isolated from Guacamole schema for security
|
|
--
|
|
|
|
-- Create API schema
|
|
CREATE SCHEMA IF NOT EXISTS api;
|
|
|
|
-- User saved machines
|
|
CREATE TABLE api.user_saved_machines (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
|
|
-- Guacamole user reference (via username, linked to guacamole_entity.name)
|
|
user_id VARCHAR(255) NOT NULL,
|
|
|
|
-- Machine data
|
|
name VARCHAR(255) NOT NULL,
|
|
hostname VARCHAR(255) NOT NULL,
|
|
port INTEGER NOT NULL,
|
|
protocol VARCHAR(50) NOT NULL, -- rdp, ssh, vnc, telnet
|
|
os VARCHAR(255), -- OS (e.g., Windows Server 2019, Ubuntu 22.04)
|
|
|
|
-- Optional credentials (passwords NOT stored, provided per-connection via HTTPS)
|
|
username VARCHAR(255),
|
|
|
|
-- Metadata
|
|
description TEXT,
|
|
tags TEXT[], -- Tag array for grouping
|
|
is_favorite BOOLEAN DEFAULT FALSE,
|
|
|
|
-- Timestamps
|
|
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
last_connected_at TIMESTAMP WITH TIME ZONE,
|
|
|
|
-- Integrity constraints
|
|
CONSTRAINT valid_protocol CHECK (protocol IN ('rdp', 'ssh', 'vnc', 'telnet')),
|
|
CONSTRAINT valid_port CHECK (port > 0 AND port < 65536),
|
|
CONSTRAINT valid_hostname CHECK (char_length(hostname) > 0),
|
|
CONSTRAINT valid_name CHECK (char_length(name) > 0)
|
|
);
|
|
|
|
-- Search indexes
|
|
CREATE INDEX idx_api_user_machines_user_id ON api.user_saved_machines(user_id);
|
|
CREATE INDEX idx_api_user_machines_protocol ON api.user_saved_machines(protocol);
|
|
CREATE INDEX idx_api_user_machines_tags ON api.user_saved_machines USING GIN(tags);
|
|
CREATE INDEX idx_api_user_machines_favorite ON api.user_saved_machines(is_favorite) WHERE is_favorite = TRUE;
|
|
CREATE INDEX idx_api_user_machines_created ON api.user_saved_machines(created_at DESC);
|
|
|
|
-- Auto-update updated_at function
|
|
CREATE OR REPLACE FUNCTION api.update_modified_column()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = NOW();
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Auto-update updated_at trigger
|
|
CREATE TRIGGER update_user_saved_machines_modtime
|
|
BEFORE UPDATE ON api.user_saved_machines
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION api.update_modified_column();
|
|
|
|
-- Connection history (statistics and audit)
|
|
CREATE TABLE api.connection_history (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id VARCHAR(255) NOT NULL,
|
|
machine_id UUID REFERENCES api.user_saved_machines(id) ON DELETE CASCADE,
|
|
|
|
-- Connection data
|
|
connected_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
|
disconnected_at TIMESTAMP WITH TIME ZONE,
|
|
duration_seconds INTEGER,
|
|
|
|
-- Status
|
|
success BOOLEAN DEFAULT TRUE,
|
|
error_message TEXT,
|
|
|
|
-- Metadata
|
|
client_ip VARCHAR(45), -- IPv4/IPv6
|
|
user_agent TEXT
|
|
);
|
|
|
|
-- History indexes
|
|
CREATE INDEX idx_api_connection_history_user_id ON api.connection_history(user_id);
|
|
CREATE INDEX idx_api_connection_history_machine_id ON api.connection_history(machine_id);
|
|
CREATE INDEX idx_api_connection_history_connected_at ON api.connection_history(connected_at DESC);
|
|
|
|
-- User statistics view
|
|
CREATE OR REPLACE VIEW api.user_machine_stats AS
|
|
SELECT
|
|
m.user_id,
|
|
m.id as machine_id,
|
|
m.name,
|
|
m.hostname,
|
|
m.protocol,
|
|
COUNT(h.id) as total_connections,
|
|
MAX(h.connected_at) as last_connection,
|
|
AVG(h.duration_seconds) as avg_duration_seconds,
|
|
SUM(CASE WHEN h.success = TRUE THEN 1 ELSE 0 END) as successful_connections,
|
|
SUM(CASE WHEN h.success = FALSE THEN 1 ELSE 0 END) as failed_connections
|
|
FROM
|
|
api.user_saved_machines m
|
|
LEFT JOIN
|
|
api.connection_history h ON m.id = h.machine_id
|
|
GROUP BY
|
|
m.user_id, m.id, m.name, m.hostname, m.protocol;
|
|
|
|
-- Documentation comments
|
|
COMMENT ON SCHEMA api IS 'API-specific tables, isolated from Guacamole schema';
|
|
COMMENT ON TABLE api.user_saved_machines IS 'User-saved machines for quick access. Passwords are NOT stored - provided per-connection via HTTPS.';
|
|
COMMENT ON TABLE api.connection_history IS 'Audit log of all connections to saved machines';
|
|
COMMENT ON COLUMN api.user_saved_machines.tags IS 'Array of tags for categorization (e.g., ["production", "web-servers"])';
|
|
COMMENT ON VIEW api.user_machine_stats IS 'Aggregated statistics per machine per user';
|
|
|
|
-- Application grants (if using separate user)
|
|
-- GRANT USAGE ON SCHEMA api TO guacamole_user;
|
|
-- GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA api TO guacamole_user;
|
|
-- GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA api TO guacamole_user;
|
|
-- GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA api TO guacamole_user;
|
|
|
|
-- Test data (remove in production)
|
|
-- INSERT INTO api.user_saved_machines (user_id, name, hostname, port, protocol, os, username, description, tags) VALUES
|
|
-- ('guacadmin', 'Test Windows Server', '192.168.1.100', 3389, 'rdp', 'Windows Server 2019', 'Administrator', 'Windows test machine', ARRAY['test', 'windows']),
|
|
-- ('guacadmin', 'Test Linux Server', '192.168.1.101', 22, 'ssh', 'Ubuntu 22.04 LTS', 'root', 'Ubuntu server for testing', ARRAY['test', 'linux']);
|
|
|
|
-- Migration completion
|
|
DO $$
|
|
BEGIN
|
|
RAISE NOTICE 'API schema created successfully';
|
|
RAISE NOTICE 'Tables: user_saved_machines, connection_history';
|
|
RAISE NOTICE 'View: user_machine_stats';
|
|
END $$;
|
|
|