Desplegadas tablas de contexto IA en architect (69.62.126.110) y corp (92.112.181.188). Cambios: - Schema completo con 5 tablas: ia_contexts, ia_messages, ia_embeddings, ia_tool_calls, ia_context_metrics - Vista ia_context_summary para consultas agregadas - 2 funciones PL/pgSQL y triggers para actualización automática - 13 índices optimizados para consultas frecuentes - Script de despliegue automatizado - Documentación completa del deployment Tests: - ✅ architect: Tablas funcionando, triggers activos - ✅ corp: Tablas funcionando, triggers activos - ⚠️ deck: Servidor no disponible (pendiente) 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Sonnet 4.5 <noreply@anthropic.com>
154 lines
5.7 KiB
PL/PgSQL
154 lines
5.7 KiB
PL/PgSQL
-- Schema de tablas de contexto IA para sistema TZZR
|
|
-- Desplegado en: architect, deck, corp
|
|
-- Fecha: 2024-12-23
|
|
-- Arquitecto: ARCHITECT
|
|
|
|
-- Tabla principal de contextos de conversación
|
|
CREATE TABLE IF NOT EXISTS ia_contexts (
|
|
id SERIAL PRIMARY KEY,
|
|
context_id VARCHAR(255) UNIQUE NOT NULL,
|
|
agent_name VARCHAR(100) NOT NULL,
|
|
user_id VARCHAR(100),
|
|
session_id VARCHAR(255),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
metadata JSONB DEFAULT '{}',
|
|
status VARCHAR(50) DEFAULT 'active',
|
|
CONSTRAINT check_status CHECK (status IN ('active', 'archived', 'deleted'))
|
|
);
|
|
|
|
-- Tabla de mensajes de conversación
|
|
CREATE TABLE IF NOT EXISTS ia_messages (
|
|
id SERIAL PRIMARY KEY,
|
|
context_id VARCHAR(255) NOT NULL REFERENCES ia_contexts(context_id) ON DELETE CASCADE,
|
|
role VARCHAR(50) NOT NULL,
|
|
content TEXT NOT NULL,
|
|
timestamp TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
token_count INTEGER,
|
|
model VARCHAR(100),
|
|
metadata JSONB DEFAULT '{}',
|
|
CONSTRAINT check_role CHECK (role IN ('user', 'assistant', 'system', 'tool'))
|
|
);
|
|
|
|
-- Tabla de embeddings para búsqueda semántica
|
|
CREATE TABLE IF NOT EXISTS ia_embeddings (
|
|
id SERIAL PRIMARY KEY,
|
|
context_id VARCHAR(255) NOT NULL REFERENCES ia_contexts(context_id) ON DELETE CASCADE,
|
|
message_id INTEGER REFERENCES ia_messages(id) ON DELETE CASCADE,
|
|
embedding_vector FLOAT8[],
|
|
content_hash VARCHAR(64) UNIQUE,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
metadata JSONB DEFAULT '{}'
|
|
);
|
|
|
|
-- Tabla de herramientas usadas
|
|
CREATE TABLE IF NOT EXISTS ia_tool_calls (
|
|
id SERIAL PRIMARY KEY,
|
|
context_id VARCHAR(255) NOT NULL REFERENCES ia_contexts(context_id) ON DELETE CASCADE,
|
|
message_id INTEGER REFERENCES ia_messages(id) ON DELETE CASCADE,
|
|
tool_name VARCHAR(100) NOT NULL,
|
|
tool_input JSONB,
|
|
tool_output TEXT,
|
|
execution_time_ms INTEGER,
|
|
success BOOLEAN DEFAULT true,
|
|
error_message TEXT,
|
|
timestamp TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Tabla de métricas de contexto
|
|
CREATE TABLE IF NOT EXISTS ia_context_metrics (
|
|
id SERIAL PRIMARY KEY,
|
|
context_id VARCHAR(255) UNIQUE NOT NULL REFERENCES ia_contexts(context_id) ON DELETE CASCADE,
|
|
total_messages INTEGER DEFAULT 0,
|
|
total_tokens INTEGER DEFAULT 0,
|
|
total_tool_calls INTEGER DEFAULT 0,
|
|
avg_response_time_ms INTEGER,
|
|
last_activity TIMESTAMP,
|
|
metadata JSONB DEFAULT '{}'
|
|
);
|
|
|
|
-- Índices para optimizar consultas
|
|
CREATE INDEX IF NOT EXISTS idx_ia_contexts_agent ON ia_contexts(agent_name);
|
|
CREATE INDEX IF NOT EXISTS idx_ia_contexts_session ON ia_contexts(session_id);
|
|
CREATE INDEX IF NOT EXISTS idx_ia_contexts_created ON ia_contexts(created_at);
|
|
CREATE INDEX IF NOT EXISTS idx_ia_contexts_status ON ia_contexts(status);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_ia_messages_context ON ia_messages(context_id);
|
|
CREATE INDEX IF NOT EXISTS idx_ia_messages_timestamp ON ia_messages(timestamp);
|
|
CREATE INDEX IF NOT EXISTS idx_ia_messages_role ON ia_messages(role);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_ia_embeddings_context ON ia_embeddings(context_id);
|
|
CREATE INDEX IF NOT EXISTS idx_ia_embeddings_hash ON ia_embeddings(content_hash);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_ia_tool_calls_context ON ia_tool_calls(context_id);
|
|
CREATE INDEX IF NOT EXISTS idx_ia_tool_calls_tool ON ia_tool_calls(tool_name);
|
|
CREATE INDEX IF NOT EXISTS idx_ia_tool_calls_timestamp ON ia_tool_calls(timestamp);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_ia_context_metrics_context ON ia_context_metrics(context_id);
|
|
|
|
-- Función para actualizar updated_at automáticamente
|
|
CREATE OR REPLACE FUNCTION update_ia_contexts_updated_at()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = CURRENT_TIMESTAMP;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Trigger para updated_at
|
|
DROP TRIGGER IF EXISTS trigger_update_ia_contexts_updated_at ON ia_contexts;
|
|
CREATE TRIGGER trigger_update_ia_contexts_updated_at
|
|
BEFORE UPDATE ON ia_contexts
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_ia_contexts_updated_at();
|
|
|
|
-- Función para actualizar métricas de contexto
|
|
CREATE OR REPLACE FUNCTION update_ia_context_metrics()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
INSERT INTO ia_context_metrics (context_id, total_messages, last_activity)
|
|
VALUES (NEW.context_id, 1, NEW.timestamp)
|
|
ON CONFLICT (context_id) DO UPDATE SET
|
|
total_messages = ia_context_metrics.total_messages + 1,
|
|
total_tokens = COALESCE(ia_context_metrics.total_tokens, 0) + COALESCE(NEW.token_count, 0),
|
|
last_activity = NEW.timestamp;
|
|
RETURN NEW;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Trigger para actualizar métricas cuando se agrega un mensaje
|
|
DROP TRIGGER IF EXISTS trigger_update_ia_context_metrics ON ia_messages;
|
|
CREATE TRIGGER trigger_update_ia_context_metrics
|
|
AFTER INSERT ON ia_messages
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION update_ia_context_metrics();
|
|
|
|
-- Vistas útiles
|
|
CREATE OR REPLACE VIEW ia_context_summary AS
|
|
SELECT
|
|
c.context_id,
|
|
c.agent_name,
|
|
c.session_id,
|
|
c.created_at,
|
|
c.updated_at,
|
|
c.status,
|
|
COALESCE(m.total_messages, 0) as message_count,
|
|
COALESCE(m.total_tokens, 0) as total_tokens,
|
|
COALESCE(m.total_tool_calls, 0) as tool_calls,
|
|
m.last_activity
|
|
FROM ia_contexts c
|
|
LEFT JOIN ia_context_metrics m ON c.context_id = m.context_id;
|
|
|
|
-- Comentarios en tablas
|
|
COMMENT ON TABLE ia_contexts IS 'Contextos de conversación de agentes IA';
|
|
COMMENT ON TABLE ia_messages IS 'Mensajes de conversación con agentes IA';
|
|
COMMENT ON TABLE ia_embeddings IS 'Embeddings vectoriales para búsqueda semántica';
|
|
COMMENT ON TABLE ia_tool_calls IS 'Registro de llamadas a herramientas';
|
|
COMMENT ON TABLE ia_context_metrics IS 'Métricas agregadas por contexto';
|
|
|
|
-- Grant permisos (ajustar según usuarios de cada servidor)
|
|
-- En architect: postgres usuario por defecto
|
|
-- En deck/corp: usuarios específicos
|
|
|
|
-- Fin del schema
|