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