fixed nodeAdd
gitea/salix/test This commit looks good
Details
gitea/salix/test This commit looks good
Details
This commit is contained in:
parent
b9b1c2b2c7
commit
59a958841e
|
@ -0,0 +1,74 @@
|
|||
USE `nst`;
|
||||
DROP procedure IF EXISTS `nodeAdd`;
|
||||
|
||||
DELIMITER $$
|
||||
USE `nst`$$
|
||||
CREATE DEFINER=`root`@`%` PROCEDURE `nodeAdd`(IN `vScheme` VARCHAR(45), IN `vTable` VARCHAR(45), IN `vParentFk` INT, IN `vChild` VARCHAR(100))
|
||||
BEGIN
|
||||
DECLARE vSql TEXT;
|
||||
DECLARE vTableClone VARCHAR(45);
|
||||
|
||||
SET vTableClone = CONCAT(vTable, 'Clone');
|
||||
|
||||
CALL util.exec(CONCAT('DROP TEMPORARY TABLE IF EXISTS tmp.', vTableClone));
|
||||
CALL util.exec(CONCAT(
|
||||
'CREATE TEMPORARY TABLE tmp.', vTableClone,
|
||||
' ENGINE = MEMORY',
|
||||
' SELECT * FROM ', vScheme, '.', vTable
|
||||
));
|
||||
|
||||
CALL util.exec(CONCAT(
|
||||
'SELECT COUNT(c.id) INTO @childs',
|
||||
' FROM ', vScheme, '.', vTable, ' p',
|
||||
' LEFT JOIN tmp.', vTableClone, ' c ON c.lft',
|
||||
' BETWEEN p.lft AND p.rgt AND c.id != ', vParentFk,
|
||||
' WHERE p.id = ', vParentFk
|
||||
));
|
||||
|
||||
IF @childs = 0 THEN
|
||||
CALL util.exec(CONCAT(
|
||||
'SELECT lft INTO @vLeft',
|
||||
' FROM ', vScheme, '.', vTable,
|
||||
' WHERE id = ', vParentFk
|
||||
));
|
||||
ELSE
|
||||
CALL util.exec(CONCAT(
|
||||
'SELECT c.rgt INTO @vLeft',
|
||||
' FROM ', vScheme, '.', vTable, ' p',
|
||||
' JOIN tmp.', vTableClone, ' c ON c.depth = p.depth + 1'
|
||||
' AND c.lft BETWEEN p.lft AND p.rgt',
|
||||
' WHERE p.id = ', vParentFk,
|
||||
' ORDER BY c.lft',
|
||||
' DESC LIMIT 1'
|
||||
));
|
||||
END IF;
|
||||
|
||||
CALL util.exec(CONCAT(
|
||||
'UPDATE ', vScheme, '.', vTable, ' SET rgt = rgt + 2',
|
||||
' WHERE rgt > @vLeft',
|
||||
' ORDER BY rgt DESC'
|
||||
));
|
||||
CALL util.exec(CONCAT(
|
||||
'UPDATE ', vScheme, '.', vTable, ' SET lft = lft + 2',
|
||||
' WHERE lft > @vLeft',
|
||||
' ORDER BY lft DESC'
|
||||
));
|
||||
|
||||
SET vChild = REPLACE(vChild, "'", "\\'");
|
||||
|
||||
CALL util.exec(CONCAT(
|
||||
'INSERT INTO ', vScheme, '.', vTable, ' (name, lft, rgt)',
|
||||
' VALUES ("', vChild, '", @vLeft + 1, @vLeft + 2)'
|
||||
));
|
||||
|
||||
-- CALL util.exec(CONCAT(
|
||||
-- 'SELECT id, name, lft, rgt, depth, sons',
|
||||
-- ' FROM ', vScheme, '.', vTable,
|
||||
-- ' WHERE id = LAST_INSERT_ID()'
|
||||
-- ));
|
||||
|
||||
CALL util.exec(CONCAT('DROP TEMPORARY TABLE tmp.', vTableClone));
|
||||
END$$
|
||||
|
||||
DELIMITER ;
|
||||
|
Loading…
Reference in New Issue