Update to Skynet v7 - Complete documentation restructure

- Nueva estructura de carpetas según Skynet v7
- Añadidos schemas SQL completos
- Documentación de entidades, componentes e integraciones
- Modelo de seguridad actualizado
- Infraestructura y operaciones reorganizadas
This commit is contained in:
ARCHITECT
2025-12-29 18:23:41 +00:00
parent ac481fe266
commit 6ea70bd34f
76 changed files with 13029 additions and 4340 deletions

View File

@@ -0,0 +1,101 @@
-- ============================================
-- TIPOS ENUMERADOS COMUNES
-- Sistema TZZR - contratos-comunes
-- ============================================
-- Aplicar primero antes de cualquier otro schema
-- Estados de tarea
DO $$ BEGIN
CREATE TYPE task_status AS ENUM (
'draft', -- Borrador, no iniciada
'pending', -- Pendiente de inicio
'in_progress', -- En progreso
'blocked', -- Bloqueada por dependencia
'review', -- En revisión
'completed', -- Completada
'cancelled' -- Cancelada
);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
-- Prioridad de tarea
DO $$ BEGIN
CREATE TYPE task_priority AS ENUM (
'critical', -- Crítica, atención inmediata
'high', -- Alta prioridad
'medium', -- Media (default)
'low', -- Baja prioridad
'someday' -- Algún día / sin fecha
);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
-- Dirección de archivo en work log
DO $$ BEGIN
CREATE TYPE file_direction AS ENUM (
'inbound', -- Archivo recibido
'outbound', -- Archivo enviado
'internal', -- Archivo interno/generado
'reference' -- Archivo de referencia
);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
-- Servicios de IA del ecosistema
DO $$ BEGIN
CREATE TYPE ai_service AS ENUM (
'grace', -- GRACE - Capa de procesamiento
'penny', -- PENNY - Asistente de voz
'factory' -- THE FACTORY - Procesamiento documental
);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
-- Grupos de etiquetas HST
DO $$ BEGIN
CREATE TYPE hst_grupo AS ENUM (
'hst', -- Sistema (sync tzrtech.org)
'emp', -- Empresa
'hsu', -- Usuario
'pjt' -- Proyecto
);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
-- Modo de despliegue S-CONTRACT
DO $$ BEGIN
CREATE TYPE deployment_mode AS ENUM (
'EXTERNAL', -- Solo APIs externas
'SELF_HOSTED', -- Solo infraestructura propia
'SEMI' -- Híbrido con fallback
);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
-- Tier de proveedor
DO $$ BEGIN
CREATE TYPE provider_tier AS ENUM (
'SELF_HOSTED', -- Infraestructura propia
'EXTERNAL' -- API externa
);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
-- ============================================
-- FUNCIÓN: Actualizar updated_at automáticamente
-- ============================================
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ language 'plpgsql';

View File

@@ -0,0 +1,227 @@
-- ============================================
-- TABLAS HST (Sistema de Etiquetas)
-- Sistema TZZR - contratos-comunes
-- ============================================
-- Requiere: 00_types.sql
--
-- SISTEMA DUAL DE HASHES:
-- ┌─────────────────────────────────────────────────────────────┐
-- │ h_maestro = SHA-256(grupo || ':' || ref) │
-- │ → Identidad SEMÁNTICA (determinista, para S-CONTRACT) │
-- │ → Ejemplo: SHA-256("hst:finanzas") = "a7b3c9..." │
-- │ │
-- │ mrf = SHA-256(bytes_imagen) │
-- │ → Identidad de ARCHIVO (para servir imágenes) │
-- │ → URL: https://tzrtech.org/{mrf}.png │
-- └─────────────────────────────────────────────────────────────┘
-- ============================================
-- TABLA BASE: hst_tags
-- Tabla unificada de etiquetas HST
-- ============================================
CREATE TABLE IF NOT EXISTS hst_tags (
id SERIAL PRIMARY KEY,
-- Identificadores duales
h_maestro VARCHAR(64) UNIQUE NOT NULL, -- SHA-256(grupo:ref), identidad semántica
ref VARCHAR(50) NOT NULL, -- Referencia corta (ej: "finanzas")
mrf VARCHAR(64), -- SHA-256(imagen_bytes), hash de imagen
-- Nombres
nombre VARCHAR(100) NOT NULL, -- Nombre legible en español
nombre_en VARCHAR(100), -- Nombre en inglés
descripcion TEXT,
-- Visual
imagen_url TEXT, -- URL completa (https://tzrtech.org/{mrf}.png)
color VARCHAR(7), -- Color hex (#RRGGBB)
icono VARCHAR(50), -- Nombre de icono (ej: lucide:tag)
-- Clasificación
grupo hst_grupo NOT NULL, -- hst, emp, hsu, pjt
categoria VARCHAR(100), -- Categoría dentro del grupo
-- Jerarquía
padre_h_maestro VARCHAR(64) REFERENCES hst_tags(h_maestro),
rootref VARCHAR(50), -- Ref del ancestro raíz
nivel INTEGER DEFAULT 0, -- Nivel de profundidad (0 = raíz)
path_h_maestros TEXT[], -- Array de ancestros para queries rápidas
-- Estado
activo BOOLEAN DEFAULT true,
visible BOOLEAN DEFAULT true, -- Visible en UI
-- Sync con tzrtech.org
source VARCHAR(50) DEFAULT 'local', -- local, tzrtech, empresa
source_id VARCHAR(100), -- ID en el sistema origen
synced_at TIMESTAMP, -- Última sincronización
-- Metadata
metadata JSONB DEFAULT '{}',
-- Timestamps
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
-- Constraints
CONSTRAINT unique_ref_grupo UNIQUE(ref, grupo)
);
-- Índices principales
CREATE INDEX IF NOT EXISTS idx_hst_tags_h_maestro ON hst_tags(h_maestro);
CREATE INDEX IF NOT EXISTS idx_hst_tags_ref ON hst_tags(ref);
CREATE INDEX IF NOT EXISTS idx_hst_tags_mrf ON hst_tags(mrf);
CREATE INDEX IF NOT EXISTS idx_hst_tags_grupo ON hst_tags(grupo);
CREATE INDEX IF NOT EXISTS idx_hst_tags_categoria ON hst_tags(categoria);
CREATE INDEX IF NOT EXISTS idx_hst_tags_padre ON hst_tags(padre_h_maestro);
CREATE INDEX IF NOT EXISTS idx_hst_tags_rootref ON hst_tags(rootref);
CREATE INDEX IF NOT EXISTS idx_hst_tags_activo ON hst_tags(activo);
CREATE INDEX IF NOT EXISTS idx_hst_tags_path ON hst_tags USING GIN(path_h_maestros);
-- Trigger para updated_at
DROP TRIGGER IF EXISTS update_hst_tags_updated_at ON hst_tags;
CREATE TRIGGER update_hst_tags_updated_at BEFORE UPDATE ON hst_tags
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
-- ============================================
-- FUNCIÓN: Calcular path de ancestros
-- ============================================
CREATE OR REPLACE FUNCTION calculate_hst_path()
RETURNS TRIGGER AS $$
DECLARE
parent_path TEXT[];
BEGIN
IF NEW.padre_h_maestro IS NULL THEN
NEW.path_h_maestros := ARRAY[]::TEXT[];
NEW.nivel := 0;
ELSE
SELECT path_h_maestros, nivel + 1
INTO parent_path, NEW.nivel
FROM hst_tags
WHERE h_maestro = NEW.padre_h_maestro;
NEW.path_h_maestros := array_append(parent_path, NEW.padre_h_maestro);
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS trigger_calculate_hst_path ON hst_tags;
CREATE TRIGGER trigger_calculate_hst_path
BEFORE INSERT OR UPDATE OF padre_h_maestro ON hst_tags
FOR EACH ROW EXECUTE FUNCTION calculate_hst_path();
-- ============================================
-- VISTAS POR GRUPO (Compatibilidad con v2)
-- ============================================
-- Vista: Etiquetas del sistema (HST)
CREATE OR REPLACE VIEW hst_tags_sistema AS
SELECT * FROM hst_tags WHERE grupo = 'hst';
-- Vista: Etiquetas de empresa (EMP)
CREATE OR REPLACE VIEW hst_tags_empresa AS
SELECT * FROM hst_tags WHERE grupo = 'emp';
-- Vista: Etiquetas de usuario (HSU)
CREATE OR REPLACE VIEW hst_tags_usuario AS
SELECT * FROM hst_tags WHERE grupo = 'hsu';
-- Vista: Etiquetas de proyecto (PJT)
CREATE OR REPLACE VIEW hst_tags_proyecto AS
SELECT * FROM hst_tags WHERE grupo = 'pjt';
-- ============================================
-- TABLA: hst_tag_relations
-- Relaciones entre etiquetas (sinónimos, relacionados)
-- ============================================
CREATE TABLE IF NOT EXISTS hst_tag_relations (
id SERIAL PRIMARY KEY,
tag_a_h_maestro VARCHAR(64) NOT NULL REFERENCES hst_tags(h_maestro),
tag_b_h_maestro VARCHAR(64) NOT NULL REFERENCES hst_tags(h_maestro),
-- Tipo de relación
relation_type VARCHAR(50) NOT NULL, -- synonym, related, opposite, child_of
strength DECIMAL(3,2) DEFAULT 1.0, -- Fuerza de la relación (0-1)
bidirectional BOOLEAN DEFAULT true,
metadata JSONB DEFAULT '{}',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT unique_tag_relation UNIQUE(tag_a_h_maestro, tag_b_h_maestro, relation_type),
CONSTRAINT chk_different_tags CHECK (tag_a_h_maestro != tag_b_h_maestro)
);
CREATE INDEX IF NOT EXISTS idx_tag_relations_a ON hst_tag_relations(tag_a_h_maestro);
CREATE INDEX IF NOT EXISTS idx_tag_relations_b ON hst_tag_relations(tag_b_h_maestro);
CREATE INDEX IF NOT EXISTS idx_tag_relations_type ON hst_tag_relations(relation_type);
-- ============================================
-- FUNCIÓN: Generar h_maestro (DETERMINISTA)
-- SHA-256(grupo || ':' || ref)
-- ============================================
CREATE OR REPLACE FUNCTION generate_h_maestro(p_grupo TEXT, p_ref TEXT)
RETURNS VARCHAR(64) AS $$
BEGIN
-- DETERMINISTA: mismo input = mismo output SIEMPRE
RETURN encode(sha256((p_grupo || ':' || p_ref)::bytea), 'hex');
END;
$$ LANGUAGE plpgsql IMMUTABLE;
-- ============================================
-- FUNCIÓN: Generar imagen_url desde mrf
-- ============================================
CREATE OR REPLACE FUNCTION generate_imagen_url(p_mrf VARCHAR(64))
RETURNS TEXT AS $$
BEGIN
IF p_mrf IS NULL THEN
RETURN NULL;
END IF;
RETURN 'https://tzrtech.org/' || p_mrf || '.png';
END;
$$ LANGUAGE plpgsql IMMUTABLE;
-- ============================================
-- DATOS INICIALES: Categorías base
-- Nota: Los datos reales vienen de tzrtech.org/api/index.json
-- ============================================
INSERT INTO hst_tags (h_maestro, ref, nombre, nombre_en, grupo, categoria, color) VALUES
(generate_h_maestro('hst', 'trabajo'), 'trabajo', 'Trabajo', 'Work', 'hst', 'actividad', '#3498db'),
(generate_h_maestro('hst', 'personal'), 'personal', 'Personal', 'Personal', 'hst', 'actividad', '#2ecc71'),
(generate_h_maestro('hst', 'urgente'), 'urgente', 'Urgente', 'Urgent', 'hst', 'prioridad', '#e74c3c'),
(generate_h_maestro('hst', 'proyecto'), 'proyecto', 'Proyecto', 'Project', 'hst', 'organizacion', '#9b59b6'),
(generate_h_maestro('hst', 'factura'), 'factura', 'Factura', 'Invoice', 'hst', 'documento', '#f39c12'),
(generate_h_maestro('hst', 'contrato'), 'contrato', 'Contrato', 'Contract', 'hst', 'documento', '#1abc9c'),
(generate_h_maestro('hst', 'email'), 'email', 'Email', 'Email', 'hst', 'comunicacion', '#34495e'),
(generate_h_maestro('hst', 'reunion'), 'reunion', 'Reunión', 'Meeting', 'hst', 'evento', '#e67e22')
ON CONFLICT (h_maestro) DO NOTHING;
-- ============================================
-- VISTA: API JSON compatible con tzrtech.org
-- ============================================
CREATE OR REPLACE VIEW hst_api_index AS
SELECT
ref,
h_maestro,
mrf,
nombre AS nombre_es,
nombre_en,
grupo,
categoria,
color,
imagen_url,
padre_h_maestro,
rootref,
nivel,
activo
FROM hst_tags
WHERE activo = true
ORDER BY grupo, nivel, nombre;

View File

@@ -0,0 +1,290 @@
-- ============================================
-- GESTOR DE TAREAS
-- Sistema TZZR - contratos-comunes
-- ============================================
-- Requiere: 00_types.sql, 01_hst_tags.sql
-- ============================================
-- TABLA: task_projects
-- Proyectos que agrupan tareas
-- ============================================
CREATE TABLE IF NOT EXISTS task_projects (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
codigo VARCHAR(50) UNIQUE NOT NULL, -- Código corto (ej: DECK-2024)
nombre VARCHAR(255) NOT NULL,
descripcion TEXT,
-- Estado
activo BOOLEAN DEFAULT true,
archivado BOOLEAN DEFAULT false,
fecha_inicio DATE,
fecha_fin_estimada DATE,
fecha_fin_real DATE,
-- Etiquetas (array de h_maestro)
tags JSONB DEFAULT '[]',
-- Configuración de contexto por defecto
default_context_id UUID, -- FK a task_contexts (añadido después)
-- Metadata
metadata JSONB DEFAULT '{}',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
CREATE INDEX IF NOT EXISTS idx_task_projects_codigo ON task_projects(codigo);
CREATE INDEX IF NOT EXISTS idx_task_projects_activo ON task_projects(activo);
CREATE INDEX IF NOT EXISTS idx_task_projects_tags ON task_projects USING GIN(tags);
DROP TRIGGER IF EXISTS update_task_projects_updated_at ON task_projects;
CREATE TRIGGER update_task_projects_updated_at BEFORE UPDATE ON task_projects
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
-- ============================================
-- TABLA: task_milestones
-- Hitos dentro de un proyecto
-- ============================================
CREATE TABLE IF NOT EXISTS task_milestones (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
project_id UUID REFERENCES task_projects(id) ON DELETE CASCADE,
codigo VARCHAR(50) NOT NULL, -- Código dentro del proyecto
nombre VARCHAR(255) NOT NULL,
descripcion TEXT,
-- Orden y jerarquía
orden INTEGER DEFAULT 0,
parent_milestone_id UUID REFERENCES task_milestones(id),
-- Fechas
fecha_objetivo DATE,
fecha_completado DATE,
-- Progreso (calculado automáticamente)
progreso_percent DECIMAL(5,2) DEFAULT 0,
-- Etiquetas
tags JSONB DEFAULT '[]',
metadata JSONB DEFAULT '{}',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT unique_milestone_code UNIQUE(project_id, codigo)
);
CREATE INDEX IF NOT EXISTS idx_task_milestones_project ON task_milestones(project_id);
CREATE INDEX IF NOT EXISTS idx_task_milestones_parent ON task_milestones(parent_milestone_id);
CREATE INDEX IF NOT EXISTS idx_task_milestones_orden ON task_milestones(orden);
DROP TRIGGER IF EXISTS update_task_milestones_updated_at ON task_milestones;
CREATE TRIGGER update_task_milestones_updated_at BEFORE UPDATE ON task_milestones
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
-- ============================================
-- TABLA: task_blocks
-- Bloques de trabajo dentro de milestones
-- ============================================
CREATE TABLE IF NOT EXISTS task_blocks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
milestone_id UUID REFERENCES task_milestones(id) ON DELETE CASCADE,
codigo VARCHAR(50) NOT NULL,
nombre VARCHAR(255) NOT NULL,
descripcion TEXT,
-- Orden
orden INTEGER DEFAULT 0,
-- Estimación
horas_estimadas DECIMAL(6,2),
horas_reales DECIMAL(6,2),
-- Estado
status task_status DEFAULT 'pending',
-- Etiquetas
tags JSONB DEFAULT '[]',
metadata JSONB DEFAULT '{}',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT unique_block_code UNIQUE(milestone_id, codigo)
);
CREATE INDEX IF NOT EXISTS idx_task_blocks_milestone ON task_blocks(milestone_id);
CREATE INDEX IF NOT EXISTS idx_task_blocks_status ON task_blocks(status);
DROP TRIGGER IF EXISTS update_task_blocks_updated_at ON task_blocks;
CREATE TRIGGER update_task_blocks_updated_at BEFORE UPDATE ON task_blocks
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
-- ============================================
-- TABLA: task_manager
-- Tareas individuales
-- ============================================
CREATE TABLE IF NOT EXISTS task_manager (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
-- Jerarquía
project_id UUID REFERENCES task_projects(id) ON DELETE SET NULL,
milestone_id UUID REFERENCES task_milestones(id) ON DELETE SET NULL,
block_id UUID REFERENCES task_blocks(id) ON DELETE SET NULL,
parent_task_id UUID REFERENCES task_manager(id) ON DELETE SET NULL,
-- Identificación
codigo VARCHAR(100), -- Código único generado
titulo VARCHAR(500) NOT NULL,
descripcion TEXT,
-- Estado y prioridad
status task_status DEFAULT 'pending',
priority task_priority DEFAULT 'medium',
-- Fechas
fecha_creacion TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
fecha_inicio DATE,
fecha_vencimiento DATE,
fecha_completado TIMESTAMP,
-- Estimación
horas_estimadas DECIMAL(6,2),
horas_reales DECIMAL(6,2),
-- Asignación
asignado_a VARCHAR(100), -- Usuario o servicio
creado_por VARCHAR(100) DEFAULT 'system',
-- Etiquetas HST (separadas por grupo para queries eficientes)
tags_hst JSONB DEFAULT '[]', -- h_maestros de grupo hst
tags_hsu JSONB DEFAULT '[]', -- h_maestros de grupo hsu
tags_emp JSONB DEFAULT '[]', -- h_maestros de grupo emp
tags_pjt JSONB DEFAULT '[]', -- h_maestros de grupo pjt
-- Contexto IA
context_id UUID, -- FK a task_contexts (añadido después)
-- Archivos relacionados (array de UUIDs de work_log)
archivos_ref JSONB DEFAULT '[]',
-- Trazabilidad S-CONTRACT
trace_id VARCHAR(64),
-- Metadata
metadata JSONB DEFAULT '{}',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
CREATE INDEX IF NOT EXISTS idx_task_manager_project ON task_manager(project_id);
CREATE INDEX IF NOT EXISTS idx_task_manager_milestone ON task_manager(milestone_id);
CREATE INDEX IF NOT EXISTS idx_task_manager_block ON task_manager(block_id);
CREATE INDEX IF NOT EXISTS idx_task_manager_parent ON task_manager(parent_task_id);
CREATE INDEX IF NOT EXISTS idx_task_manager_status ON task_manager(status);
CREATE INDEX IF NOT EXISTS idx_task_manager_priority ON task_manager(priority);
CREATE INDEX IF NOT EXISTS idx_task_manager_fecha_venc ON task_manager(fecha_vencimiento);
CREATE INDEX IF NOT EXISTS idx_task_manager_asignado ON task_manager(asignado_a);
CREATE INDEX IF NOT EXISTS idx_task_manager_tags_hst ON task_manager USING GIN(tags_hst);
CREATE INDEX IF NOT EXISTS idx_task_manager_tags_hsu ON task_manager USING GIN(tags_hsu);
CREATE INDEX IF NOT EXISTS idx_task_manager_trace ON task_manager(trace_id);
DROP TRIGGER IF EXISTS update_task_manager_updated_at ON task_manager;
CREATE TRIGGER update_task_manager_updated_at BEFORE UPDATE ON task_manager
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
-- ============================================
-- TABLA: task_dependencies
-- Dependencias entre tareas
-- ============================================
CREATE TABLE IF NOT EXISTS task_dependencies (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
task_id UUID NOT NULL REFERENCES task_manager(id) ON DELETE CASCADE,
depends_on_task_id UUID NOT NULL REFERENCES task_manager(id) ON DELETE CASCADE,
-- Tipo de dependencia
tipo VARCHAR(50) DEFAULT 'finish_to_start',
-- finish_to_start: B empieza cuando A termina
-- start_to_start: B empieza cuando A empieza
-- finish_to_finish: B termina cuando A termina
-- start_to_finish: B termina cuando A empieza
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT unique_dependency UNIQUE(task_id, depends_on_task_id),
CONSTRAINT chk_no_self_dep CHECK (task_id != depends_on_task_id)
);
CREATE INDEX IF NOT EXISTS idx_task_deps_task ON task_dependencies(task_id);
CREATE INDEX IF NOT EXISTS idx_task_deps_depends ON task_dependencies(depends_on_task_id);
-- ============================================
-- FUNCIÓN: Actualizar progreso de milestone
-- ============================================
CREATE OR REPLACE FUNCTION update_milestone_progress()
RETURNS TRIGGER AS $$
BEGIN
UPDATE task_milestones
SET progreso_percent = (
SELECT COALESCE(
(COUNT(*) FILTER (WHERE status = 'completed')::DECIMAL /
NULLIF(COUNT(*), 0) * 100),
0
)
FROM task_manager
WHERE milestone_id = COALESCE(NEW.milestone_id, OLD.milestone_id)
),
updated_at = CURRENT_TIMESTAMP
WHERE id = COALESCE(NEW.milestone_id, OLD.milestone_id);
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS trigger_update_milestone_progress ON task_manager;
CREATE TRIGGER trigger_update_milestone_progress
AFTER INSERT OR UPDATE OF status OR DELETE ON task_manager
FOR EACH ROW EXECUTE FUNCTION update_milestone_progress();
-- ============================================
-- FUNCIÓN: Generar código de tarea
-- ============================================
CREATE OR REPLACE FUNCTION generate_task_codigo()
RETURNS TRIGGER AS $$
DECLARE
prefix VARCHAR(20);
seq INTEGER;
BEGIN
IF NEW.codigo IS NULL OR NEW.codigo = '' THEN
IF NEW.project_id IS NOT NULL THEN
SELECT codigo INTO prefix FROM task_projects WHERE id = NEW.project_id;
ELSE
prefix := 'TASK';
END IF;
SELECT COALESCE(MAX(
CAST(SUBSTRING(codigo FROM '[0-9]+$') AS INTEGER)
), 0) + 1
INTO seq
FROM task_manager
WHERE codigo LIKE prefix || '-%';
NEW.codigo := prefix || '-' || LPAD(seq::TEXT, 4, '0');
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS trigger_generate_task_codigo ON task_manager;
CREATE TRIGGER trigger_generate_task_codigo
BEFORE INSERT ON task_manager
FOR EACH ROW EXECUTE FUNCTION generate_task_codigo();

View File

@@ -0,0 +1,168 @@
-- ============================================
-- LOG DE TRABAJO (Work Log)
-- Sistema TZZR - contratos-comunes
-- ============================================
-- Requiere: 00_types.sql, 02_task_manager.sql
-- ============================================
-- TABLA: task_work_log
-- Registro de archivos entrantes/salientes
-- ============================================
CREATE TABLE IF NOT EXISTS task_work_log (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
-- Relación con tarea (opcional)
task_id UUID REFERENCES task_manager(id) ON DELETE SET NULL,
project_id UUID REFERENCES task_projects(id) ON DELETE SET NULL,
-- Dirección
direction file_direction NOT NULL,
-- Información del archivo
filename VARCHAR(500) NOT NULL,
filepath TEXT, -- Ruta en FileBrowser o URL
file_hash VARCHAR(64), -- SHA-256 del contenido
file_size_bytes BIGINT,
mime_type VARCHAR(100),
file_extension VARCHAR(20),
-- Origen/Destino
source VARCHAR(255), -- email, upload, api, scrape, etc.
source_ref VARCHAR(500), -- Referencia específica (message_id, url, etc.)
destination VARCHAR(255), -- grace, penny, factory, export, storage
destination_ref VARCHAR(500),
-- Procesamiento IA
processed_by_ia BOOLEAN DEFAULT false,
ai_service ai_service,
ai_module VARCHAR(50), -- Módulo específico (ASR_ENGINE, OCR_CORE, etc.)
ai_trace_id VARCHAR(64), -- trace_id del S-CONTRACT
ai_status VARCHAR(20), -- SUCCESS, ERROR, PARTIAL
ai_result_summary JSONB, -- Resumen del resultado
-- Descripción
titulo VARCHAR(255),
descripcion TEXT,
-- Etiquetas (h_maestros)
tags JSONB DEFAULT '[]',
-- Metadata
metadata JSONB DEFAULT '{}',
-- Timestamps
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
processed_at TIMESTAMP
);
CREATE INDEX IF NOT EXISTS idx_work_log_task ON task_work_log(task_id);
CREATE INDEX IF NOT EXISTS idx_work_log_project ON task_work_log(project_id);
CREATE INDEX IF NOT EXISTS idx_work_log_direction ON task_work_log(direction);
CREATE INDEX IF NOT EXISTS idx_work_log_hash ON task_work_log(file_hash);
CREATE INDEX IF NOT EXISTS idx_work_log_source ON task_work_log(source);
CREATE INDEX IF NOT EXISTS idx_work_log_destination ON task_work_log(destination);
CREATE INDEX IF NOT EXISTS idx_work_log_ai_service ON task_work_log(ai_service);
CREATE INDEX IF NOT EXISTS idx_work_log_ai_trace ON task_work_log(ai_trace_id);
CREATE INDEX IF NOT EXISTS idx_work_log_fecha ON task_work_log(created_at);
CREATE INDEX IF NOT EXISTS idx_work_log_tags ON task_work_log USING GIN(tags);
CREATE INDEX IF NOT EXISTS idx_work_log_mime ON task_work_log(mime_type);
-- ============================================
-- TABLA: task_work_log_versions
-- Versiones de archivos (tracking de cambios)
-- ============================================
CREATE TABLE IF NOT EXISTS task_work_log_versions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
work_log_id UUID NOT NULL REFERENCES task_work_log(id) ON DELETE CASCADE,
version INTEGER NOT NULL,
filepath TEXT NOT NULL,
file_hash VARCHAR(64) NOT NULL,
file_size_bytes BIGINT,
-- Cambio
change_type VARCHAR(50), -- created, modified, processed, exported
change_description TEXT,
changed_by VARCHAR(100),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT unique_version UNIQUE(work_log_id, version)
);
CREATE INDEX IF NOT EXISTS idx_work_log_versions_log ON task_work_log_versions(work_log_id);
CREATE INDEX IF NOT EXISTS idx_work_log_versions_hash ON task_work_log_versions(file_hash);
-- ============================================
-- FUNCIÓN: Auto-incrementar versión
-- ============================================
CREATE OR REPLACE FUNCTION auto_version_work_log()
RETURNS TRIGGER AS $$
DECLARE
next_version INTEGER;
BEGIN
SELECT COALESCE(MAX(version), 0) + 1
INTO next_version
FROM task_work_log_versions
WHERE work_log_id = NEW.work_log_id;
NEW.version := next_version;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
DROP TRIGGER IF EXISTS trigger_auto_version_work_log ON task_work_log_versions;
CREATE TRIGGER trigger_auto_version_work_log
BEFORE INSERT ON task_work_log_versions
FOR EACH ROW EXECUTE FUNCTION auto_version_work_log();
-- ============================================
-- VISTA: Work log reciente
-- ============================================
CREATE OR REPLACE VIEW v_work_log_recent AS
SELECT
w.id,
w.filename,
w.direction,
w.source,
w.destination,
w.ai_service,
w.ai_module,
w.ai_status,
w.processed_by_ia,
t.titulo AS tarea,
t.codigo AS tarea_codigo,
p.nombre AS proyecto,
p.codigo AS proyecto_codigo,
w.file_size_bytes,
w.mime_type,
w.created_at,
w.processed_at
FROM task_work_log w
LEFT JOIN task_manager t ON w.task_id = t.id
LEFT JOIN task_projects p ON w.project_id = p.id
ORDER BY w.created_at DESC;
-- ============================================
-- VISTA: Archivos pendientes de procesar
-- ============================================
CREATE OR REPLACE VIEW v_work_log_pending AS
SELECT
w.id,
w.filename,
w.mime_type,
w.file_size_bytes,
w.source,
w.direction,
p.nombre AS proyecto,
w.created_at
FROM task_work_log w
LEFT JOIN task_projects p ON w.project_id = p.id
WHERE w.processed_by_ia = false
AND w.direction IN ('inbound', 'internal')
ORDER BY w.created_at ASC;

View File

@@ -0,0 +1,354 @@
-- ============================================
-- 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;

View File

@@ -0,0 +1,277 @@
-- ============================================
-- LOG DE REQUESTS A SERVICIOS IA
-- Sistema TZZR - contratos-comunes
-- ============================================
-- Requiere: 00_types.sql, 02_task_manager.sql, 03_work_log.sql, 04_ai_context.sql
-- ============================================
-- TABLA: task_ai_requests
-- Registro de todas las requests a servicios IA
-- ============================================
CREATE TABLE IF NOT EXISTS task_ai_requests (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
-- Trazabilidad S-CONTRACT
trace_id VARCHAR(64) NOT NULL, -- trace_id del S-CONTRACT
idempotency_key VARCHAR(64), -- Para deduplicación
step_id VARCHAR(64), -- ID del paso en cadena
step_index INTEGER, -- Posición en la cadena
-- Origen
task_id UUID REFERENCES task_manager(id) ON DELETE SET NULL,
work_log_id UUID REFERENCES task_work_log(id) ON DELETE SET NULL,
project_id UUID REFERENCES task_projects(id) ON DELETE SET NULL,
-- Destino
target_service ai_service NOT NULL,
target_module VARCHAR(50) NOT NULL, -- ASR_ENGINE, CLASSIFIER, OCR_CORE, etc.
-- Contexto usado
context_id UUID REFERENCES task_contexts(id) ON DELETE SET NULL,
context_snapshot JSONB, -- Snapshot del contexto en el momento
-- Deployment
deployment_mode deployment_mode,
tier_requested provider_tier,
tier_used provider_tier,
provider_used VARCHAR(50),
endpoint_used TEXT,
-- Request (sin contenido sensible)
request_summary JSONB, -- Resumen de la request
payload_type VARCHAR(50), -- text, audio, image, document
payload_size_bytes BIGINT,
payload_hash VARCHAR(64),
-- Response
status VARCHAR(20) NOT NULL, -- SUCCESS, PARTIAL, ERROR, TIMEOUT, FALLBACK
fallback_level INTEGER DEFAULT 0,
response_summary JSONB, -- Resumen de respuesta
output_schema VARCHAR(100),
output_hash VARCHAR(64),
-- Calidad
confidence DECIMAL(4,3),
coverage DECIMAL(4,3),
validation_passed BOOLEAN,
-- Métricas
latency_ms INTEGER,
queue_wait_ms INTEGER,
tokens_input INTEGER,
tokens_output INTEGER,
cost_usd DECIMAL(10,6),
-- Errores
error_code VARCHAR(50),
error_message TEXT,
retry_count INTEGER DEFAULT 0,
-- Timestamps
timestamp_init TIMESTAMP NOT NULL,
timestamp_end TIMESTAMP,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Índices principales
CREATE INDEX IF NOT EXISTS idx_ai_requests_trace ON task_ai_requests(trace_id);
CREATE INDEX IF NOT EXISTS idx_ai_requests_idempotency ON task_ai_requests(idempotency_key);
CREATE INDEX IF NOT EXISTS idx_ai_requests_task ON task_ai_requests(task_id);
CREATE INDEX IF NOT EXISTS idx_ai_requests_work_log ON task_ai_requests(work_log_id);
CREATE INDEX IF NOT EXISTS idx_ai_requests_project ON task_ai_requests(project_id);
CREATE INDEX IF NOT EXISTS idx_ai_requests_service ON task_ai_requests(target_service);
CREATE INDEX IF NOT EXISTS idx_ai_requests_module ON task_ai_requests(target_module);
CREATE INDEX IF NOT EXISTS idx_ai_requests_status ON task_ai_requests(status);
CREATE INDEX IF NOT EXISTS idx_ai_requests_fecha ON task_ai_requests(timestamp_init);
CREATE INDEX IF NOT EXISTS idx_ai_requests_tier ON task_ai_requests(tier_used);
CREATE INDEX IF NOT EXISTS idx_ai_requests_provider ON task_ai_requests(provider_used);
-- Índice para métricas temporales
CREATE INDEX IF NOT EXISTS idx_ai_requests_fecha_service ON task_ai_requests(timestamp_init, target_service);
-- ============================================
-- TABLA: task_ai_request_chain
-- Cadenas de requests relacionadas
-- ============================================
CREATE TABLE IF NOT EXISTS task_ai_request_chain (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
-- Trace principal de la cadena
chain_trace_id VARCHAR(64) NOT NULL,
-- Request en la cadena
request_id UUID NOT NULL REFERENCES task_ai_requests(id) ON DELETE CASCADE,
-- Posición
chain_index INTEGER NOT NULL,
-- Dependencias (requests previas necesarias)
depends_on JSONB DEFAULT '[]', -- Array de request_ids
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
CONSTRAINT unique_chain_position UNIQUE(chain_trace_id, chain_index)
);
CREATE INDEX IF NOT EXISTS idx_request_chain_trace ON task_ai_request_chain(chain_trace_id);
CREATE INDEX IF NOT EXISTS idx_request_chain_request ON task_ai_request_chain(request_id);
-- ============================================
-- VISTAS DE MÉTRICAS
-- ============================================
-- Vista: Métricas por servicio (últimos 30 días)
CREATE OR REPLACE VIEW v_ai_metrics_by_service AS
SELECT
target_service,
target_module,
COUNT(*) AS total_requests,
COUNT(*) FILTER (WHERE status = 'SUCCESS') AS successful,
COUNT(*) FILTER (WHERE status = 'ERROR') AS errors,
COUNT(*) FILTER (WHERE status = 'FALLBACK') AS fallbacks,
ROUND(AVG(latency_ms)::numeric, 2) AS avg_latency_ms,
ROUND(PERCENTILE_CONT(0.95) WITHIN GROUP (ORDER BY latency_ms)::numeric, 2) AS p95_latency_ms,
SUM(cost_usd) AS total_cost_usd,
SUM(tokens_input) AS total_tokens_in,
SUM(tokens_output) AS total_tokens_out,
ROUND(AVG(confidence)::numeric, 3) AS avg_confidence
FROM task_ai_requests
WHERE timestamp_init > CURRENT_DATE - INTERVAL '30 days'
GROUP BY target_service, target_module
ORDER BY total_requests DESC;
-- Vista: Métricas por tier
CREATE OR REPLACE VIEW v_ai_metrics_by_tier AS
SELECT
tier_used,
provider_used,
COUNT(*) AS total_requests,
COUNT(*) FILTER (WHERE status = 'SUCCESS') AS successful,
ROUND(AVG(latency_ms)::numeric, 2) AS avg_latency_ms,
SUM(cost_usd) AS total_cost_usd
FROM task_ai_requests
WHERE timestamp_init > CURRENT_DATE - INTERVAL '30 days'
AND tier_used IS NOT NULL
GROUP BY tier_used, provider_used
ORDER BY total_requests DESC;
-- Vista: Costos diarios
CREATE OR REPLACE VIEW v_ai_daily_costs AS
SELECT
DATE(timestamp_init) AS fecha,
target_service,
COUNT(*) AS requests,
SUM(cost_usd) AS cost_usd,
SUM(tokens_input) AS tokens_in,
SUM(tokens_output) AS tokens_out
FROM task_ai_requests
WHERE timestamp_init > CURRENT_DATE - INTERVAL '30 days'
GROUP BY DATE(timestamp_init), target_service
ORDER BY fecha DESC, cost_usd DESC;
-- Vista: Errores recientes
CREATE OR REPLACE VIEW v_ai_recent_errors AS
SELECT
id,
trace_id,
target_service,
target_module,
status,
error_code,
error_message,
provider_used,
tier_used,
timestamp_init
FROM task_ai_requests
WHERE status IN ('ERROR', 'TIMEOUT')
AND timestamp_init > CURRENT_DATE - INTERVAL '7 days'
ORDER BY timestamp_init DESC
LIMIT 100;
-- ============================================
-- FUNCIÓN: Registrar request de S-CONTRACT
-- ============================================
CREATE OR REPLACE FUNCTION log_ai_request(
p_trace_id VARCHAR(64),
p_service ai_service,
p_module VARCHAR(50),
p_context_id UUID DEFAULT NULL,
p_task_id UUID DEFAULT NULL,
p_work_log_id UUID DEFAULT NULL
)
RETURNS UUID AS $$
DECLARE
new_id UUID;
ctx_snapshot JSONB;
BEGIN
-- Obtener snapshot del contexto si existe
IF p_context_id IS NOT NULL THEN
ctx_snapshot := build_ai_context(p_context_id);
END IF;
INSERT INTO task_ai_requests (
trace_id,
target_service,
target_module,
context_id,
context_snapshot,
task_id,
work_log_id,
status,
timestamp_init
) VALUES (
p_trace_id,
p_service,
p_module,
p_context_id,
ctx_snapshot,
p_task_id,
p_work_log_id,
'pending',
CURRENT_TIMESTAMP
)
RETURNING id INTO new_id;
RETURN new_id;
END;
$$ LANGUAGE plpgsql;
-- ============================================
-- FUNCIÓN: Actualizar request completada
-- ============================================
CREATE OR REPLACE FUNCTION complete_ai_request(
p_request_id UUID,
p_status VARCHAR(20),
p_tier_used provider_tier,
p_provider VARCHAR(50),
p_latency_ms INTEGER,
p_tokens_in INTEGER DEFAULT NULL,
p_tokens_out INTEGER DEFAULT NULL,
p_cost_usd DECIMAL(10,6) DEFAULT NULL,
p_confidence DECIMAL(4,3) DEFAULT NULL,
p_error_code VARCHAR(50) DEFAULT NULL,
p_error_message TEXT DEFAULT NULL
)
RETURNS VOID AS $$
BEGIN
UPDATE task_ai_requests
SET
status = p_status,
tier_used = p_tier_used,
provider_used = p_provider,
latency_ms = p_latency_ms,
tokens_input = p_tokens_in,
tokens_output = p_tokens_out,
cost_usd = p_cost_usd,
confidence = p_confidence,
error_code = p_error_code,
error_message = p_error_message,
timestamp_end = CURRENT_TIMESTAMP
WHERE id = p_request_id;
END;
$$ LANGUAGE plpgsql;

View File

@@ -0,0 +1,50 @@
-- Inicialización de la base de datos para CLARA
-- Servicio inmutable de log de entrada
-- Tabla principal: clara_log
CREATE TABLE IF NOT EXISTS clara_log (
id BIGSERIAL PRIMARY KEY,
h_instancia VARCHAR(64) NOT NULL,
h_entrada VARCHAR(64) NOT NULL,
contenedor JSONB NOT NULL,
r2_paths JSONB,
created_at TIMESTAMP DEFAULT NOW()
);
-- Índices para búsqueda eficiente
CREATE INDEX IF NOT EXISTS idx_clara_instancia ON clara_log(h_instancia);
CREATE INDEX IF NOT EXISTS idx_clara_entrada ON clara_log(h_entrada);
CREATE INDEX IF NOT EXISTS idx_clara_created ON clara_log(created_at DESC);
-- Índice para buscar por estado del contenedor
CREATE INDEX IF NOT EXISTS idx_clara_estado ON clara_log((contenedor->'estado'->>'actual'));
-- Índice para buscar por timestamp de captura
CREATE INDEX IF NOT EXISTS idx_clara_timestamp ON clara_log((contenedor->'origen'->>'timestamp_captura'));
-- Índice compuesto para búsquedas frecuentes
CREATE INDEX IF NOT EXISTS idx_clara_inst_entrada ON clara_log(h_instancia, h_entrada);
-- Vista para consultas comunes
CREATE OR REPLACE VIEW clara_summary AS
SELECT
id,
h_instancia,
h_entrada,
contenedor->>'id' as contenedor_id,
contenedor->'origen'->>'timestamp_captura' as timestamp_captura,
contenedor->'archivo'->>'tipo' as tipo_archivo,
contenedor->'archivo'->>'categoria' as categoria,
contenedor->'estado'->>'actual' as estado_actual,
jsonb_array_length(COALESCE(contenedor->'tags', '[]'::jsonb)) as num_tags,
created_at
FROM clara_log
ORDER BY id DESC;
-- Comentarios para documentación
COMMENT ON TABLE clara_log IS 'Log inmutable de contenedores recibidos de PACKET';
COMMENT ON COLUMN clara_log.h_instancia IS 'Hash de identificación de la instancia DECK';
COMMENT ON COLUMN clara_log.h_entrada IS 'Hash del archivo (sha256)';
COMMENT ON COLUMN clara_log.contenedor IS 'Contenedor completo según esquema de contratos-comunes';
COMMENT ON COLUMN clara_log.r2_paths IS 'Rutas de los archivos en Cloudflare R2';
COMMENT ON COLUMN clara_log.created_at IS 'Timestamp de recepción (inmutable)';

View File

@@ -0,0 +1,123 @@
-- Los Libros Contables - FELDMAN v2.0
-- Tablas para milestones, bloques y validaciones
-- MILESTONES
CREATE TABLE IF NOT EXISTS milestones (
id BIGSERIAL PRIMARY KEY,
h_milestone VARCHAR(64) NOT NULL UNIQUE,
h_instancia VARCHAR(64) NOT NULL,
secuencia BIGINT NOT NULL,
hash_previo VARCHAR(64),
hash_contenido VARCHAR(64) NOT NULL,
alias VARCHAR(200) NOT NULL,
tipo_item VARCHAR(50) NOT NULL,
descripcion TEXT,
datos JSONB DEFAULT '{}',
etiqueta_principal VARCHAR(64),
proyecto_tag VARCHAR(64),
id_padre_milestone BIGINT REFERENCES milestones(id),
id_bloque_asociado BIGINT,
blockchain_pending BOOLEAN DEFAULT TRUE,
blockchain_tx_ref VARCHAR(128),
notario_batch_id VARCHAR(64),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
created_by VARCHAR(64),
CONSTRAINT milestone_secuencia_unica UNIQUE (h_instancia, secuencia)
);
-- BLOQUES
CREATE TABLE IF NOT EXISTS bloques (
id BIGSERIAL PRIMARY KEY,
h_bloque VARCHAR(64) NOT NULL UNIQUE,
h_instancia VARCHAR(64) NOT NULL,
secuencia BIGINT NOT NULL,
hash_previo VARCHAR(64),
hash_contenido VARCHAR(64) NOT NULL,
alias VARCHAR(200) NOT NULL,
tipo_accion VARCHAR(50) NOT NULL,
descripcion TEXT,
datos JSONB DEFAULT '{}',
evidencia_hash VARCHAR(64) NOT NULL,
evidencia_url VARCHAR(500) NOT NULL,
evidencia_tipo VARCHAR(50) NOT NULL,
etiqueta_principal VARCHAR(64),
proyecto_tag VARCHAR(64),
id_padre_bloque BIGINT REFERENCES bloques(id),
id_milestone_asociado BIGINT REFERENCES milestones(id),
blockchain_pending BOOLEAN DEFAULT TRUE,
blockchain_tx_ref VARCHAR(128),
notario_batch_id VARCHAR(64),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
created_by VARCHAR(64),
CONSTRAINT bloque_secuencia_unica UNIQUE (h_instancia, secuencia)
);
-- COLA DE VALIDACION
CREATE TABLE IF NOT EXISTS feldman_cola (
id BIGSERIAL PRIMARY KEY,
h_entrada VARCHAR(64) NOT NULL UNIQUE,
h_instancia VARCHAR(64) NOT NULL,
origen VARCHAR(50) NOT NULL,
h_origen VARCHAR(64),
tipo_destino VARCHAR(20) NOT NULL,
datos JSONB NOT NULL,
estado VARCHAR(20) DEFAULT 'pendiente',
error_mensaje TEXT,
intentos INT DEFAULT 0,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
processed_at TIMESTAMP
);
-- VALIDACIONES
CREATE TABLE IF NOT EXISTS feldman_validaciones (
id BIGSERIAL PRIMARY KEY,
h_entrada VARCHAR(64) NOT NULL,
validacion_ok BOOLEAN NOT NULL,
reglas_aplicadas JSONB NOT NULL,
tipo_registro VARCHAR(20),
h_registro VARCHAR(64),
validated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- INDICES
CREATE INDEX IF NOT EXISTS idx_milestones_pending ON milestones(blockchain_pending) WHERE blockchain_pending = TRUE;
CREATE INDEX IF NOT EXISTS idx_bloques_pending ON bloques(blockchain_pending) WHERE blockchain_pending = TRUE;
CREATE INDEX IF NOT EXISTS idx_milestones_proyecto ON milestones(proyecto_tag);
CREATE INDEX IF NOT EXISTS idx_bloques_proyecto ON bloques(proyecto_tag);
CREATE INDEX IF NOT EXISTS idx_feldman_estado ON feldman_cola(estado);
CREATE INDEX IF NOT EXISTS idx_feldman_instancia ON feldman_cola(h_instancia);
-- FUNCIONES
CREATE OR REPLACE FUNCTION get_ultimo_hash_milestone(p_h_instancia VARCHAR)
RETURNS VARCHAR AS $$
DECLARE v_hash VARCHAR;
BEGIN
SELECT hash_contenido INTO v_hash FROM milestones
WHERE h_instancia = p_h_instancia ORDER BY secuencia DESC LIMIT 1;
RETURN COALESCE(v_hash, 'GENESIS');
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION get_ultimo_hash_bloque(p_h_instancia VARCHAR)
RETURNS VARCHAR AS $$
DECLARE v_hash VARCHAR;
BEGIN
SELECT hash_contenido INTO v_hash FROM bloques
WHERE h_instancia = p_h_instancia ORDER BY secuencia DESC LIMIT 1;
RETURN COALESCE(v_hash, 'GENESIS');
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION get_siguiente_secuencia_milestone(p_h_instancia VARCHAR)
RETURNS BIGINT AS $$
BEGIN
RETURN (SELECT COALESCE(MAX(secuencia), 0) + 1 FROM milestones WHERE h_instancia = p_h_instancia);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION get_siguiente_secuencia_bloque(p_h_instancia VARCHAR)
RETURNS BIGINT AS $$
BEGIN
RETURN (SELECT COALESCE(MAX(secuencia), 0) + 1 FROM bloques WHERE h_instancia = p_h_instancia);
END;
$$ LANGUAGE plpgsql;

View File

@@ -0,0 +1,36 @@
-- ALFRED - Flujos Predefinidos
-- Deploy en DECK PostgreSQL
-- Flujos predefinidos
CREATE TABLE IF NOT EXISTS flujos_predefinidos (
id VARCHAR(64) PRIMARY KEY,
h_instancia VARCHAR(64) NOT NULL,
nombre VARCHAR(100) NOT NULL,
descripcion TEXT,
pasos JSONB NOT NULL,
campos_fijos JSONB DEFAULT '{}',
campos_variables JSONB DEFAULT '[]',
activo BOOLEAN DEFAULT true,
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW()
);
-- Ejecuciones de flujos
CREATE TABLE IF NOT EXISTS flujo_ejecuciones (
id BIGSERIAL PRIMARY KEY,
h_flujo VARCHAR(64) REFERENCES flujos_predefinidos(id),
h_instancia VARCHAR(64) NOT NULL,
h_ejecucion VARCHAR(64) NOT NULL UNIQUE,
datos JSONB NOT NULL,
estado VARCHAR(20) DEFAULT 'ok',
destino VARCHAR(20) DEFAULT 'feldman',
notas TEXT,
created_at TIMESTAMP DEFAULT NOW()
);
-- Indices
CREATE INDEX IF NOT EXISTS idx_flujos_h_instancia ON flujos_predefinidos(h_instancia);
CREATE INDEX IF NOT EXISTS idx_flujos_activo ON flujos_predefinidos(activo);
CREATE INDEX IF NOT EXISTS idx_ejecuciones_h_flujo ON flujo_ejecuciones(h_flujo);
CREATE INDEX IF NOT EXISTS idx_ejecuciones_estado ON flujo_ejecuciones(estado);
CREATE INDEX IF NOT EXISTS idx_ejecuciones_created ON flujo_ejecuciones(created_at DESC);

View File

@@ -0,0 +1,82 @@
# Schemas SQL
**Versión:** 1.0
**Estado:** Implementado
---
## Archivos
| Archivo | Descripción | Tablas |
|---------|-------------|--------|
| 00_types.sql | Tipos y enums | task_status, task_priority, file_direction, ai_service, hst_grupo, deployment_mode |
| 01_hst_tags.sql | Tags semánticos | hst_tags, hst_biblioteca |
| 02_task_manager.sql | Gestión de tareas | tasks, task_dependencies, task_comments |
| 03_work_log.sql | Log de trabajo | work_log, work_log_files |
| 04_ai_context.sql | Contexto IA | ai_context_blocks, ai_context_datasets |
| 05_ai_requests.sql | Peticiones IA | ai_requests, ai_responses |
| 06_clara.sql | Clara (secretaría) | clara_log, clara_summary (vista) |
| 07_feldman.sql | Feldman (contable) | milestones, bloques, feldman_cola, feldman_validaciones |
| 08_alfred.sql | Alfred (producción) | flujos_predefinidos, flujo_ejecuciones |
---
## Orden de Aplicación
```bash
# Aplicar en este orden
psql -U tzzr -d tzzr -f 00_types.sql
psql -U tzzr -d tzzr -f 01_hst_tags.sql
psql -U tzzr -d tzzr -f 02_task_manager.sql
psql -U tzzr -d tzzr -f 03_work_log.sql
psql -U tzzr -d tzzr -f 04_ai_context.sql
psql -U tzzr -d tzzr -f 05_ai_requests.sql
psql -U tzzr -d tzzr -f 06_clara.sql
psql -U tzzr -d tzzr -f 07_feldman.sql
psql -U tzzr -d tzzr -f 08_alfred.sql
```
---
## Tipos Enumerados (00_types.sql)
```sql
-- Estados de tarea
CREATE TYPE task_status AS ENUM (
'draft', 'pending', 'in_progress',
'blocked', 'review', 'completed', 'cancelled'
);
-- Prioridad de tarea
CREATE TYPE task_priority AS ENUM (
'critical', 'high', 'medium', 'low', 'someday'
);
-- Dirección de archivo
CREATE TYPE file_direction AS ENUM (
'inbound', 'outbound', 'internal', 'reference'
);
-- Servicios IA
CREATE TYPE ai_service AS ENUM (
'grace', 'penny', 'factory'
);
-- Grupos HST
CREATE TYPE hst_grupo AS ENUM (
'hst', 'emp', 'hsu', 'pjt'
);
-- Modo despliegue
CREATE TYPE deployment_mode AS ENUM (
'EXTERNAL', 'SELF_HOSTED', 'SEMI'
);
```
---
## Notas
- Todos los schemas usan `DO $$ BEGIN ... EXCEPTION ... END $$` para ser idempotentes
- Función `update_updated_at_column()` actualiza `updated_at` automáticamente
- Los SQL están en `/schemas/` junto a este README