-- ============================================ -- CONTEXTO PARA SERVICIOS IA -- Sistema TZZR - contratos-comunes -- ============================================ -- Requiere: 00_types.sql, 01_hst_tags.sql, 02_task_manager.sql -- -- IMPORTANTE: Las estructuras aquí almacenadas corresponden -- exactamente al bloque "context" del S-CONTRACT v2.1 -- (schemas/s-contract-request.json) -- ============================================ -- TABLA: s_contract_contexts -- Contextos reutilizables en formato S-CONTRACT -- ============================================ CREATE TABLE IF NOT EXISTS s_contract_contexts ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- Identificación codigo VARCHAR(100) UNIQUE NOT NULL, nombre VARCHAR(255) NOT NULL, descripcion TEXT, -- ============================================ -- BLOQUE context (S-CONTRACT v2.1) -- Almacenado como JSONB para garantizar formato exacto -- ============================================ context JSONB NOT NULL DEFAULT '{ "lang": "es", "mode": "strict", "pii_filter": false, "bandera_id": null, "player_id": null, "method_hash": null, "human_readable": null, "system_instruction": null, "datasets": [], "tags": {"hst": [], "hsu": [], "emp": [], "pjt": []}, "ambiente": {"timezone": "Europe/Madrid", "locale": "es-ES"} }'::jsonb, -- ============================================ -- BLOQUE deployment (S-CONTRACT v2.1) -- Configuración de despliegue asociada -- ============================================ deployment JSONB DEFAULT '{ "mode": "SEMI", "tier_preference": ["SELF_HOSTED", "EXTERNAL"] }'::jsonb, -- Alcance scope VARCHAR(50) DEFAULT 'global', -- global, project, task project_id UUID REFERENCES task_projects(id) ON DELETE SET NULL, -- Estado activo BOOLEAN DEFAULT true, -- Metadata (campos no S-CONTRACT, solo para gestión interna) metadata JSONB DEFAULT '{}', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); CREATE INDEX IF NOT EXISTS idx_scontract_ctx_codigo ON s_contract_contexts(codigo); CREATE INDEX IF NOT EXISTS idx_scontract_ctx_scope ON s_contract_contexts(scope); CREATE INDEX IF NOT EXISTS idx_scontract_ctx_project ON s_contract_contexts(project_id); CREATE INDEX IF NOT EXISTS idx_scontract_ctx_activo ON s_contract_contexts(activo); CREATE INDEX IF NOT EXISTS idx_scontract_ctx_context ON s_contract_contexts USING GIN(context); CREATE INDEX IF NOT EXISTS idx_scontract_ctx_deployment ON s_contract_contexts USING GIN(deployment); DROP TRIGGER IF EXISTS update_scontract_ctx_updated_at ON s_contract_contexts; CREATE TRIGGER update_scontract_ctx_updated_at BEFORE UPDATE ON s_contract_contexts FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- ============================================ -- TABLA: s_contract_datasets -- Datasets reutilizables (formato S-CONTRACT context.datasets[]) -- ============================================ CREATE TABLE IF NOT EXISTS s_contract_datasets ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- Campos que mapean a context.datasets[] en S-CONTRACT codigo VARCHAR(100) UNIQUE NOT NULL, tipo VARCHAR(50) NOT NULL, -- knowledge, examples, rules, vocabulary, context, persona contenido TEXT, -- Contenido inline contenido_ref TEXT, -- URI a contenido externo -- Campos adicionales de gestión (no van en S-CONTRACT) nombre VARCHAR(255) NOT NULL, descripcion TEXT, version VARCHAR(20) DEFAULT '1.0', scope VARCHAR(50) DEFAULT 'global', project_id UUID REFERENCES task_projects(id) ON DELETE SET NULL, activo BOOLEAN DEFAULT true, metadata JSONB DEFAULT '{}', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, CONSTRAINT chk_dataset_tipo CHECK (tipo IN ('knowledge', 'examples', 'rules', 'vocabulary', 'context', 'persona')) ); CREATE INDEX IF NOT EXISTS idx_scontract_ds_codigo ON s_contract_datasets(codigo); CREATE INDEX IF NOT EXISTS idx_scontract_ds_tipo ON s_contract_datasets(tipo); CREATE INDEX IF NOT EXISTS idx_scontract_ds_activo ON s_contract_datasets(activo); DROP TRIGGER IF EXISTS update_scontract_ds_updated_at ON s_contract_datasets; CREATE TRIGGER update_scontract_ds_updated_at BEFORE UPDATE ON s_contract_datasets FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- ============================================ -- FUNCIÓN: Convertir dataset a formato S-CONTRACT -- ============================================ CREATE OR REPLACE FUNCTION dataset_to_scontract(p_dataset_id UUID) RETURNS JSONB AS $$ SELECT jsonb_build_object( 'codigo', codigo, 'tipo', tipo, 'contenido', contenido, 'contenido_ref', contenido_ref ) FROM s_contract_datasets WHERE id = p_dataset_id AND activo = true; $$ LANGUAGE SQL STABLE; -- ============================================ -- FUNCIÓN: Obtener context block para S-CONTRACT -- Devuelve EXACTAMENTE el formato de context en S-CONTRACT -- ============================================ CREATE OR REPLACE FUNCTION get_scontract_context(p_context_codigo VARCHAR) RETURNS JSONB AS $$ SELECT context FROM s_contract_contexts WHERE codigo = p_context_codigo AND activo = true; $$ LANGUAGE SQL STABLE; -- ============================================ -- FUNCIÓN: Obtener deployment block para S-CONTRACT -- ============================================ CREATE OR REPLACE FUNCTION get_scontract_deployment(p_context_codigo VARCHAR) RETURNS JSONB AS $$ SELECT deployment FROM s_contract_contexts WHERE codigo = p_context_codigo AND activo = true; $$ LANGUAGE SQL STABLE; -- ============================================ -- FUNCIÓN: Construir context con datasets expandidos -- Útil cuando se quiere incluir datasets por código -- ============================================ CREATE OR REPLACE FUNCTION build_scontract_context( p_context_codigo VARCHAR, p_dataset_codigos VARCHAR[] DEFAULT NULL ) RETURNS JSONB AS $$ DECLARE base_context JSONB; datasets_array JSONB; BEGIN -- Obtener contexto base SELECT context INTO base_context FROM s_contract_contexts WHERE codigo = p_context_codigo AND activo = true; IF base_context IS NULL THEN RETURN NULL; END IF; -- Si se especifican datasets, construir el array IF p_dataset_codigos IS NOT NULL AND array_length(p_dataset_codigos, 1) > 0 THEN SELECT jsonb_agg( jsonb_build_object( 'codigo', d.codigo, 'tipo', d.tipo, 'contenido', d.contenido, 'contenido_ref', d.contenido_ref ) ) INTO datasets_array FROM s_contract_datasets d WHERE d.codigo = ANY(p_dataset_codigos) AND d.activo = true; -- Reemplazar datasets en el contexto base_context := jsonb_set(base_context, '{datasets}', COALESCE(datasets_array, '[]'::jsonb)); END IF; RETURN base_context; END; $$ LANGUAGE plpgsql STABLE; -- ============================================ -- FUNCIÓN: Actualizar campo específico del context -- ============================================ CREATE OR REPLACE FUNCTION update_scontract_context_field( p_context_codigo VARCHAR, p_field_path TEXT[], p_value JSONB ) RETURNS BOOLEAN AS $$ BEGIN UPDATE s_contract_contexts SET context = jsonb_set(context, p_field_path, p_value), updated_at = CURRENT_TIMESTAMP WHERE codigo = p_context_codigo; RETURN FOUND; END; $$ LANGUAGE plpgsql; -- ============================================ -- Añadir FK en task_manager -- ============================================ -- Eliminar columna antigua si existe ALTER TABLE task_manager DROP COLUMN IF EXISTS context_id; -- Añadir referencia al contexto S-CONTRACT ALTER TABLE task_manager ADD COLUMN IF NOT EXISTS scontract_context_codigo VARCHAR(100); -- Añadir FK en task_projects ALTER TABLE task_projects DROP COLUMN IF EXISTS default_context_id; ALTER TABLE task_projects ADD COLUMN IF NOT EXISTS default_scontract_context VARCHAR(100); -- ============================================ -- DATOS INICIALES -- ============================================ -- Contexto por defecto INSERT INTO s_contract_contexts (codigo, nombre, descripcion, context, deployment) VALUES ( 'CTX_DEFAULT', 'Contexto por defecto', 'Contexto base para operaciones sin configuración específica', '{ "lang": "es", "mode": "strict", "pii_filter": false, "bandera_id": null, "player_id": null, "method_hash": null, "human_readable": null, "system_instruction": "Procesa la información recibida de forma precisa. Responde en español.", "datasets": [], "tags": {"hst": [], "hsu": [], "emp": [], "pjt": []}, "ambiente": { "timezone": "Europe/Madrid", "locale": "es-ES", "currency": "EUR" } }'::jsonb, '{ "mode": "SEMI", "tier_preference": ["SELF_HOSTED", "EXTERNAL"] }'::jsonb ), ( 'CTX_GRACE', 'Contexto para GRACE', 'Contexto optimizado para procesamiento GRACE', '{ "lang": "es", "mode": "strict", "pii_filter": false, "system_instruction": "Eres un asistente de procesamiento del sistema GRACE. Procesa los datos de forma estructurada y precisa. Si hay incertidumbre, indica el nivel de confianza.", "datasets": [], "tags": {"hst": [], "hsu": [], "emp": [], "pjt": []}, "ambiente": { "timezone": "Europe/Madrid", "locale": "es-ES" } }'::jsonb, '{"mode": "SEMI", "tier_preference": ["SELF_HOSTED", "EXTERNAL"]}'::jsonb ), ( 'CTX_PENNY', 'Contexto para PENNY', 'Contexto optimizado para asistente de voz PENNY', '{ "lang": "es", "mode": "lenient", "pii_filter": false, "system_instruction": "Eres PENNY, un asistente de voz amable y eficiente. Responde de forma concisa (máximo 2-3 oraciones). Usa tono conversacional pero profesional.", "datasets": [], "tags": {"hst": [], "hsu": [], "emp": [], "pjt": []}, "ambiente": { "timezone": "Europe/Madrid", "locale": "es-ES", "session_type": "interactive" } }'::jsonb, '{"mode": "SEMI", "tier_preference": ["SELF_HOSTED", "EXTERNAL"]}'::jsonb ), ( 'CTX_FACTORY', 'Contexto para THE FACTORY', 'Contexto optimizado para procesamiento documental', '{ "lang": "es", "mode": "strict", "pii_filter": true, "system_instruction": "Eres un procesador de documentos de THE FACTORY. Extrae información de forma estructurada. Mantén fidelidad al documento original. Señala incertidumbres con [INCIERTO: razón].", "datasets": [], "tags": {"hst": [], "hsu": [], "emp": [], "pjt": []}, "ambiente": { "timezone": "Europe/Madrid", "locale": "es-ES", "session_type": "batch" } }'::jsonb, '{"mode": "SEMI", "tier_preference": ["EXTERNAL", "SELF_HOSTED"]}'::jsonb ) ON CONFLICT (codigo) DO UPDATE SET context = EXCLUDED.context, deployment = EXCLUDED.deployment, updated_at = CURRENT_TIMESTAMP; -- Datasets base INSERT INTO s_contract_datasets (codigo, nombre, tipo, contenido) VALUES ( 'DS_TZZR_ECOSYSTEM', 'Ecosistema TZZR', 'knowledge', 'TZZR es un ecosistema personal de productividad: - DECK: Servidor central, iniciador de conexiones - GRACE: Capa de procesamiento IA - PENNY: Asistente de voz real-time - THE FACTORY: Procesamiento documental Sistema de etiquetas HST con h_maestro (SHA-256) como ID único.' ), ( 'DS_HST_INTRO', 'Introducción HST', 'vocabulary', 'Grupos de etiquetas HST: - hst: Sistema (sync tzrtech.org) - emp: Empresa - hsu: Usuario - pjt: Proyecto Cada etiqueta tiene: codigo, nombre, descripcion, color, jerarquía.' ) ON CONFLICT (codigo) DO UPDATE SET contenido = EXCLUDED.contenido, updated_at = CURRENT_TIMESTAMP;