Sistema local de gestión de contexto para IA: - Log inmutable (blockchain-style) - Algoritmos versionados y mejorables - Agnóstico al modelo (Anthropic, OpenAI, Ollama) - Sistema de métricas y A/B testing 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
277 lines
8.7 KiB
PL/PgSQL
277 lines
8.7 KiB
PL/PgSQL
-- ============================================
|
|
-- 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;
|