57 lines
1.3 KiB
SQL
57 lines
1.3 KiB
SQL
DROP procedure IF EXISTS `zoneNestProvince`;
|
|
|
|
DELIMITER $$
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zoneNestProvince`()
|
|
BEGIN
|
|
|
|
DECLARE vDone BOOL;
|
|
DECLARE vParent INT DEFAULT 1;
|
|
DECLARE vGeoFk INT;
|
|
DECLARE vChildFk INT;
|
|
DECLARE vChildName VARCHAR(100);
|
|
DECLARE provinceCur CURSOR FOR
|
|
SELECT c.geoFk, p.id, p.`name`
|
|
FROM province p
|
|
JOIN tmp.country tc ON tc.id = p.countryFk
|
|
JOIN vn.country c ON c.id = tc.id
|
|
ORDER BY c.geoFk, p.`name`;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
|
|
-- Remove existing provinces from zoneGeo
|
|
DELETE zg FROM vn.province p
|
|
JOIN tmp.country tc ON tc.id = p.countryFk
|
|
JOIN tmp.zoneGeo zg ON zg.id = p.geoFk;
|
|
|
|
-- Reset country geoFk
|
|
UPDATE vn.province p
|
|
JOIN tmp.country tc ON tc.id = p.countryFk
|
|
SET p.geoFk = NULL
|
|
WHERE p.geoFk IS NOT NULL;
|
|
|
|
-- > Province cursor start
|
|
OPEN provinceCur;
|
|
|
|
provinceLoop: LOOP
|
|
SET vDone = FALSE;
|
|
|
|
FETCH provinceCur INTO vParent, vChildFk, vChildName;
|
|
|
|
IF vDone THEN
|
|
LEAVE provinceLoop;
|
|
END IF;
|
|
|
|
CALL nst.nodeAdd('tmp', 'zoneGeo', vParent, vChildName);
|
|
END LOOP;
|
|
CLOSE provinceCur;
|
|
-- < Province cursor end
|
|
|
|
UPDATE province p
|
|
JOIN tmp.zoneGeo z ON z.name = p.name
|
|
SET p.geoFk = z.id
|
|
WHERE p.geoFk IS NULL;
|
|
END$$
|
|
|
|
DELIMITER ;
|
|
|