-- GuruRMM Clients and Sites Schema -- Adds multi-tenant support with clients, sites, and site-based agent registration -- Clients table (organizations/companies) CREATE TABLE clients ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), name VARCHAR(255) NOT NULL, code VARCHAR(50) UNIQUE, -- Optional short code like "ACME" notes TEXT, is_active BOOLEAN DEFAULT TRUE, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX idx_clients_name ON clients(name); CREATE INDEX idx_clients_code ON clients(code); -- Trigger for clients updated_at CREATE TRIGGER update_clients_updated_at BEFORE UPDATE ON clients FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Sites table (locations under a client) CREATE TABLE sites ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), client_id UUID NOT NULL REFERENCES clients(id) ON DELETE CASCADE, name VARCHAR(255) NOT NULL, -- Site code: human-friendly, used for agent registration (e.g., "BLUE-TIGER-4829") site_code VARCHAR(50) UNIQUE NOT NULL, -- API key hash for this site (all agents at site share this key) api_key_hash VARCHAR(255) NOT NULL, address TEXT, notes TEXT, is_active BOOLEAN DEFAULT TRUE, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX idx_sites_client ON sites(client_id); CREATE INDEX idx_sites_code ON sites(site_code); CREATE INDEX idx_sites_api_key ON sites(api_key_hash); -- Trigger for sites updated_at CREATE TRIGGER update_sites_updated_at BEFORE UPDATE ON sites FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Add new columns to agents table -- device_id: unique hardware-derived identifier for the machine ALTER TABLE agents ADD COLUMN device_id VARCHAR(255); -- site_id: which site this agent belongs to (nullable for legacy agents) ALTER TABLE agents ADD COLUMN site_id UUID REFERENCES sites(id) ON DELETE SET NULL; -- Make api_key_hash nullable (new agents will use site's api_key) ALTER TABLE agents ALTER COLUMN api_key_hash DROP NOT NULL; -- Index for looking up agents by device_id within a site CREATE UNIQUE INDEX idx_agents_site_device ON agents(site_id, device_id) WHERE site_id IS NOT NULL AND device_id IS NOT NULL; -- Index for site lookups CREATE INDEX idx_agents_site ON agents(site_id); -- Registration tokens table (optional: for secure site code distribution) CREATE TABLE registration_tokens ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), site_id UUID NOT NULL REFERENCES sites(id) ON DELETE CASCADE, token_hash VARCHAR(255) NOT NULL, description VARCHAR(255), uses_remaining INTEGER, -- NULL = unlimited expires_at TIMESTAMPTZ, created_at TIMESTAMPTZ DEFAULT NOW(), created_by UUID REFERENCES users(id) ON DELETE SET NULL ); CREATE INDEX idx_reg_tokens_site ON registration_tokens(site_id); CREATE INDEX idx_reg_tokens_hash ON registration_tokens(token_hash); -- Function to generate a random site code (WORD-WORD-####) -- This is just a helper; actual generation should be in application code -- for better word lists CREATE OR REPLACE FUNCTION generate_site_code() RETURNS VARCHAR(50) AS $$ DECLARE words TEXT[] := ARRAY['ALPHA', 'BETA', 'GAMMA', 'DELTA', 'ECHO', 'FOXTROT', 'BLUE', 'GREEN', 'RED', 'GOLD', 'SILVER', 'IRON', 'HAWK', 'EAGLE', 'TIGER', 'LION', 'WOLF', 'BEAR', 'NORTH', 'SOUTH', 'EAST', 'WEST', 'PEAK', 'VALLEY', 'RIVER', 'OCEAN', 'STORM', 'CLOUD', 'STAR', 'MOON']; word1 TEXT; word2 TEXT; num INTEGER; BEGIN word1 := words[1 + floor(random() * array_length(words, 1))::int]; word2 := words[1 + floor(random() * array_length(words, 1))::int]; num := 1000 + floor(random() * 9000)::int; RETURN word1 || '-' || word2 || '-' || num::text; END; $$ LANGUAGE plpgsql;