From 16d91d09997d5b49417afb6fea78c7127a6243fe Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Joan=20S=C3=A1nchez?= Date: Tue, 4 Jun 2019 21:05:43 +0200 Subject: [PATCH] fixed zoneNest add new country --- db/changes/10031-zone/00-zoneNest.sql | 28 +++++++++ db/changes/10031-zone/00-zoneNestCountry.sql | 55 +++++++++++++++++ db/changes/10031-zone/00-zoneNestPostcode.sql | 61 +++++++++++++++++++ db/changes/10031-zone/00-zoneNestProvince.sql | 56 +++++++++++++++++ db/changes/10031-zone/00-zoneNestTown.sql | 59 ++++++++++++++++++ 5 files changed, 259 insertions(+) create mode 100644 db/changes/10031-zone/00-zoneNest.sql create mode 100644 db/changes/10031-zone/00-zoneNestCountry.sql create mode 100644 db/changes/10031-zone/00-zoneNestPostcode.sql create mode 100644 db/changes/10031-zone/00-zoneNestProvince.sql create mode 100644 db/changes/10031-zone/00-zoneNestTown.sql diff --git a/db/changes/10031-zone/00-zoneNest.sql b/db/changes/10031-zone/00-zoneNest.sql new file mode 100644 index 000000000..1452dd1fe --- /dev/null +++ b/db/changes/10031-zone/00-zoneNest.sql @@ -0,0 +1,28 @@ +DROP procedure IF EXISTS `zoneNest`; + +DELIMITER $$ +CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zoneNest`() +BEGIN + DROP TEMPORARY TABLE IF EXISTS tmp.zoneGeo; + CREATE TEMPORARY TABLE tmp.zoneGeo + (id INT AUTO_INCREMENT PRIMARY KEY) + ENGINE = MEMORY + SELECT * FROM vn.zoneGeo; + + DROP TEMPORARY TABLE IF EXISTS tmp.country; + CREATE TEMPORARY TABLE tmp.country + SELECT id FROM country + WHERE country IN('EspaƱa exento'); + + CALL vn.zoneNestCountry(); + CALL vn.zoneNestProvince(); + CALL vn.zoneNestTown(); + CALL vn.zoneNestPostcode(); + CALL vn.nestTree('tmp', 'zoneGeo', 'vn', 'zoneGeo'); + + DROP TEMPORARY TABLE + tmp.zoneGeo, + tmp.country; +END$$ + +DELIMITER ; diff --git a/db/changes/10031-zone/00-zoneNestCountry.sql b/db/changes/10031-zone/00-zoneNestCountry.sql new file mode 100644 index 000000000..b0f3b6958 --- /dev/null +++ b/db/changes/10031-zone/00-zoneNestCountry.sql @@ -0,0 +1,55 @@ +DROP procedure IF EXISTS `zoneNestCountry`; + +DELIMITER $$ +CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zoneNestCountry`() +BEGIN + + DECLARE vDone BOOL; + DECLARE vParent INT DEFAULT 1; + DECLARE vGeoFk INT; + DECLARE vChildFk INT; + DECLARE vChildName VARCHAR(100); + DECLARE countryCur CURSOR FOR + SELECT 1, c.id, c.`country` + FROM vn.country c + JOIN tmp.country tc ON tc.id = c.id + ORDER BY c.`country`; + + DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; + + -- Remove existing countries + DELETE zg FROM vn.country c + JOIN tmp.country tc ON tc.id = c.id + JOIN tmp.zoneGeo zg ON zg.id = c.geoFk; + + -- Reset country geoFk + UPDATE vn.country c + JOIN tmp.country tc ON tc.id = c.id + SET c.geoFk = NULL + WHERE c.geoFk IS NOT NULL; + + -- > Country cursor start + OPEN countryCur; + + countryLoop: LOOP + SET vDone = FALSE; + + FETCH countryCur INTO vParent, vChildFk, vChildName; + + IF vDone THEN + LEAVE countryLoop; + END IF; + + CALL nst.nodeAdd('tmp', 'zoneGeo', vParent, vChildName); + END LOOP; + CLOSE countryCur; + -- < Country cursor end + + UPDATE country c + JOIN tmp.zoneGeo z ON z.name = c.country + SET c.geoFk = z.id + WHERE c.geoFk IS NULL; +END$$ + +DELIMITER ; + diff --git a/db/changes/10031-zone/00-zoneNestPostcode.sql b/db/changes/10031-zone/00-zoneNestPostcode.sql new file mode 100644 index 000000000..92a5490c7 --- /dev/null +++ b/db/changes/10031-zone/00-zoneNestPostcode.sql @@ -0,0 +1,61 @@ +DROP procedure IF EXISTS `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 ; + diff --git a/db/changes/10031-zone/00-zoneNestProvince.sql b/db/changes/10031-zone/00-zoneNestProvince.sql new file mode 100644 index 000000000..e7b316ca1 --- /dev/null +++ b/db/changes/10031-zone/00-zoneNestProvince.sql @@ -0,0 +1,56 @@ +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 ; + diff --git a/db/changes/10031-zone/00-zoneNestTown.sql b/db/changes/10031-zone/00-zoneNestTown.sql new file mode 100644 index 000000000..80c10d7a0 --- /dev/null +++ b/db/changes/10031-zone/00-zoneNestTown.sql @@ -0,0 +1,59 @@ +DROP procedure IF EXISTS `zoneNestTown`; + +DELIMITER $$ +CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zoneNestTown`() +BEGIN + + DECLARE vDone BOOL; + DECLARE vParent INT DEFAULT 1; + DECLARE vGeoFk INT; + DECLARE vChildFk INT; + DECLARE vChildName VARCHAR(100); + DECLARE townCur CURSOR FOR + SELECT p.geoFk, t.id, t.`name` + FROM vn.town t + JOIN vn.province p ON p.id = t.provinceFk + JOIN tmp.country tc ON tc.id = p.countryFk + ORDER BY p.geoFk, t.`name`; + + DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; + + -- Remove existing towns from zoneGeo + DELETE zg FROM vn.town t + 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 = t.geoFk; + + -- Reset town geoFk + UPDATE vn.town t + JOIN vn.province p ON p.id = t.provinceFk + JOIN tmp.country tc ON tc.id = p.countryFk + SET t.geoFk = NULL + WHERE t.geoFk IS NOT NULL; + + -- > Town cursor start + OPEN townCur; + + townLoop: LOOP + SET vDone = FALSE; + + FETCH townCur INTO vParent, vChildFk, vChildName; + + IF vDone THEN + LEAVE townLoop; + END IF; + + CALL nst.nodeAdd('tmp', 'zoneGeo', vParent, vChildName); + END LOOP; + CLOSE townCur; + -- < Town cursor end + + UPDATE town t + JOIN tmp.zoneGeo z ON z.name = t.name + LEFT JOIN province p ON p.geoFk = z.id + SET t.geoFk = z.id + WHERE p.geoFk IS NULL; +END$$ + +DELIMITER ; +