DELIMITER $$ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`worker_getHierarchy`( vUserFk INT ) BEGIN /** * Retorna una tabla temporal con los trabajadores que tiene * el usuario por debajo en la jerarquía de la empresa. * * @param vUserFk Id de usuario. * @return tmp.workerHierarchyList */ CREATE OR REPLACE TEMPORARY TABLE tmp.workerHierarchyList (PRIMARY KEY (workerFk)) ENGINE = MEMORY WITH RECURSIVE workerHierarchy AS ( SELECT id workerFk, bossFk, 0 `depth`, CAST(id AS CHAR(255)) `path` FROM vn.worker WHERE id = vUserFk UNION ALL SELECT w.id, w.bossFk, wh.`depth` + 1, CONCAT(wh.`path`, ',', w.id) FROM vn.worker w JOIN workerHierarchy wh ON w.bossFk = wh.workerFk WHERE NOT FIND_IN_SET(w.id, wh.`path`) ) SELECT * FROM workerHierarchy ORDER BY depth, workerFk; END$$ DELIMITER ;