-- Migration 018: Create Chat & MCP Registry tables -- AI assistant with full MCP (Model Context Protocol) server registry -- ==================== MCP SERVER REGISTRY ==================== -- MCP Server definitions CREATE TABLE mcp_servers ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), name VARCHAR(100) NOT NULL UNIQUE, description TEXT, -- Connection config transport_type VARCHAR(20) NOT NULL, -- 'stdio', 'sse', 'websocket' command VARCHAR(500), -- for stdio: command to run args JSONB NOT NULL DEFAULT '[]', -- command arguments env JSONB NOT NULL DEFAULT '{}', -- environment variables url VARCHAR(500), -- for sse/websocket is_active BOOLEAN NOT NULL DEFAULT TRUE, -- Rate limiting rate_limit_per_minute INTEGER CHECK (rate_limit_per_minute > 0), rate_limit_per_hour INTEGER CHECK (rate_limit_per_hour > 0) ); -- Tools provided by MCP servers CREATE TABLE mcp_tools ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), server_id UUID NOT NULL REFERENCES mcp_servers(id) ON DELETE CASCADE, name VARCHAR(100) NOT NULL, description TEXT, input_schema JSONB NOT NULL DEFAULT '{}', is_active BOOLEAN NOT NULL DEFAULT TRUE, UNIQUE (server_id, name) ); -- Role-based permissions for MCP tools CREATE TABLE mcp_tool_permissions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), tool_id UUID NOT NULL REFERENCES mcp_tools(id) ON DELETE CASCADE, role team_role NOT NULL, UNIQUE (tool_id, role) ); -- Per-user tool permissions (override role-based) CREATE TABLE mcp_tool_user_permissions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), tool_id UUID NOT NULL REFERENCES mcp_tools(id) ON DELETE CASCADE, team_profile_id UUID NOT NULL REFERENCES team_profiles(id) ON DELETE CASCADE, is_allowed BOOLEAN NOT NULL, -- explicit allow/deny UNIQUE (tool_id, team_profile_id) ); -- ==================== CHAT (AI ASSISTANT) ==================== -- Chat conversations (AI assistant) CREATE TABLE chat_conversations ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), team_profile_id UUID NOT NULL REFERENCES team_profiles(id) ON DELETE CASCADE, title VARCHAR(255) NOT NULL, is_active BOOLEAN NOT NULL DEFAULT TRUE ); -- Chat messages with tool call tracking CREATE TABLE chat_messages ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), conversation_id UUID NOT NULL REFERENCES chat_conversations(id) ON DELETE CASCADE, role VARCHAR(20) NOT NULL CHECK (role IN ('user', 'assistant', 'tool')), content TEXT, -- For tool calls/results tool_calls JSONB NOT NULL DEFAULT '[]', tool_results JSONB NOT NULL DEFAULT '[]' ); -- ==================== MCP TOOL EXECUTION LOG ==================== -- Tool execution log (for auditing, rate limiting, debugging) CREATE TABLE mcp_tool_executions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(), tool_id UUID NOT NULL REFERENCES mcp_tools(id) ON DELETE CASCADE, team_profile_id UUID NOT NULL REFERENCES team_profiles(id) ON DELETE CASCADE, chat_message_id UUID REFERENCES chat_messages(id) ON DELETE SET NULL, -- Execution details input JSONB NOT NULL, output JSONB, error TEXT, started_at TIMESTAMPTZ NOT NULL, completed_at TIMESTAMPTZ, duration_ms INTEGER CHECK (duration_ms >= 0), status VARCHAR(20) NOT NULL CHECK (status IN ('pending', 'running', 'success', 'error')) ); -- ==================== INDEXES ==================== -- MCP server queries CREATE INDEX idx_mcp_servers_active ON mcp_servers(is_active); -- MCP tool queries CREATE INDEX idx_mcp_tools_server ON mcp_tools(server_id); CREATE INDEX idx_mcp_tools_active ON mcp_tools(is_active); -- Permission lookups CREATE INDEX idx_mcp_tool_permissions_tool ON mcp_tool_permissions(tool_id); CREATE INDEX idx_mcp_tool_permissions_role ON mcp_tool_permissions(role); CREATE INDEX idx_mcp_tool_user_permissions_tool ON mcp_tool_user_permissions(tool_id); CREATE INDEX idx_mcp_tool_user_permissions_user ON mcp_tool_user_permissions(team_profile_id); -- Chat queries CREATE INDEX idx_chat_conversations_user ON chat_conversations(team_profile_id); CREATE INDEX idx_chat_conversations_active ON chat_conversations(team_profile_id, is_active); CREATE INDEX idx_chat_messages_conversation ON chat_messages(conversation_id); CREATE INDEX idx_chat_messages_conversation_created ON chat_messages(conversation_id, created_at DESC); -- Rate limiting queries CREATE INDEX idx_mcp_tool_executions_rate_limit ON mcp_tool_executions (tool_id, team_profile_id, created_at DESC); CREATE INDEX idx_mcp_tool_executions_status ON mcp_tool_executions(status); CREATE INDEX idx_mcp_tool_executions_started ON mcp_tool_executions(started_at DESC);