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