salix/db/install/changes/13-nodeAdd.sql

84 lines
2.4 KiB
MySQL
Raw Normal View History

2019-03-12 14:04:09 +00:00
DROP PROCEDURE IF EXISTS nst.NodeAdd;
DELIMITER $$
$$
CREATE DEFINER=`root`@`%` PROCEDURE `nst`.`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
));
-- Check parent childs
SET vSql = sql_printf('
SELECT COUNT(c.id) INTO @childs
FROM %t.%t p
LEFT JOIN %t.%t c ON c.lft BETWEEN p.lft AND p.rgt AND c.id != %v
WHERE p.id = %v',
vScheme, vTable, 'tmp', vTableClone, vParentFk, vParentFk);
SET @qrySql := vSql;
PREPARE stmt FROM @qrySql;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;
-- Select left from last child
IF @childs = 0 THEN
SET vSql = sql_printf('SELECT lft INTO @vLeft FROM %t.%t WHERE id = %v', vScheme, vTable, vParentFk);
SET @qrySql := vSql;
ELSE
SET vSql = sql_printf('
SELECT c.rgt INTO @vLeft
FROM %t.%t p
JOIN %t.%t c ON c.lft BETWEEN p.lft AND p.rgt
WHERE p.id = %v
ORDER BY c.lft
DESC LIMIT 1',
vScheme, vTable, 'tmp', vTableClone, vParentFk);
SET @qrySql := vSql;
END IF;
PREPARE stmt FROM @qrySql;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;
-- Update right
SET vSql = sql_printf('UPDATE %t.%t SET rgt = rgt + 2 WHERE rgt > %v ORDER BY rgt DESC', vScheme, vTable, @vLeft);
SET @qrySql := vSql;
PREPARE stmt FROM @qrySql;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;
SET vSql = sql_printf('UPDATE %t.%t SET lft = lft + 2 WHERE lft > %v ORDER BY lft DESC', vScheme, vTable, @vLeft);
SET @qrySql := vSql;
PREPARE stmt FROM @qrySql;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;
-- Escape character
SET vChild = REPLACE(vChild, "'", "\\'");
-- Add child
SET vSql = sql_printf('INSERT INTO %t.%t (name, lft, rgt) VALUES (%v, %v, %v)', vScheme, vTable, vChild, @vLeft + 1, @vLeft + 2);
SET @qrySql := vSql;
PREPARE stmt FROM @qrySql;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;
SELECT id, name, lft, rgt, depth, sons FROM vn.department
WHERE id = LAST_INSERT_ID();
CALL util.exec(CONCAT('DROP TEMPORARY TABLE tmp.', vTableClone));
END$$
DELIMITER ;