Files
system-docs/03_MODELO_DATOS/schemas/02_task_manager.sql
ARCHITECT 6ea70bd34f 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
2025-12-29 18:23:41 +00:00

291 lines
10 KiB
PL/PgSQL

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