79 lines
1.6 KiB
SQL
79 lines
1.6 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`department_getLeaves`(
|
|
vParentFk INT,
|
|
vSearch VARCHAR(255)
|
|
)
|
|
BEGIN
|
|
DECLARE vIsNumber BOOL;
|
|
DECLARE vIsSearch BOOL DEFAULT vSearch IS NOT NULL AND vSearch != '';
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tNodes;
|
|
CREATE TEMPORARY TABLE tNodes
|
|
(UNIQUE (id))
|
|
ENGINE = MEMORY
|
|
SELECT id FROM department LIMIT 0;
|
|
|
|
IF vIsSearch THEN
|
|
SET vIsNumber = vSearch REGEXP '^[0-9]+$';
|
|
|
|
INSERT INTO tNodes
|
|
SELECT id FROM department
|
|
WHERE (vIsNumber AND `name` = vSearch)
|
|
OR (!vIsNumber AND `name` LIKE CONCAT('%', vSearch, '%'))
|
|
LIMIT 1000;
|
|
END IF;
|
|
|
|
IF vParentFk IS NULL THEN
|
|
DROP TEMPORARY TABLE IF EXISTS tChilds;
|
|
CREATE TEMPORARY TABLE tChilds
|
|
ENGINE = MEMORY
|
|
SELECT id FROM tNodes;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tParents;
|
|
CREATE TEMPORARY TABLE tParents
|
|
ENGINE = MEMORY
|
|
SELECT id FROM department LIMIT 0;
|
|
|
|
myLoop: LOOP
|
|
DELETE FROM tParents;
|
|
INSERT INTO tParents
|
|
SELECT parentFk id
|
|
FROM department g
|
|
JOIN tChilds c ON c.id = g.id
|
|
WHERE g.parentFk IS NOT NULL;
|
|
|
|
INSERT IGNORE INTO tNodes
|
|
SELECT id FROM tParents;
|
|
|
|
IF ROW_COUNT() = 0 THEN
|
|
LEAVE myLoop;
|
|
END IF;
|
|
|
|
DELETE FROM tChilds;
|
|
INSERT INTO tChilds
|
|
SELECT id FROM tParents;
|
|
END LOOP;
|
|
|
|
DROP TEMPORARY TABLE
|
|
tChilds,
|
|
tParents;
|
|
END IF;
|
|
|
|
IF !vIsSearch THEN
|
|
INSERT IGNORE INTO tNodes
|
|
SELECT id FROM department
|
|
WHERE parentFk <=> vParentFk;
|
|
END IF;
|
|
|
|
SELECT d.id,
|
|
d.`name`,
|
|
d.parentFk,
|
|
d.sons
|
|
FROM department d
|
|
JOIN tNodes n ON n.id = d.id
|
|
ORDER BY depth, `name`;
|
|
|
|
DROP TEMPORARY TABLE tNodes;
|
|
END$$
|
|
DELIMITER ;
|