Initial commit - Captain Claude multiagent system
- Core captain_claude.py orchestrator - Context manager with SQL schemas - Provider adapters (Anthropic, OpenAI) - Execution scripts
This commit is contained in:
39
context-manager/schemas/00_base.sql
Normal file
39
context-manager/schemas/00_base.sql
Normal file
@@ -0,0 +1,39 @@
|
||||
-- ============================================
|
||||
-- CONTEXT MANAGER - BASE TYPES
|
||||
-- Sistema local de gestión de contexto para IA
|
||||
-- ============================================
|
||||
|
||||
-- Extension para UUIDs
|
||||
CREATE EXTENSION IF NOT EXISTS "pgcrypto";
|
||||
|
||||
-- ============================================
|
||||
-- TIPOS ENUMERADOS
|
||||
-- ============================================
|
||||
|
||||
CREATE TYPE mensaje_role AS ENUM ('user', 'assistant', 'system', 'tool');
|
||||
CREATE TYPE context_source AS ENUM ('memory', 'knowledge', 'history', 'ambient', 'dataset');
|
||||
CREATE TYPE algorithm_status AS ENUM ('draft', 'testing', 'active', 'deprecated');
|
||||
CREATE TYPE metric_type AS ENUM ('relevance', 'token_efficiency', 'response_quality', 'latency');
|
||||
|
||||
-- ============================================
|
||||
-- FUNCIÓN: Timestamp de actualización
|
||||
-- ============================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = CURRENT_TIMESTAMP;
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- ============================================
|
||||
-- FUNCIÓN: Hash SHA-256
|
||||
-- ============================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION sha256_hash(content TEXT)
|
||||
RETURNS VARCHAR(64) AS $$
|
||||
BEGIN
|
||||
RETURN encode(digest(content, 'sha256'), 'hex');
|
||||
END;
|
||||
$$ LANGUAGE plpgsql IMMUTABLE;
|
||||
276
context-manager/schemas/01_immutable_log.sql
Normal file
276
context-manager/schemas/01_immutable_log.sql
Normal file
@@ -0,0 +1,276 @@
|
||||
-- ============================================
|
||||
-- LOG INMUTABLE - TABLA DE REFERENCIA
|
||||
-- NO EDITABLE - Solo INSERT permitido
|
||||
-- ============================================
|
||||
-- Esta tabla es la fuente de verdad del sistema.
|
||||
-- Nunca se modifica ni se borra. Solo se inserta.
|
||||
|
||||
-- ============================================
|
||||
-- TABLA: immutable_log
|
||||
-- Registro permanente de todas las interacciones
|
||||
-- ============================================
|
||||
|
||||
CREATE TABLE IF NOT EXISTS immutable_log (
|
||||
-- Identificación
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
hash VARCHAR(64) NOT NULL UNIQUE, -- SHA-256 del contenido
|
||||
hash_anterior VARCHAR(64), -- Encadenamiento (blockchain-style)
|
||||
|
||||
-- Sesión
|
||||
session_id UUID NOT NULL,
|
||||
sequence_num BIGINT NOT NULL, -- Número secuencial en la sesión
|
||||
|
||||
-- Mensaje
|
||||
role mensaje_role NOT NULL,
|
||||
content TEXT NOT NULL,
|
||||
|
||||
-- Modelo IA (agnóstico)
|
||||
model_provider VARCHAR(50), -- anthropic, openai, ollama, local, etc.
|
||||
model_name VARCHAR(100), -- claude-3-opus, gpt-4, llama-3, etc.
|
||||
model_params JSONB DEFAULT '{}', -- temperature, max_tokens, etc.
|
||||
|
||||
-- Contexto enviado (snapshot)
|
||||
context_snapshot JSONB, -- Copia del contexto usado
|
||||
context_algorithm_id UUID, -- Qué algoritmo seleccionó el contexto
|
||||
context_tokens_used INT,
|
||||
|
||||
-- Respuesta (solo para role=assistant)
|
||||
tokens_input INT,
|
||||
tokens_output INT,
|
||||
latency_ms INT,
|
||||
|
||||
-- Metadata inmutable
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
source_ip VARCHAR(45),
|
||||
user_agent TEXT,
|
||||
|
||||
-- Integridad
|
||||
CONSTRAINT chain_integrity CHECK (
|
||||
(sequence_num = 1 AND hash_anterior IS NULL) OR
|
||||
(sequence_num > 1 AND hash_anterior IS NOT NULL)
|
||||
)
|
||||
);
|
||||
|
||||
-- Índices para consulta (no para modificación)
|
||||
CREATE INDEX IF NOT EXISTS idx_log_session ON immutable_log(session_id, sequence_num);
|
||||
CREATE INDEX IF NOT EXISTS idx_log_created ON immutable_log(created_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_log_model ON immutable_log(model_provider, model_name);
|
||||
CREATE INDEX IF NOT EXISTS idx_log_hash ON immutable_log(hash);
|
||||
CREATE INDEX IF NOT EXISTS idx_log_chain ON immutable_log(hash_anterior);
|
||||
|
||||
-- ============================================
|
||||
-- PROTECCIÓN: Trigger que impide UPDATE y DELETE
|
||||
-- ============================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION prevent_log_modification()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
RAISE EXCEPTION 'immutable_log no permite modificaciones. Solo INSERT está permitido.';
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
DROP TRIGGER IF EXISTS protect_immutable_log_update ON immutable_log;
|
||||
CREATE TRIGGER protect_immutable_log_update
|
||||
BEFORE UPDATE ON immutable_log
|
||||
FOR EACH ROW EXECUTE FUNCTION prevent_log_modification();
|
||||
|
||||
DROP TRIGGER IF EXISTS protect_immutable_log_delete ON immutable_log;
|
||||
CREATE TRIGGER protect_immutable_log_delete
|
||||
BEFORE DELETE ON immutable_log
|
||||
FOR EACH ROW EXECUTE FUNCTION prevent_log_modification();
|
||||
|
||||
-- ============================================
|
||||
-- FUNCIÓN: Insertar en log con hash automático
|
||||
-- ============================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION insert_log_entry(
|
||||
p_session_id UUID,
|
||||
p_role mensaje_role,
|
||||
p_content TEXT,
|
||||
p_model_provider VARCHAR DEFAULT NULL,
|
||||
p_model_name VARCHAR DEFAULT NULL,
|
||||
p_model_params JSONB DEFAULT '{}',
|
||||
p_context_snapshot JSONB DEFAULT NULL,
|
||||
p_context_algorithm_id UUID DEFAULT NULL,
|
||||
p_context_tokens_used INT DEFAULT NULL,
|
||||
p_tokens_input INT DEFAULT NULL,
|
||||
p_tokens_output INT DEFAULT NULL,
|
||||
p_latency_ms INT DEFAULT NULL,
|
||||
p_source_ip VARCHAR DEFAULT NULL,
|
||||
p_user_agent TEXT DEFAULT NULL
|
||||
)
|
||||
RETURNS UUID AS $$
|
||||
DECLARE
|
||||
v_sequence_num BIGINT;
|
||||
v_hash_anterior VARCHAR(64);
|
||||
v_content_hash VARCHAR(64);
|
||||
v_new_id UUID;
|
||||
BEGIN
|
||||
-- Obtener último hash y secuencia de la sesión
|
||||
SELECT sequence_num, hash
|
||||
INTO v_sequence_num, v_hash_anterior
|
||||
FROM immutable_log
|
||||
WHERE session_id = p_session_id
|
||||
ORDER BY sequence_num DESC
|
||||
LIMIT 1;
|
||||
|
||||
IF v_sequence_num IS NULL THEN
|
||||
v_sequence_num := 1;
|
||||
v_hash_anterior := NULL;
|
||||
ELSE
|
||||
v_sequence_num := v_sequence_num + 1;
|
||||
END IF;
|
||||
|
||||
-- Calcular hash del contenido (incluye hash anterior para encadenamiento)
|
||||
v_content_hash := sha256_hash(
|
||||
COALESCE(v_hash_anterior, '') ||
|
||||
p_session_id::TEXT ||
|
||||
v_sequence_num::TEXT ||
|
||||
p_role::TEXT ||
|
||||
p_content
|
||||
);
|
||||
|
||||
-- Insertar
|
||||
INSERT INTO immutable_log (
|
||||
session_id, sequence_num, hash, hash_anterior,
|
||||
role, content,
|
||||
model_provider, model_name, model_params,
|
||||
context_snapshot, context_algorithm_id, context_tokens_used,
|
||||
tokens_input, tokens_output, latency_ms,
|
||||
source_ip, user_agent
|
||||
) VALUES (
|
||||
p_session_id, v_sequence_num, v_content_hash, v_hash_anterior,
|
||||
p_role, p_content,
|
||||
p_model_provider, p_model_name, p_model_params,
|
||||
p_context_snapshot, p_context_algorithm_id, p_context_tokens_used,
|
||||
p_tokens_input, p_tokens_output, p_latency_ms,
|
||||
p_source_ip, p_user_agent
|
||||
) RETURNING id INTO v_new_id;
|
||||
|
||||
RETURN v_new_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- ============================================
|
||||
-- TABLA: sessions
|
||||
-- Registro de sesiones (también inmutable)
|
||||
-- ============================================
|
||||
|
||||
CREATE TABLE IF NOT EXISTS sessions (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
hash VARCHAR(64) NOT NULL UNIQUE,
|
||||
|
||||
-- Identificación
|
||||
user_id VARCHAR(100),
|
||||
instance_id VARCHAR(100),
|
||||
|
||||
-- Configuración inicial
|
||||
initial_model_provider VARCHAR(50),
|
||||
initial_model_name VARCHAR(100),
|
||||
initial_context_algorithm_id UUID,
|
||||
|
||||
-- Metadata
|
||||
metadata JSONB DEFAULT '{}',
|
||||
|
||||
-- Timestamps inmutables
|
||||
started_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
ended_at TIMESTAMP,
|
||||
|
||||
-- Estadísticas finales (se actualizan solo al cerrar)
|
||||
total_messages INT DEFAULT 0,
|
||||
total_tokens_input INT DEFAULT 0,
|
||||
total_tokens_output INT DEFAULT 0,
|
||||
total_latency_ms INT DEFAULT 0
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_sessions_user ON sessions(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_sessions_instance ON sessions(instance_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_sessions_started ON sessions(started_at DESC);
|
||||
|
||||
-- ============================================
|
||||
-- FUNCIÓN: Crear nueva sesión
|
||||
-- ============================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION create_session(
|
||||
p_user_id VARCHAR DEFAULT NULL,
|
||||
p_instance_id VARCHAR DEFAULT NULL,
|
||||
p_model_provider VARCHAR DEFAULT NULL,
|
||||
p_model_name VARCHAR DEFAULT NULL,
|
||||
p_algorithm_id UUID DEFAULT NULL,
|
||||
p_metadata JSONB DEFAULT '{}'
|
||||
)
|
||||
RETURNS UUID AS $$
|
||||
DECLARE
|
||||
v_session_id UUID;
|
||||
v_hash VARCHAR(64);
|
||||
BEGIN
|
||||
v_session_id := gen_random_uuid();
|
||||
v_hash := sha256_hash(v_session_id::TEXT || CURRENT_TIMESTAMP::TEXT);
|
||||
|
||||
INSERT INTO sessions (
|
||||
id, hash, user_id, instance_id,
|
||||
initial_model_provider, initial_model_name,
|
||||
initial_context_algorithm_id, metadata
|
||||
) VALUES (
|
||||
v_session_id, v_hash, p_user_id, p_instance_id,
|
||||
p_model_provider, p_model_name,
|
||||
p_algorithm_id, p_metadata
|
||||
);
|
||||
|
||||
RETURN v_session_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- ============================================
|
||||
-- FUNCIÓN: Verificar integridad de la cadena
|
||||
-- ============================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION verify_chain_integrity(p_session_id UUID)
|
||||
RETURNS TABLE (
|
||||
is_valid BOOLEAN,
|
||||
broken_at_sequence BIGINT,
|
||||
expected_hash VARCHAR(64),
|
||||
actual_hash VARCHAR(64)
|
||||
) AS $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
prev_hash VARCHAR(64) := NULL;
|
||||
computed_hash VARCHAR(64);
|
||||
BEGIN
|
||||
FOR rec IN
|
||||
SELECT * FROM immutable_log
|
||||
WHERE session_id = p_session_id
|
||||
ORDER BY sequence_num
|
||||
LOOP
|
||||
-- Verificar encadenamiento
|
||||
IF rec.sequence_num = 1 AND rec.hash_anterior IS NOT NULL THEN
|
||||
RETURN QUERY SELECT FALSE, rec.sequence_num, NULL::VARCHAR(64), rec.hash_anterior;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
IF rec.sequence_num > 1 AND rec.hash_anterior != prev_hash THEN
|
||||
RETURN QUERY SELECT FALSE, rec.sequence_num, prev_hash, rec.hash_anterior;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Verificar hash del contenido
|
||||
computed_hash := sha256_hash(
|
||||
COALESCE(prev_hash, '') ||
|
||||
rec.session_id::TEXT ||
|
||||
rec.sequence_num::TEXT ||
|
||||
rec.role::TEXT ||
|
||||
rec.content
|
||||
);
|
||||
|
||||
IF computed_hash != rec.hash THEN
|
||||
RETURN QUERY SELECT FALSE, rec.sequence_num, computed_hash, rec.hash;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
prev_hash := rec.hash;
|
||||
END LOOP;
|
||||
|
||||
RETURN QUERY SELECT TRUE, NULL::BIGINT, NULL::VARCHAR(64), NULL::VARCHAR(64);
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
243
context-manager/schemas/02_context_manager.sql
Normal file
243
context-manager/schemas/02_context_manager.sql
Normal file
@@ -0,0 +1,243 @@
|
||||
-- ============================================
|
||||
-- GESTOR DE CONTEXTO - TABLAS EDITABLES
|
||||
-- Estas tablas SÍ se pueden modificar
|
||||
-- ============================================
|
||||
|
||||
-- ============================================
|
||||
-- TABLA: context_blocks
|
||||
-- Bloques de contexto reutilizables
|
||||
-- ============================================
|
||||
|
||||
CREATE TABLE IF NOT EXISTS context_blocks (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
|
||||
-- Identificación
|
||||
code VARCHAR(100) UNIQUE NOT NULL,
|
||||
name VARCHAR(255) NOT NULL,
|
||||
description TEXT,
|
||||
|
||||
-- Contenido
|
||||
content TEXT NOT NULL,
|
||||
content_hash VARCHAR(64), -- Para detectar cambios
|
||||
|
||||
-- Clasificación
|
||||
category VARCHAR(50) NOT NULL, -- system, persona, knowledge, rules, examples
|
||||
priority INT DEFAULT 50, -- 0-100, mayor = más importante
|
||||
tokens_estimated INT,
|
||||
|
||||
-- Alcance
|
||||
scope VARCHAR(50) DEFAULT 'global', -- global, project, session
|
||||
project_id UUID,
|
||||
|
||||
-- Condiciones de activación
|
||||
activation_rules JSONB DEFAULT '{}',
|
||||
/*
|
||||
Ejemplo activation_rules:
|
||||
{
|
||||
"always": false,
|
||||
"keywords": ["database", "sql"],
|
||||
"model_providers": ["anthropic"],
|
||||
"min_session_messages": 0,
|
||||
"time_of_day": null
|
||||
}
|
||||
*/
|
||||
|
||||
-- Estado
|
||||
active BOOLEAN DEFAULT true,
|
||||
version INT DEFAULT 1,
|
||||
|
||||
-- Timestamps
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_ctx_blocks_code ON context_blocks(code);
|
||||
CREATE INDEX IF NOT EXISTS idx_ctx_blocks_category ON context_blocks(category);
|
||||
CREATE INDEX IF NOT EXISTS idx_ctx_blocks_priority ON context_blocks(priority DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_ctx_blocks_active ON context_blocks(active);
|
||||
CREATE INDEX IF NOT EXISTS idx_ctx_blocks_scope ON context_blocks(scope);
|
||||
|
||||
DROP TRIGGER IF EXISTS update_ctx_blocks_updated_at ON context_blocks;
|
||||
CREATE TRIGGER update_ctx_blocks_updated_at
|
||||
BEFORE UPDATE ON context_blocks
|
||||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
-- Trigger para calcular hash y tokens al insertar/actualizar
|
||||
CREATE OR REPLACE FUNCTION update_block_metadata()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.content_hash := sha256_hash(NEW.content);
|
||||
-- Estimación simple: ~4 caracteres por token
|
||||
NEW.tokens_estimated := CEIL(LENGTH(NEW.content) / 4.0);
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
DROP TRIGGER IF EXISTS calc_block_metadata ON context_blocks;
|
||||
CREATE TRIGGER calc_block_metadata
|
||||
BEFORE INSERT OR UPDATE OF content ON context_blocks
|
||||
FOR EACH ROW EXECUTE FUNCTION update_block_metadata();
|
||||
|
||||
-- ============================================
|
||||
-- TABLA: knowledge_base
|
||||
-- Base de conocimiento (RAG simple)
|
||||
-- ============================================
|
||||
|
||||
CREATE TABLE IF NOT EXISTS knowledge_base (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
|
||||
-- Identificación
|
||||
title VARCHAR(255) NOT NULL,
|
||||
category VARCHAR(100) NOT NULL,
|
||||
tags TEXT[] DEFAULT '{}',
|
||||
|
||||
-- Contenido
|
||||
content TEXT NOT NULL,
|
||||
content_hash VARCHAR(64),
|
||||
tokens_estimated INT,
|
||||
|
||||
-- Embeddings (para búsqueda semántica futura)
|
||||
embedding_model VARCHAR(100),
|
||||
embedding VECTOR(1536), -- Requiere pgvector si se usa
|
||||
|
||||
-- Fuente
|
||||
source_type VARCHAR(50), -- file, url, manual, extracted
|
||||
source_ref TEXT,
|
||||
|
||||
-- Relevancia
|
||||
priority INT DEFAULT 50,
|
||||
access_count INT DEFAULT 0,
|
||||
last_accessed_at TIMESTAMP,
|
||||
|
||||
-- Estado
|
||||
active BOOLEAN DEFAULT true,
|
||||
|
||||
-- Timestamps
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_kb_category ON knowledge_base(category);
|
||||
CREATE INDEX IF NOT EXISTS idx_kb_tags ON knowledge_base USING GIN(tags);
|
||||
CREATE INDEX IF NOT EXISTS idx_kb_priority ON knowledge_base(priority DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_kb_active ON knowledge_base(active);
|
||||
|
||||
DROP TRIGGER IF EXISTS update_kb_updated_at ON knowledge_base;
|
||||
CREATE TRIGGER update_kb_updated_at
|
||||
BEFORE UPDATE ON knowledge_base
|
||||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
DROP TRIGGER IF EXISTS calc_kb_metadata ON knowledge_base;
|
||||
CREATE TRIGGER calc_kb_metadata
|
||||
BEFORE INSERT OR UPDATE OF content ON knowledge_base
|
||||
FOR EACH ROW EXECUTE FUNCTION update_block_metadata();
|
||||
|
||||
-- ============================================
|
||||
-- TABLA: memory
|
||||
-- Memoria a largo plazo extraída de conversaciones
|
||||
-- ============================================
|
||||
|
||||
CREATE TABLE IF NOT EXISTS memory (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
|
||||
-- Clasificación
|
||||
type VARCHAR(50) NOT NULL, -- fact, preference, decision, learning, procedure
|
||||
category VARCHAR(100),
|
||||
|
||||
-- Contenido
|
||||
content TEXT NOT NULL,
|
||||
summary VARCHAR(500),
|
||||
content_hash VARCHAR(64),
|
||||
|
||||
-- Origen
|
||||
extracted_from_session UUID REFERENCES sessions(id),
|
||||
extracted_from_log UUID, -- No FK para no bloquear
|
||||
|
||||
-- Relevancia
|
||||
importance INT DEFAULT 50, -- 0-100
|
||||
confidence DECIMAL(3,2) DEFAULT 1.0, -- 0.00-1.00
|
||||
uses INT DEFAULT 0,
|
||||
last_used_at TIMESTAMP,
|
||||
|
||||
-- Expiración
|
||||
expires_at TIMESTAMP,
|
||||
|
||||
-- Estado
|
||||
active BOOLEAN DEFAULT true,
|
||||
verified BOOLEAN DEFAULT false, -- Confirmado por usuario
|
||||
|
||||
-- Timestamps
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_memory_type ON memory(type);
|
||||
CREATE INDEX IF NOT EXISTS idx_memory_importance ON memory(importance DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_memory_active ON memory(active);
|
||||
CREATE INDEX IF NOT EXISTS idx_memory_expires ON memory(expires_at);
|
||||
|
||||
DROP TRIGGER IF EXISTS update_memory_updated_at ON memory;
|
||||
CREATE TRIGGER update_memory_updated_at
|
||||
BEFORE UPDATE ON memory
|
||||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
-- ============================================
|
||||
-- TABLA: ambient_context
|
||||
-- Contexto ambiental (estado actual del sistema)
|
||||
-- ============================================
|
||||
|
||||
CREATE TABLE IF NOT EXISTS ambient_context (
|
||||
id SERIAL PRIMARY KEY,
|
||||
|
||||
-- Snapshot
|
||||
captured_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
expires_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP + INTERVAL '1 hour',
|
||||
|
||||
-- Datos ambientales
|
||||
environment JSONB DEFAULT '{}',
|
||||
/*
|
||||
{
|
||||
"timezone": "Europe/Madrid",
|
||||
"locale": "es-ES",
|
||||
"working_directory": "/home/user/project",
|
||||
"git_branch": "main",
|
||||
"active_project": "my-app"
|
||||
}
|
||||
*/
|
||||
|
||||
-- Estado del sistema
|
||||
system_state JSONB DEFAULT '{}',
|
||||
/*
|
||||
{
|
||||
"servers": {"architect": "online"},
|
||||
"services": {"gitea": "running"},
|
||||
"pending_tasks": [],
|
||||
"alerts": []
|
||||
}
|
||||
*/
|
||||
|
||||
-- Archivos/recursos activos
|
||||
active_resources JSONB DEFAULT '[]'
|
||||
/*
|
||||
[
|
||||
{"type": "file", "path": "/path/to/file.py", "modified": true},
|
||||
{"type": "url", "href": "https://docs.example.com"}
|
||||
]
|
||||
*/
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_ambient_captured ON ambient_context(captured_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_ambient_expires ON ambient_context(expires_at);
|
||||
|
||||
-- Limpiar contextos expirados
|
||||
CREATE OR REPLACE FUNCTION cleanup_expired_ambient()
|
||||
RETURNS INTEGER AS $$
|
||||
DECLARE
|
||||
deleted_count INTEGER;
|
||||
BEGIN
|
||||
DELETE FROM ambient_context
|
||||
WHERE expires_at < CURRENT_TIMESTAMP;
|
||||
GET DIAGNOSTICS deleted_count = ROW_COUNT;
|
||||
RETURN deleted_count;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
399
context-manager/schemas/03_algorithm_engine.sql
Normal file
399
context-manager/schemas/03_algorithm_engine.sql
Normal file
@@ -0,0 +1,399 @@
|
||||
-- ============================================
|
||||
-- MOTOR DE ALGORITMOS - Sistema evolutivo
|
||||
-- Permite versionar y mejorar el algoritmo de contexto
|
||||
-- ============================================
|
||||
|
||||
-- ============================================
|
||||
-- TABLA: context_algorithms
|
||||
-- Definición de algoritmos de selección de contexto
|
||||
-- ============================================
|
||||
|
||||
CREATE TABLE IF NOT EXISTS context_algorithms (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
|
||||
-- Identificación
|
||||
code VARCHAR(100) UNIQUE NOT NULL,
|
||||
name VARCHAR(255) NOT NULL,
|
||||
description TEXT,
|
||||
version VARCHAR(20) NOT NULL DEFAULT '1.0.0',
|
||||
|
||||
-- Estado
|
||||
status algorithm_status DEFAULT 'draft',
|
||||
|
||||
-- Configuración del algoritmo
|
||||
config JSONB NOT NULL DEFAULT '{
|
||||
"max_tokens": 4000,
|
||||
"sources": {
|
||||
"system_prompts": true,
|
||||
"context_blocks": true,
|
||||
"memory": true,
|
||||
"knowledge": true,
|
||||
"history": true,
|
||||
"ambient": true
|
||||
},
|
||||
"weights": {
|
||||
"priority": 0.4,
|
||||
"relevance": 0.3,
|
||||
"recency": 0.2,
|
||||
"frequency": 0.1
|
||||
},
|
||||
"history_config": {
|
||||
"max_messages": 20,
|
||||
"summarize_after": 10,
|
||||
"include_system": false
|
||||
},
|
||||
"memory_config": {
|
||||
"max_items": 15,
|
||||
"min_importance": 30
|
||||
},
|
||||
"knowledge_config": {
|
||||
"max_items": 5,
|
||||
"require_keyword_match": true
|
||||
}
|
||||
}'::jsonb,
|
||||
|
||||
-- Código del algoritmo (Python embebido)
|
||||
selector_code TEXT,
|
||||
/*
|
||||
Ejemplo:
|
||||
def select_context(session, message, config):
|
||||
context = []
|
||||
# ... lógica de selección
|
||||
return context
|
||||
*/
|
||||
|
||||
-- Estadísticas
|
||||
times_used INT DEFAULT 0,
|
||||
avg_tokens_used DECIMAL(10,2),
|
||||
avg_relevance_score DECIMAL(3,2),
|
||||
avg_response_quality DECIMAL(3,2),
|
||||
|
||||
-- Linaje
|
||||
parent_algorithm_id UUID REFERENCES context_algorithms(id),
|
||||
fork_reason TEXT,
|
||||
|
||||
-- Timestamps
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
activated_at TIMESTAMP,
|
||||
deprecated_at TIMESTAMP
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_algo_code ON context_algorithms(code);
|
||||
CREATE INDEX IF NOT EXISTS idx_algo_status ON context_algorithms(status);
|
||||
CREATE INDEX IF NOT EXISTS idx_algo_version ON context_algorithms(version);
|
||||
CREATE INDEX IF NOT EXISTS idx_algo_parent ON context_algorithms(parent_algorithm_id);
|
||||
|
||||
DROP TRIGGER IF EXISTS update_algo_updated_at ON context_algorithms;
|
||||
CREATE TRIGGER update_algo_updated_at
|
||||
BEFORE UPDATE ON context_algorithms
|
||||
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
||||
|
||||
-- ============================================
|
||||
-- TABLA: algorithm_metrics
|
||||
-- Métricas de rendimiento por algoritmo
|
||||
-- ============================================
|
||||
|
||||
CREATE TABLE IF NOT EXISTS algorithm_metrics (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
|
||||
-- Referencias
|
||||
algorithm_id UUID NOT NULL REFERENCES context_algorithms(id),
|
||||
session_id UUID REFERENCES sessions(id),
|
||||
log_entry_id UUID, -- Referencia al log inmutable
|
||||
|
||||
-- Métricas de contexto
|
||||
tokens_budget INT,
|
||||
tokens_used INT,
|
||||
token_efficiency DECIMAL(5,4), -- tokens_used / tokens_budget
|
||||
|
||||
-- Composición del contexto
|
||||
context_composition JSONB,
|
||||
/*
|
||||
{
|
||||
"system_prompts": {"count": 1, "tokens": 500},
|
||||
"context_blocks": {"count": 3, "tokens": 800},
|
||||
"memory": {"count": 5, "tokens": 300},
|
||||
"knowledge": {"count": 2, "tokens": 400},
|
||||
"history": {"count": 10, "tokens": 1500},
|
||||
"ambient": {"count": 1, "tokens": 100}
|
||||
}
|
||||
*/
|
||||
|
||||
-- Métricas de respuesta
|
||||
latency_ms INT,
|
||||
model_tokens_input INT,
|
||||
model_tokens_output INT,
|
||||
|
||||
-- Evaluación (puede ser automática o manual)
|
||||
relevance_score DECIMAL(3,2), -- 0.00-1.00: ¿El contexto fue relevante?
|
||||
response_quality DECIMAL(3,2), -- 0.00-1.00: ¿La respuesta fue buena?
|
||||
user_satisfaction DECIMAL(3,2), -- 0.00-1.00: Feedback del usuario
|
||||
|
||||
-- Evaluación automática
|
||||
auto_evaluated BOOLEAN DEFAULT false,
|
||||
evaluation_method VARCHAR(50), -- llm_judge, heuristic, user_feedback
|
||||
|
||||
-- Timestamp
|
||||
recorded_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_metrics_algorithm ON algorithm_metrics(algorithm_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_metrics_session ON algorithm_metrics(session_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_metrics_recorded ON algorithm_metrics(recorded_at DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_metrics_quality ON algorithm_metrics(response_quality DESC);
|
||||
|
||||
-- ============================================
|
||||
-- TABLA: algorithm_experiments
|
||||
-- A/B testing de algoritmos
|
||||
-- ============================================
|
||||
|
||||
CREATE TABLE IF NOT EXISTS algorithm_experiments (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
|
||||
-- Identificación
|
||||
name VARCHAR(255) NOT NULL,
|
||||
description TEXT,
|
||||
|
||||
-- Algoritmos en competencia
|
||||
control_algorithm_id UUID NOT NULL REFERENCES context_algorithms(id),
|
||||
treatment_algorithm_id UUID NOT NULL REFERENCES context_algorithms(id),
|
||||
|
||||
-- Configuración
|
||||
traffic_split DECIMAL(3,2) DEFAULT 0.50, -- % para treatment
|
||||
min_samples INT DEFAULT 100,
|
||||
max_samples INT DEFAULT 1000,
|
||||
|
||||
-- Estado
|
||||
status VARCHAR(50) DEFAULT 'pending', -- pending, running, completed, cancelled
|
||||
|
||||
-- Resultados
|
||||
control_samples INT DEFAULT 0,
|
||||
treatment_samples INT DEFAULT 0,
|
||||
control_avg_quality DECIMAL(3,2),
|
||||
treatment_avg_quality DECIMAL(3,2),
|
||||
winner_algorithm_id UUID REFERENCES context_algorithms(id),
|
||||
statistical_significance DECIMAL(5,4),
|
||||
|
||||
-- Timestamps
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
started_at TIMESTAMP,
|
||||
completed_at TIMESTAMP
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_exp_status ON algorithm_experiments(status);
|
||||
CREATE INDEX IF NOT EXISTS idx_exp_control ON algorithm_experiments(control_algorithm_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_exp_treatment ON algorithm_experiments(treatment_algorithm_id);
|
||||
|
||||
-- ============================================
|
||||
-- VISTA: Resumen de rendimiento por algoritmo
|
||||
-- ============================================
|
||||
|
||||
CREATE OR REPLACE VIEW algorithm_performance AS
|
||||
SELECT
|
||||
a.id,
|
||||
a.code,
|
||||
a.name,
|
||||
a.version,
|
||||
a.status,
|
||||
a.times_used,
|
||||
COUNT(m.id) as total_metrics,
|
||||
AVG(m.token_efficiency) as avg_token_efficiency,
|
||||
AVG(m.relevance_score) as avg_relevance,
|
||||
AVG(m.response_quality) as avg_quality,
|
||||
AVG(m.user_satisfaction) as avg_satisfaction,
|
||||
AVG(m.latency_ms) as avg_latency,
|
||||
PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY m.response_quality) as median_quality,
|
||||
STDDEV(m.response_quality) as quality_stddev
|
||||
FROM context_algorithms a
|
||||
LEFT JOIN algorithm_metrics m ON a.id = m.algorithm_id
|
||||
GROUP BY a.id, a.code, a.name, a.version, a.status, a.times_used;
|
||||
|
||||
-- ============================================
|
||||
-- FUNCIÓN: Activar algoritmo (desactiva el anterior)
|
||||
-- ============================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION activate_algorithm(p_algorithm_id UUID)
|
||||
RETURNS BOOLEAN AS $$
|
||||
BEGIN
|
||||
-- Deprecar algoritmo activo actual
|
||||
UPDATE context_algorithms
|
||||
SET status = 'deprecated', deprecated_at = CURRENT_TIMESTAMP
|
||||
WHERE status = 'active';
|
||||
|
||||
-- Activar nuevo algoritmo
|
||||
UPDATE context_algorithms
|
||||
SET status = 'active', activated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = p_algorithm_id;
|
||||
|
||||
RETURN FOUND;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- ============================================
|
||||
-- FUNCIÓN: Clonar algoritmo para experimentación
|
||||
-- ============================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION fork_algorithm(
|
||||
p_source_id UUID,
|
||||
p_new_code VARCHAR,
|
||||
p_new_name VARCHAR,
|
||||
p_reason TEXT DEFAULT NULL
|
||||
)
|
||||
RETURNS UUID AS $$
|
||||
DECLARE
|
||||
v_new_id UUID;
|
||||
v_source RECORD;
|
||||
BEGIN
|
||||
SELECT * INTO v_source FROM context_algorithms WHERE id = p_source_id;
|
||||
|
||||
IF NOT FOUND THEN
|
||||
RAISE EXCEPTION 'Algoritmo fuente no encontrado: %', p_source_id;
|
||||
END IF;
|
||||
|
||||
INSERT INTO context_algorithms (
|
||||
code, name, description, version,
|
||||
status, config, selector_code,
|
||||
parent_algorithm_id, fork_reason
|
||||
) VALUES (
|
||||
p_new_code,
|
||||
p_new_name,
|
||||
v_source.description,
|
||||
'1.0.0',
|
||||
'draft',
|
||||
v_source.config,
|
||||
v_source.selector_code,
|
||||
p_source_id,
|
||||
p_reason
|
||||
) RETURNING id INTO v_new_id;
|
||||
|
||||
RETURN v_new_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- ============================================
|
||||
-- FUNCIÓN: Obtener algoritmo activo
|
||||
-- ============================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_active_algorithm()
|
||||
RETURNS UUID AS $$
|
||||
SELECT id FROM context_algorithms
|
||||
WHERE status = 'active'
|
||||
ORDER BY activated_at DESC
|
||||
LIMIT 1;
|
||||
$$ LANGUAGE SQL STABLE;
|
||||
|
||||
-- ============================================
|
||||
-- FUNCIÓN: Registrar métrica de uso
|
||||
-- ============================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION record_algorithm_metric(
|
||||
p_algorithm_id UUID,
|
||||
p_session_id UUID,
|
||||
p_log_entry_id UUID,
|
||||
p_tokens_budget INT,
|
||||
p_tokens_used INT,
|
||||
p_context_composition JSONB,
|
||||
p_latency_ms INT DEFAULT NULL,
|
||||
p_model_tokens_input INT DEFAULT NULL,
|
||||
p_model_tokens_output INT DEFAULT NULL
|
||||
)
|
||||
RETURNS UUID AS $$
|
||||
DECLARE
|
||||
v_metric_id UUID;
|
||||
v_efficiency DECIMAL(5,4);
|
||||
BEGIN
|
||||
v_efficiency := CASE
|
||||
WHEN p_tokens_budget > 0 THEN p_tokens_used::DECIMAL / p_tokens_budget
|
||||
ELSE 0
|
||||
END;
|
||||
|
||||
INSERT INTO algorithm_metrics (
|
||||
algorithm_id, session_id, log_entry_id,
|
||||
tokens_budget, tokens_used, token_efficiency,
|
||||
context_composition, latency_ms,
|
||||
model_tokens_input, model_tokens_output
|
||||
) VALUES (
|
||||
p_algorithm_id, p_session_id, p_log_entry_id,
|
||||
p_tokens_budget, p_tokens_used, v_efficiency,
|
||||
p_context_composition, p_latency_ms,
|
||||
p_model_tokens_input, p_model_tokens_output
|
||||
) RETURNING id INTO v_metric_id;
|
||||
|
||||
-- Actualizar contador del algoritmo
|
||||
UPDATE context_algorithms
|
||||
SET times_used = times_used + 1
|
||||
WHERE id = p_algorithm_id;
|
||||
|
||||
RETURN v_metric_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- ============================================
|
||||
-- FUNCIÓN: Actualizar evaluación de métrica
|
||||
-- ============================================
|
||||
|
||||
CREATE OR REPLACE FUNCTION update_metric_evaluation(
|
||||
p_metric_id UUID,
|
||||
p_relevance DECIMAL DEFAULT NULL,
|
||||
p_quality DECIMAL DEFAULT NULL,
|
||||
p_satisfaction DECIMAL DEFAULT NULL,
|
||||
p_method VARCHAR DEFAULT 'manual'
|
||||
)
|
||||
RETURNS BOOLEAN AS $$
|
||||
BEGIN
|
||||
UPDATE algorithm_metrics
|
||||
SET
|
||||
relevance_score = COALESCE(p_relevance, relevance_score),
|
||||
response_quality = COALESCE(p_quality, response_quality),
|
||||
user_satisfaction = COALESCE(p_satisfaction, user_satisfaction),
|
||||
auto_evaluated = (p_method != 'user_feedback'),
|
||||
evaluation_method = p_method
|
||||
WHERE id = p_metric_id;
|
||||
|
||||
RETURN FOUND;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- ============================================
|
||||
-- DATOS INICIALES: Algoritmo por defecto
|
||||
-- ============================================
|
||||
|
||||
INSERT INTO context_algorithms (code, name, description, version, status, config) VALUES
|
||||
(
|
||||
'ALG_DEFAULT_V1',
|
||||
'Algoritmo por defecto v1',
|
||||
'Selección de contexto basada en prioridad y tokens disponibles',
|
||||
'1.0.0',
|
||||
'active',
|
||||
'{
|
||||
"max_tokens": 4000,
|
||||
"sources": {
|
||||
"system_prompts": true,
|
||||
"context_blocks": true,
|
||||
"memory": true,
|
||||
"knowledge": true,
|
||||
"history": true,
|
||||
"ambient": true
|
||||
},
|
||||
"weights": {
|
||||
"priority": 0.4,
|
||||
"relevance": 0.3,
|
||||
"recency": 0.2,
|
||||
"frequency": 0.1
|
||||
},
|
||||
"history_config": {
|
||||
"max_messages": 20,
|
||||
"summarize_after": 10,
|
||||
"include_system": false
|
||||
},
|
||||
"memory_config": {
|
||||
"max_items": 15,
|
||||
"min_importance": 30
|
||||
},
|
||||
"knowledge_config": {
|
||||
"max_items": 5,
|
||||
"require_keyword_match": true
|
||||
}
|
||||
}'::jsonb
|
||||
) ON CONFLICT (code) DO NOTHING;
|
||||
Reference in New Issue
Block a user