Files
context-manager/schemas/05_cto.sql
ARCHITECT 05d21976ca fix: corregir descripciones de servidores TZZR
- Añadir tabla correcta: ARCHITECT=Desarrollo, DECK=Usuario, CORP=Corporativo
- Eliminar ejemplos inventados (architect_persona)
- Usar ejemplos genéricos (system_rules, dev_config)
2026-01-01 16:16:35 +00:00

306 lines
11 KiB
PL/PgSQL

-- ============================================================================
-- SCHEMA CTO v2.0 - Context Manager Tables
-- ============================================================================
-- Servidor: ARCHITECT/DECK/CORP
-- Dependencias: pgvector extension
-- ============================================================================
CREATE SCHEMA IF NOT EXISTS cto;
-- Asegurar extensión vector
CREATE EXTENSION IF NOT EXISTS vector;
-- ============================================================================
-- cto.blocks - Bloques de contexto estático
-- ============================================================================
CREATE TABLE IF NOT EXISTS cto.blocks (
id BIGSERIAL PRIMARY KEY,
hash CHAR(64) NOT NULL UNIQUE,
code VARCHAR(50) UNIQUE,
name VARCHAR(200),
session_hash CHAR(64),
owner_id CHAR(64),
block_type VARCHAR(50),
category VARCHAR(50),
content TEXT NOT NULL,
embedding vector(1536),
priority INT DEFAULT 0,
scope VARCHAR(20) DEFAULT 'global',
server_code VARCHAR(20),
agent_code VARCHAR(50),
token_count INT,
status VARCHAR(20) DEFAULT 'active',
created_at TIMESTAMPTZ DEFAULT NOW(),
updated_at TIMESTAMPTZ DEFAULT NOW()
);
-- Índices
CREATE INDEX IF NOT EXISTS idx_blocks_hash ON cto.blocks(hash);
CREATE INDEX IF NOT EXISTS idx_blocks_code ON cto.blocks(code);
CREATE INDEX IF NOT EXISTS idx_blocks_session ON cto.blocks(session_hash);
CREATE INDEX IF NOT EXISTS idx_blocks_owner ON cto.blocks(owner_id);
CREATE INDEX IF NOT EXISTS idx_blocks_type ON cto.blocks(block_type);
CREATE INDEX IF NOT EXISTS idx_blocks_category ON cto.blocks(category);
CREATE INDEX IF NOT EXISTS idx_blocks_scope ON cto.blocks(scope);
CREATE INDEX IF NOT EXISTS idx_blocks_status ON cto.blocks(status) WHERE status = 'active';
CREATE INDEX IF NOT EXISTS idx_blocks_server ON cto.blocks(server_code) WHERE server_code IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_blocks_embedding ON cto.blocks USING ivfflat (embedding vector_cosine_ops) WITH (lists = 100);
-- Comentarios
COMMENT ON TABLE cto.blocks IS 'Bloques de contexto estático (personas, reglas, conocimiento)';
COMMENT ON COLUMN cto.blocks.code IS 'Identificador único legible (ej: system_rules, dev_config)';
COMMENT ON COLUMN cto.blocks.scope IS 'Ámbito: global, server, agent, session';
COMMENT ON COLUMN cto.blocks.priority IS 'Orden de inclusión (mayor = primero)';
COMMENT ON COLUMN cto.blocks.status IS 'Estado: active, inactive, deprecated';
-- ============================================================================
-- cto.memory - Memoria a largo plazo
-- ============================================================================
CREATE TABLE IF NOT EXISTS cto.memory (
id BIGSERIAL PRIMARY KEY,
hash CHAR(64) UNIQUE,
session_hash CHAR(64),
block_hash CHAR(64),
owner_id CHAR(64),
type VARCHAR(20),
content TEXT,
summary VARCHAR(500),
importance FLOAT DEFAULT 0.5,
confidence FLOAT DEFAULT 0.8,
embedding vector(1536),
embedding_model VARCHAR(50) DEFAULT 'text-embedding-3-small',
access_count INT DEFAULT 0,
access_count_v2 INT DEFAULT 0,
last_access TIMESTAMPTZ DEFAULT NOW(),
source_hash CHAR(64),
expires_at TIMESTAMPTZ,
status VARCHAR(20) DEFAULT 'active',
superseded_by BIGINT,
related_to BIGINT[],
metadata JSONB DEFAULT '{}',
owner_type VARCHAR(20) DEFAULT 'user',
created_at TIMESTAMPTZ DEFAULT NOW(),
updated_at TIMESTAMPTZ DEFAULT NOW(),
FOREIGN KEY (block_hash) REFERENCES cto.blocks(hash)
);
-- Índices
CREATE INDEX IF NOT EXISTS idx_memory_hash ON cto.memory(hash) WHERE hash IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_memory_session ON cto.memory(session_hash);
CREATE INDEX IF NOT EXISTS idx_memory_block ON cto.memory(block_hash);
CREATE INDEX IF NOT EXISTS idx_memory_owner ON cto.memory(owner_id);
CREATE INDEX IF NOT EXISTS idx_memory_type ON cto.memory(type) WHERE type IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_memory_status ON cto.memory(status) WHERE status = 'active';
CREATE INDEX IF NOT EXISTS idx_memory_expires ON cto.memory(expires_at) WHERE expires_at IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_memory_source ON cto.memory(source_hash) WHERE source_hash IS NOT NULL;
CREATE INDEX IF NOT EXISTS idx_memory_embedding ON cto.memory USING ivfflat (embedding vector_cosine_ops) WITH (lists = 100);
-- Comentarios
COMMENT ON TABLE cto.memory IS 'Memoria a largo plazo con embeddings para búsqueda semántica';
COMMENT ON COLUMN cto.memory.type IS 'Tipo: preference, decision, fact, entity, temporal';
COMMENT ON COLUMN cto.memory.importance IS 'Importancia 0-1 (mayor = más relevante)';
COMMENT ON COLUMN cto.memory.status IS 'Estado: active, superseded, expired, deleted';
-- ============================================================================
-- cto.algorithms - Configuración de algoritmos
-- ============================================================================
CREATE TABLE IF NOT EXISTS cto.algorithms (
id SERIAL PRIMARY KEY,
code VARCHAR(50) UNIQUE,
name VARCHAR(100) NOT NULL,
version VARCHAR(20) DEFAULT '1.0',
config JSONB NOT NULL DEFAULT '{}',
enabled BOOLEAN DEFAULT true,
status VARCHAR(20) DEFAULT 'active',
parent_id INT REFERENCES cto.algorithms(id),
metrics JSONB DEFAULT '{}',
activated_at TIMESTAMPTZ,
deprecated_at TIMESTAMPTZ,
created_at TIMESTAMPTZ DEFAULT NOW(),
updated_at TIMESTAMPTZ DEFAULT NOW()
);
-- Índices
CREATE INDEX IF NOT EXISTS idx_algorithms_code ON cto.algorithms(code);
CREATE INDEX IF NOT EXISTS idx_algorithms_status ON cto.algorithms(status);
CREATE INDEX IF NOT EXISTS idx_algorithms_parent ON cto.algorithms(parent_id) WHERE parent_id IS NOT NULL;
-- Comentarios
COMMENT ON TABLE cto.algorithms IS 'Configuración de algoritmos de contexto';
COMMENT ON COLUMN cto.algorithms.code IS 'Código único (ej: default_v1, experiment_a)';
COMMENT ON COLUMN cto.algorithms.status IS 'Estado: draft, active, experiment, deprecated';
COMMENT ON COLUMN cto.algorithms.parent_id IS 'Algoritmo padre (para versionado/forks)';
-- ============================================================================
-- Algoritmo por defecto v2
-- ============================================================================
INSERT INTO cto.algorithms (code, name, version, config, status, activated_at)
VALUES (
'default_v2',
'TZZR Context Manager v2',
'2.0.0',
'{
"version": "2.0.0",
"name": "TZZR Context Manager v2",
"extraction": {
"enabled": true,
"async": true,
"batch_size": 10,
"filter": {
"min_length": 20,
"skip_patterns": ["ok", "gracias", "entendido"]
}
},
"consolidation": {
"strategy": "heuristic_first",
"duplicate_threshold": 0.95,
"conflict_threshold": 0.85
},
"scoring": {
"strategy": "linear",
"weights": {
"recency": 0.20,
"importance": 0.40,
"relevance": 0.30,
"frequency": 0.10
},
"decay_rates": {
"preference": 0.01,
"decision": 0.05,
"fact": 0.10,
"entity": 0.05,
"temporal": 0.50
}
},
"selection": {
"strategy": "priority",
"token_budget": 8000,
"priority_order": ["system", "core", "working", "retrieved"]
},
"compression": {
"strategy": "progressive",
"keep_first": 3,
"keep_last": 10
},
"embedding": {
"provider": "openai",
"model": "text-embedding-3-small",
"dimension": 1536
}
}'::JSONB,
'active',
NOW()
) ON CONFLICT (code) DO NOTHING;
-- ============================================================================
-- Funciones auxiliares
-- ============================================================================
-- Calcular score de memoria
CREATE OR REPLACE FUNCTION cto.calculate_memory_score(
p_memory_id BIGINT,
p_query_embedding vector(1536) DEFAULT NULL,
p_current_time TIMESTAMPTZ DEFAULT NOW()
) RETURNS FLOAT AS $$
DECLARE
v_memory RECORD;
v_recency FLOAT;
v_relevance FLOAT;
v_frequency FLOAT;
v_hours_elapsed FLOAT;
v_decay_rate FLOAT;
v_strength FLOAT;
BEGIN
SELECT * INTO v_memory FROM cto.memory WHERE id = p_memory_id;
IF NOT FOUND THEN RETURN 0; END IF;
v_hours_elapsed := EXTRACT(EPOCH FROM (p_current_time - COALESCE(v_memory.last_access, v_memory.created_at))) / 3600;
v_decay_rate := CASE v_memory.type
WHEN 'preference' THEN 0.01
WHEN 'decision' THEN 0.05
WHEN 'fact' THEN 0.10
WHEN 'entity' THEN 0.05
WHEN 'temporal' THEN 0.50
ELSE 0.10
END;
v_strength := 1 + LN(1 + COALESCE(v_memory.access_count_v2, 0));
v_recency := EXP(-v_decay_rate * v_hours_elapsed / v_strength);
IF v_memory.embedding IS NOT NULL AND p_query_embedding IS NOT NULL THEN
v_relevance := 1 - (v_memory.embedding <=> p_query_embedding);
ELSE
v_relevance := 0.5;
END IF;
v_frequency := LEAST(COALESCE(v_memory.access_count_v2, 0) / 10.0, 1.0);
RETURN 0.20 * v_recency + 0.40 * COALESCE(v_memory.importance, 0.5) + 0.30 * v_relevance + 0.10 * v_frequency;
END;
$$ LANGUAGE plpgsql STABLE;
-- Buscar memorias por similitud semántica
CREATE OR REPLACE FUNCTION cto.search_memories(
p_query_embedding vector(1536),
p_owner_id CHAR(64),
p_limit INT DEFAULT 20,
p_min_similarity FLOAT DEFAULT 0.3
) RETURNS TABLE (
id BIGINT,
content TEXT,
type VARCHAR(20),
importance FLOAT,
similarity FLOAT,
score FLOAT
) AS $$
BEGIN
RETURN QUERY
SELECT
m.id,
m.content,
m.type,
m.importance::FLOAT,
(1 - (m.embedding <=> p_query_embedding))::FLOAT as similarity,
cto.calculate_memory_score(m.id, p_query_embedding, NOW()) as score
FROM cto.memory m
WHERE m.owner_id = p_owner_id
AND m.status = 'active'
AND m.embedding IS NOT NULL
AND (1 - (m.embedding <=> p_query_embedding)) > p_min_similarity
ORDER BY score DESC
LIMIT p_limit;
END;
$$ LANGUAGE plpgsql STABLE;
-- Obtener bloques activos por scope
CREATE OR REPLACE FUNCTION cto.get_active_blocks(
p_scope VARCHAR(20) DEFAULT 'global',
p_server_code VARCHAR(20) DEFAULT NULL,
p_agent_code VARCHAR(50) DEFAULT NULL
) RETURNS TABLE (
code VARCHAR(50),
name VARCHAR(200),
content TEXT,
category VARCHAR(50),
priority INT,
token_count INT
) AS $$
BEGIN
RETURN QUERY
SELECT
b.code,
b.name,
b.content,
b.category,
b.priority,
b.token_count
FROM cto.blocks b
WHERE b.status = 'active'
AND (
b.scope = 'global'
OR (b.scope = 'server' AND b.server_code = p_server_code)
OR (b.scope = 'agent' AND b.agent_code = p_agent_code)
)
ORDER BY b.priority DESC NULLS LAST, b.created_at ASC;
END;
$$ LANGUAGE plpgsql STABLE;