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