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:
ARCHITECT
2025-12-29 18:31:54 +00:00
commit d21bd9e650
17 changed files with 3295 additions and 0 deletions

View 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;