-- Migración: Subpreguntas anidadas hasta 5 niveles -- Fecha: 2025-11-25 -- Descripción: Agrega soporte y validación para subpreguntas anidadas hasta 5 niveles de profundidad -- Agregar columna para tracking de nivel (opcional pero útil) ALTER TABLE questions ADD COLUMN IF NOT EXISTS depth_level INTEGER DEFAULT 0; -- Comentarios COMMENT ON COLUMN questions.parent_question_id IS 'ID de la pregunta padre. NULL = pregunta principal. Soporta anidamiento hasta 5 niveles.'; COMMENT ON COLUMN questions.depth_level IS 'Nivel de profundidad: 0=principal, 1-5=subpreguntas anidadas'; -- Función para calcular profundidad de una pregunta CREATE OR REPLACE FUNCTION calculate_question_depth(question_id INTEGER) RETURNS INTEGER AS $$ DECLARE current_parent_id INTEGER; depth INTEGER := 0; max_iterations INTEGER := 10; -- Protección contra loops infinitos BEGIN -- Obtener el parent_id de la pregunta SELECT parent_question_id INTO current_parent_id FROM questions WHERE id = question_id; -- Si no tiene padre, es nivel 0 IF current_parent_id IS NULL THEN RETURN 0; END IF; -- Subir por la jerarquía contando niveles WHILE current_parent_id IS NOT NULL AND depth < max_iterations LOOP depth := depth + 1; SELECT parent_question_id INTO current_parent_id FROM questions WHERE id = current_parent_id; END LOOP; RETURN depth; END; $$ LANGUAGE plpgsql; -- Función trigger para validar profundidad máxima CREATE OR REPLACE FUNCTION validate_question_depth() RETURNS TRIGGER AS $$ DECLARE calculated_depth INTEGER; parent_depth INTEGER; BEGIN -- Si no tiene padre, es nivel 0 IF NEW.parent_question_id IS NULL THEN NEW.depth_level := 0; RETURN NEW; END IF; -- Validar que el padre existe y no es la misma pregunta IF NEW.parent_question_id = NEW.id THEN RAISE EXCEPTION 'Una pregunta no puede ser su propio padre'; END IF; -- Calcular profundidad del padre SELECT depth_level INTO parent_depth FROM questions WHERE id = NEW.parent_question_id; IF parent_depth IS NULL THEN -- Si el padre no tiene depth_level, calcularlo parent_depth := calculate_question_depth(NEW.parent_question_id); END IF; -- La nueva pregunta es un nivel más profundo que su padre calculated_depth := parent_depth + 1; -- Validar que no excede 5 niveles IF calculated_depth > 5 THEN RAISE EXCEPTION 'No se permiten subpreguntas con profundidad mayor a 5. Esta pregunta tendría profundidad %, máximo permitido: 5', calculated_depth; END IF; -- Asignar el nivel calculado NEW.depth_level := calculated_depth; RETURN NEW; END; $$ LANGUAGE plpgsql; -- Crear trigger para INSERT y UPDATE DROP TRIGGER IF EXISTS validate_depth_trigger ON questions; CREATE TRIGGER validate_depth_trigger BEFORE INSERT OR UPDATE OF parent_question_id ON questions FOR EACH ROW EXECUTE FUNCTION validate_question_depth(); -- Actualizar depth_level para preguntas existentes UPDATE questions SET depth_level = calculate_question_depth(id); -- Crear índice para mejorar queries de subpreguntas CREATE INDEX IF NOT EXISTS idx_questions_parent ON questions(parent_question_id) WHERE parent_question_id IS NOT NULL; CREATE INDEX IF NOT EXISTS idx_questions_depth ON questions(depth_level); -- Función helper para obtener árbol de subpreguntas CREATE OR REPLACE FUNCTION get_question_tree(root_question_id INTEGER) RETURNS TABLE ( id INTEGER, parent_question_id INTEGER, text TEXT, type VARCHAR(30), depth_level INTEGER, show_if_answer VARCHAR(50), path TEXT ) AS $$ BEGIN RETURN QUERY WITH RECURSIVE question_tree AS ( -- Pregunta raíz SELECT q.id, q.parent_question_id, q.text, q.type, q.depth_level, q.show_if_answer, q.id::TEXT as path FROM questions q WHERE q.id = root_question_id UNION ALL -- Subpreguntas recursivas SELECT q.id, q.parent_question_id, q.text, q.type, q.depth_level, q.show_if_answer, qt.path || ' > ' || q.id::TEXT FROM questions q INNER JOIN question_tree qt ON q.parent_question_id = qt.id WHERE q.depth_level <= 5 -- Límite de seguridad ) SELECT * FROM question_tree ORDER BY depth_level, id; END; $$ LANGUAGE plpgsql; -- Verificar estructura actual SELECT COUNT(*) as total_preguntas, COUNT(CASE WHEN parent_question_id IS NULL THEN 1 END) as principales, COUNT(CASE WHEN parent_question_id IS NOT NULL THEN 1 END) as subpreguntas, MAX(depth_level) as max_profundidad FROM questions; -- Ver distribución por profundidad SELECT depth_level, COUNT(*) as cantidad, CASE WHEN depth_level = 0 THEN 'Principales' WHEN depth_level = 1 THEN 'Nivel 1' WHEN depth_level = 2 THEN 'Nivel 2' WHEN depth_level = 3 THEN 'Nivel 3' WHEN depth_level = 4 THEN 'Nivel 4' WHEN depth_level = 5 THEN 'Nivel 5' END as descripcion FROM questions GROUP BY depth_level ORDER BY depth_level; SELECT '✓ Migración de subpreguntas anidadas completada' AS status;