Add CTO schema v1.0 - Context Manager tables
This commit is contained in:
127
schemas/05_cto.sql
Normal file
127
schemas/05_cto.sql
Normal file
@@ -0,0 +1,127 @@
|
||||
-- =============================================================================
|
||||
-- Context Manager Schema (CTO) v1.0
|
||||
-- Sistema de gestión de contexto con embeddings
|
||||
-- Requiere: pgvector extension
|
||||
-- =============================================================================
|
||||
|
||||
CREATE EXTENSION IF NOT EXISTS vector;
|
||||
CREATE SCHEMA IF NOT EXISTS cto;
|
||||
|
||||
-- -----------------------------------------------------------------------------
|
||||
-- cto.blocks: Bloques de memoria con embeddings
|
||||
-- -----------------------------------------------------------------------------
|
||||
CREATE TABLE IF NOT EXISTS cto.blocks (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
hash CHAR(64) UNIQUE NOT NULL, -- SHA-256 del contenido
|
||||
session_hash CHAR(64) NOT NULL, -- Sesión origen
|
||||
owner_id CHAR(64) NOT NULL, -- Propietario (PLY hash)
|
||||
block_type TEXT NOT NULL DEFAULT 'fact', -- fact|instruction|preference|context
|
||||
content TEXT NOT NULL, -- Contenido del bloque
|
||||
embedding vector(1536), -- OpenAI text-embedding-3-small
|
||||
importance FLOAT DEFAULT 0.5, -- 0.0-1.0
|
||||
access_count INT DEFAULT 0, -- Frecuencia de acceso
|
||||
last_accessed TIMESTAMPTZ, -- Último acceso
|
||||
source_hash CHAR(64), -- Mensaje origen (log.messages.hash)
|
||||
metadata JSONB DEFAULT '{}', -- Metadatos adicionales
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- Índices para blocks
|
||||
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_importance ON cto.blocks(importance DESC);
|
||||
CREATE INDEX IF NOT EXISTS idx_blocks_embedding ON cto.blocks USING ivfflat (embedding vector_cosine_ops) WITH (lists = 100);
|
||||
|
||||
-- -----------------------------------------------------------------------------
|
||||
-- cto.memory: Memoria activa por sesión
|
||||
-- -----------------------------------------------------------------------------
|
||||
CREATE TABLE IF NOT EXISTS cto.memory (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
session_hash CHAR(64) NOT NULL, -- Sesión actual
|
||||
owner_id CHAR(64) NOT NULL, -- Propietario
|
||||
block_hash CHAR(64) NOT NULL REFERENCES cto.blocks(hash),
|
||||
position INT NOT NULL, -- Orden en contexto
|
||||
score FLOAT DEFAULT 0.0, -- Puntuación de relevancia
|
||||
token_count INT DEFAULT 0, -- Tokens consumidos
|
||||
included BOOLEAN DEFAULT true, -- Incluido en contexto actual
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
UNIQUE(session_hash, block_hash)
|
||||
);
|
||||
|
||||
-- Índices para memory
|
||||
CREATE INDEX IF NOT EXISTS idx_memory_session ON cto.memory(session_hash);
|
||||
CREATE INDEX IF NOT EXISTS idx_memory_position ON cto.memory(session_hash, position);
|
||||
CREATE INDEX IF NOT EXISTS idx_memory_score ON cto.memory(score DESC);
|
||||
|
||||
-- -----------------------------------------------------------------------------
|
||||
-- cto.algorithms: Configuración de algoritmos
|
||||
-- -----------------------------------------------------------------------------
|
||||
CREATE TABLE IF NOT EXISTS cto.algorithms (
|
||||
id SERIAL PRIMARY KEY,
|
||||
name TEXT UNIQUE NOT NULL,
|
||||
version TEXT NOT NULL DEFAULT '1.0',
|
||||
description TEXT,
|
||||
config JSONB NOT NULL DEFAULT '{}',
|
||||
enabled BOOLEAN DEFAULT true,
|
||||
created_at TIMESTAMPTZ DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ DEFAULT NOW()
|
||||
);
|
||||
|
||||
-- -----------------------------------------------------------------------------
|
||||
-- Función y triggers para updated_at
|
||||
-- -----------------------------------------------------------------------------
|
||||
CREATE OR REPLACE FUNCTION cto.update_timestamp()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at = NOW();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
DROP TRIGGER IF EXISTS blocks_updated ON cto.blocks;
|
||||
DROP TRIGGER IF EXISTS algorithms_updated ON cto.algorithms;
|
||||
|
||||
CREATE TRIGGER blocks_updated
|
||||
BEFORE UPDATE ON cto.blocks
|
||||
FOR EACH ROW EXECUTE FUNCTION cto.update_timestamp();
|
||||
|
||||
CREATE TRIGGER algorithms_updated
|
||||
BEFORE UPDATE ON cto.algorithms
|
||||
FOR EACH ROW EXECUTE FUNCTION cto.update_timestamp();
|
||||
|
||||
-- -----------------------------------------------------------------------------
|
||||
-- Algoritmos por defecto
|
||||
-- -----------------------------------------------------------------------------
|
||||
INSERT INTO cto.algorithms (name, version, description, config) VALUES
|
||||
('extractor', '1.0', 'Extrae bloques de memoria de mensajes', '{
|
||||
"min_content_length": 10,
|
||||
"max_block_size": 500,
|
||||
"extraction_mode": "heuristic",
|
||||
"patterns": ["fact", "instruction", "preference", "context"]
|
||||
}'::jsonb),
|
||||
('scorer', '1.0', 'Calcula relevancia de bloques', '{
|
||||
"weights": {
|
||||
"recency": 0.3,
|
||||
"frequency": 0.2,
|
||||
"importance": 0.3,
|
||||
"similarity": 0.2
|
||||
},
|
||||
"decay_factor": 0.95
|
||||
}'::jsonb),
|
||||
('selector', '1.0', 'Selecciona bloques para contexto', '{
|
||||
"budget_tokens": 8000,
|
||||
"min_score": 0.1,
|
||||
"max_blocks": 50,
|
||||
"strategy": "greedy"
|
||||
}'::jsonb),
|
||||
('consolidator', '1.0', 'Consolida y comprime bloques', '{
|
||||
"similarity_threshold": 0.85,
|
||||
"merge_strategy": "newest",
|
||||
"compression_ratio": 0.7
|
||||
}'::jsonb)
|
||||
ON CONFLICT (name) DO UPDATE SET
|
||||
config = EXCLUDED.config,
|
||||
version = EXCLUDED.version,
|
||||
updated_at = NOW();
|
||||
Reference in New Issue
Block a user