WIP: Save current work before CHORUS rebrand
- Agent roles integration progress - Various backend and frontend updates - Storybook cache cleanup 🤖 Generated with [Claude Code](https://claude.ai/code) Co-Authored-By: Claude <noreply@anthropic.com>
This commit is contained in:
241
backend/migrations/007_add_cluster_registration.sql
Normal file
241
backend/migrations/007_add_cluster_registration.sql
Normal file
@@ -0,0 +1,241 @@
|
||||
-- Cluster Registration Migration
|
||||
-- Implements the registration-based cluster architecture for Hive-Bzzz integration
|
||||
-- Version: 1.0
|
||||
-- Date: 2025-07-31
|
||||
|
||||
-- =============================================================================
|
||||
-- CLUSTER REGISTRATION SYSTEM
|
||||
-- =============================================================================
|
||||
|
||||
-- Cluster registration tokens (similar to Docker Swarm tokens)
|
||||
CREATE TABLE cluster_tokens (
|
||||
id SERIAL PRIMARY KEY,
|
||||
token VARCHAR(64) UNIQUE NOT NULL,
|
||||
description TEXT,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
expires_at TIMESTAMP WITH TIME ZONE,
|
||||
is_active BOOLEAN DEFAULT true,
|
||||
created_by UUID REFERENCES users(id) ON DELETE SET NULL,
|
||||
|
||||
-- Token metadata
|
||||
max_registrations INTEGER DEFAULT NULL, -- NULL = unlimited
|
||||
current_registrations INTEGER DEFAULT 0,
|
||||
|
||||
-- IP restrictions (optional)
|
||||
allowed_ip_ranges TEXT[], -- CIDR ranges like ['192.168.1.0/24']
|
||||
|
||||
CONSTRAINT valid_token_format CHECK (token ~ '^[a-zA-Z0-9_-]{32,64}$')
|
||||
);
|
||||
|
||||
-- Registered cluster nodes (dynamic discovery)
|
||||
CREATE TABLE cluster_nodes (
|
||||
id SERIAL PRIMARY KEY,
|
||||
node_id VARCHAR(64) UNIQUE NOT NULL,
|
||||
hostname VARCHAR(255) NOT NULL,
|
||||
ip_address INET NOT NULL,
|
||||
registration_token VARCHAR(64) REFERENCES cluster_tokens(token) ON DELETE CASCADE,
|
||||
|
||||
-- Hardware information (reported by client)
|
||||
cpu_info JSONB,
|
||||
memory_info JSONB,
|
||||
gpu_info JSONB,
|
||||
disk_info JSONB,
|
||||
|
||||
-- System information
|
||||
os_info JSONB,
|
||||
platform_info JSONB,
|
||||
|
||||
-- Status tracking
|
||||
status VARCHAR(20) DEFAULT 'online' CHECK (status IN ('online', 'offline', 'maintenance', 'error')),
|
||||
last_heartbeat TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
first_registered TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
|
||||
-- Services and capabilities
|
||||
services JSONB, -- Available services like ollama, docker, etc.
|
||||
capabilities JSONB, -- Available models, tools, etc.
|
||||
|
||||
-- Network information
|
||||
ports JSONB, -- Service ports like {"ollama": 11434, "cockpit": 9090}
|
||||
|
||||
-- Registration metadata
|
||||
client_version VARCHAR(50),
|
||||
registration_metadata JSONB,
|
||||
|
||||
CONSTRAINT valid_node_id_format CHECK (node_id ~ '^[a-zA-Z0-9_-]+$'),
|
||||
CONSTRAINT valid_status CHECK (status IN ('online', 'offline', 'maintenance', 'error'))
|
||||
);
|
||||
|
||||
-- Node heartbeat history (for performance tracking)
|
||||
CREATE TABLE node_heartbeats (
|
||||
id SERIAL PRIMARY KEY,
|
||||
node_id VARCHAR(64) REFERENCES cluster_nodes(node_id) ON DELETE CASCADE,
|
||||
heartbeat_time TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
|
||||
-- Runtime metrics
|
||||
cpu_usage FLOAT,
|
||||
memory_usage FLOAT,
|
||||
disk_usage FLOAT,
|
||||
gpu_usage FLOAT,
|
||||
|
||||
-- Service status
|
||||
services_status JSONB,
|
||||
|
||||
-- Network metrics
|
||||
network_metrics JSONB,
|
||||
|
||||
-- Custom metrics from client
|
||||
custom_metrics JSONB
|
||||
);
|
||||
|
||||
-- Node registration attempts (for security monitoring)
|
||||
CREATE TABLE node_registration_attempts (
|
||||
id SERIAL PRIMARY KEY,
|
||||
attempted_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
|
||||
|
||||
-- Request information
|
||||
ip_address INET NOT NULL,
|
||||
user_agent TEXT,
|
||||
token_used VARCHAR(64),
|
||||
node_id VARCHAR(64),
|
||||
hostname VARCHAR(255),
|
||||
|
||||
-- Result
|
||||
success BOOLEAN NOT NULL,
|
||||
failure_reason TEXT,
|
||||
|
||||
-- Security metadata
|
||||
request_metadata JSONB
|
||||
);
|
||||
|
||||
-- =============================================================================
|
||||
-- INDEXES FOR PERFORMANCE
|
||||
-- =============================================================================
|
||||
|
||||
-- Token lookup and validation
|
||||
CREATE INDEX idx_cluster_tokens_token ON cluster_tokens(token) WHERE is_active = true;
|
||||
CREATE INDEX idx_cluster_tokens_active ON cluster_tokens(is_active, expires_at);
|
||||
|
||||
-- Node lookups and status queries
|
||||
CREATE INDEX idx_cluster_nodes_node_id ON cluster_nodes(node_id);
|
||||
CREATE INDEX idx_cluster_nodes_status ON cluster_nodes(status);
|
||||
CREATE INDEX idx_cluster_nodes_last_heartbeat ON cluster_nodes(last_heartbeat);
|
||||
CREATE INDEX idx_cluster_nodes_token ON cluster_nodes(registration_token);
|
||||
|
||||
-- Heartbeat queries (time-series data)
|
||||
CREATE INDEX idx_node_heartbeats_node_time ON node_heartbeats(node_id, heartbeat_time DESC);
|
||||
CREATE INDEX idx_node_heartbeats_time ON node_heartbeats(heartbeat_time DESC);
|
||||
|
||||
-- Security monitoring
|
||||
CREATE INDEX idx_registration_attempts_ip_time ON node_registration_attempts(ip_address, attempted_at DESC);
|
||||
CREATE INDEX idx_registration_attempts_success ON node_registration_attempts(success, attempted_at DESC);
|
||||
|
||||
-- =============================================================================
|
||||
-- FUNCTIONS AND TRIGGERS
|
||||
-- =============================================================================
|
||||
|
||||
-- Function to update token registration count
|
||||
CREATE OR REPLACE FUNCTION update_token_registration_count()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
IF TG_OP = 'INSERT' THEN
|
||||
UPDATE cluster_tokens
|
||||
SET current_registrations = current_registrations + 1
|
||||
WHERE token = NEW.registration_token;
|
||||
RETURN NEW;
|
||||
ELSIF TG_OP = 'DELETE' THEN
|
||||
UPDATE cluster_tokens
|
||||
SET current_registrations = current_registrations - 1
|
||||
WHERE token = OLD.registration_token;
|
||||
RETURN OLD;
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Trigger to maintain registration counts
|
||||
CREATE TRIGGER trigger_update_token_count
|
||||
AFTER INSERT OR DELETE ON cluster_nodes
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_token_registration_count();
|
||||
|
||||
-- Function to clean up old heartbeats (data retention)
|
||||
CREATE OR REPLACE FUNCTION cleanup_old_heartbeats()
|
||||
RETURNS INTEGER AS $$
|
||||
DECLARE
|
||||
deleted_count INTEGER;
|
||||
BEGIN
|
||||
DELETE FROM node_heartbeats
|
||||
WHERE heartbeat_time < NOW() - INTERVAL '30 days';
|
||||
|
||||
GET DIAGNOSTICS deleted_count = ROW_COUNT;
|
||||
RETURN deleted_count;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Function to update node status based on heartbeat
|
||||
CREATE OR REPLACE FUNCTION update_node_status()
|
||||
RETURNS INTEGER AS $$
|
||||
DECLARE
|
||||
updated_count INTEGER;
|
||||
BEGIN
|
||||
-- Mark nodes as offline if no heartbeat in 5 minutes
|
||||
UPDATE cluster_nodes
|
||||
SET status = 'offline'
|
||||
WHERE status = 'online'
|
||||
AND last_heartbeat < NOW() - INTERVAL '5 minutes';
|
||||
|
||||
GET DIAGNOSTICS updated_count = ROW_COUNT;
|
||||
RETURN updated_count;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- =============================================================================
|
||||
-- INITIAL DATA (for development/testing)
|
||||
-- =============================================================================
|
||||
|
||||
-- Insert development cluster token
|
||||
INSERT INTO cluster_tokens (token, description, created_by)
|
||||
VALUES (
|
||||
'hive_dev_cluster_token_12345678901234567890123456789012',
|
||||
'Development cluster token for testing',
|
||||
(SELECT id FROM users WHERE username = 'admin' LIMIT 1)
|
||||
) ON CONFLICT (token) DO NOTHING;
|
||||
|
||||
-- Insert production cluster token (should be changed in production)
|
||||
INSERT INTO cluster_tokens (token, description, created_by, expires_at)
|
||||
VALUES (
|
||||
'hive_prod_cluster_token_98765432109876543210987654321098',
|
||||
'Production cluster token - CHANGE THIS IN PRODUCTION',
|
||||
(SELECT id FROM users WHERE username = 'admin' LIMIT 1),
|
||||
NOW() + INTERVAL '1 year'
|
||||
) ON CONFLICT (token) DO NOTHING;
|
||||
|
||||
-- =============================================================================
|
||||
-- COMMENTS AND DOCUMENTATION
|
||||
-- =============================================================================
|
||||
|
||||
COMMENT ON TABLE cluster_tokens IS 'Registration tokens for cluster nodes to join the Hive cluster';
|
||||
COMMENT ON TABLE cluster_nodes IS 'Dynamically registered cluster nodes with hardware and capability information';
|
||||
COMMENT ON TABLE node_heartbeats IS 'Heartbeat history for performance monitoring and status tracking';
|
||||
COMMENT ON TABLE node_registration_attempts IS 'Security log of all node registration attempts';
|
||||
|
||||
COMMENT ON COLUMN cluster_tokens.token IS 'Unique token for node registration, format: hive_[env]_cluster_token_[random]';
|
||||
COMMENT ON COLUMN cluster_tokens.max_registrations IS 'Maximum number of nodes that can use this token (NULL = unlimited)';
|
||||
COMMENT ON COLUMN cluster_tokens.allowed_ip_ranges IS 'CIDR ranges that can use this token (NULL = any IP)';
|
||||
|
||||
COMMENT ON COLUMN cluster_nodes.node_id IS 'Unique identifier for the node (hostname-uuid format recommended)';
|
||||
COMMENT ON COLUMN cluster_nodes.cpu_info IS 'CPU information: {"cores": 8, "model": "AMD Ryzen 7", "architecture": "x86_64"}';
|
||||
COMMENT ON COLUMN cluster_nodes.memory_info IS 'Memory information: {"total_gb": 64, "available_gb": 32, "type": "DDR4"}';
|
||||
COMMENT ON COLUMN cluster_nodes.gpu_info IS 'GPU information: {"model": "NVIDIA RTX 2080S", "memory_gb": 8, "driver": "535.86.05"}';
|
||||
COMMENT ON COLUMN cluster_nodes.services IS 'Available services: {"ollama": {"version": "0.1.7", "port": 11434}, "docker": {"version": "24.0.6"}}';
|
||||
COMMENT ON COLUMN cluster_nodes.capabilities IS 'Node capabilities: {"models": ["llama2", "codellama"], "max_concurrent": 4}';
|
||||
|
||||
-- Migration completion notice
|
||||
DO $$
|
||||
BEGIN
|
||||
RAISE NOTICE 'Cluster registration migration completed successfully!';
|
||||
RAISE NOTICE 'Development token: hive_dev_cluster_token_12345678901234567890123456789012';
|
||||
RAISE NOTICE 'Production token: hive_prod_cluster_token_98765432109876543210987654321098';
|
||||
RAISE NOTICE 'SECURITY WARNING: Change production tokens before deployment!';
|
||||
END
|
||||
$$;
|
||||
Reference in New Issue
Block a user