diff --git a/db/routines/vn/functions/client_getGeo.sql b/db/routines/vn/functions/client_getGeo.sql new file mode 100644 index 000000000..067eb84bc --- /dev/null +++ b/db/routines/vn/functions/client_getGeo.sql @@ -0,0 +1,25 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`vn`@`localhost` FUNCTION `vn`.`client_getGeo`(vSelf INT) + RETURNS int(11) + DETERMINISTIC +BEGIN +/** + * Returns the geo for the passed client. + * + * @param vSelf The address id + * @return The geo id + */ + DECLARE vGeoFk INT; + + SELECT p.geoFk INTO vGeoFk + FROM client c + JOIN town t ON t.provinceFk = c.provinceFk + JOIN postCode p ON p.townFk = t.id + AND p.`code` = c.postcode + WHERE c.id = vSelf + ORDER BY (c.city SOUNDS LIKE t.`name`) DESC + LIMIT 1; + + RETURN vGeoFk; +END$$ +DELIMITER ; diff --git a/db/routines/vn/functions/supplier_getGeo.sql b/db/routines/vn/functions/supplier_getGeo.sql new file mode 100644 index 000000000..93115d712 --- /dev/null +++ b/db/routines/vn/functions/supplier_getGeo.sql @@ -0,0 +1,25 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`vn`@`localhost` FUNCTION `vn`.`supplier_getGeo`(vSelf INT) + RETURNS int(11) + DETERMINISTIC +BEGIN +/** + * Returns the geo for the passed supplier. + * + * @param vSelf The address id + * @return The geo id + */ + DECLARE vGeoFk INT; + + SELECT p.geoFk INTO vGeoFk + FROM supplier s + JOIN town t ON t.provinceFk = s.provinceFk + JOIN postCode p ON p.townFk = t.id + AND p.`code` = s.postCode + WHERE s.id = vSelf + ORDER BY (s.city SOUNDS LIKE t.`name`) DESC + LIMIT 1; + + RETURN vGeoFk; +END$$ +DELIMITER ; diff --git a/db/routines/vn/triggers/address_beforeInsert.sql b/db/routines/vn/triggers/address_beforeInsert.sql index 56ef7aa51..a4f384f14 100644 --- a/db/routines/vn/triggers/address_beforeInsert.sql +++ b/db/routines/vn/triggers/address_beforeInsert.sql @@ -6,6 +6,7 @@ BEGIN DECLARE vIsEqualizated BOOL; SET NEW.editorFk = account.myUser_getId(); + SET NEW.geoFk = address_getGeo(NEW.id); IF (NEW.phone <> '') THEN CALL pbx.phone_isValid(NEW.phone); diff --git a/db/routines/vn/triggers/address_beforeUpdate.sql b/db/routines/vn/triggers/address_beforeUpdate.sql index 35887912c..0b19a6266 100644 --- a/db/routines/vn/triggers/address_beforeUpdate.sql +++ b/db/routines/vn/triggers/address_beforeUpdate.sql @@ -3,7 +3,6 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` TRIGGER `vn`.`address_beforeUpdate` BEFORE UPDATE ON `address` FOR EACH ROW BEGIN - SET NEW.editorFk = account.myUser_getId(); IF !(NEW.phone <=> OLD.phone) AND (NEW.phone <> '') THEN @@ -14,5 +13,10 @@ BEGIN CALL pbx.phone_isValid(NEW.mobile); END IF; + IF NOT (NEW.provinceFk <=> OLD.provinceFk) + OR (NEW.postalCode <=> OLD.postalCode) THEN + + SET NEW.geoFk = address_getGeo(NEW.id); + END IF; END$$ DELIMITER ; diff --git a/db/routines/vn/triggers/client_beforeInsert.sql b/db/routines/vn/triggers/client_beforeInsert.sql index 45de107f1..b4038a2ba 100644 --- a/db/routines/vn/triggers/client_beforeInsert.sql +++ b/db/routines/vn/triggers/client_beforeInsert.sql @@ -3,8 +3,10 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` TRIGGER `vn`.`client_beforeInsert` BEFORE INSERT ON `client` FOR EACH ROW BEGIN - SET NEW.editorFk = account.myUser_getId(); + SET NEW.accountingAccount = 4300000000 + NEW.id; + SET NEW.lastSalesPersonFk = NEW.salesPersonFk; + SET NEW.geoFk = client_getGeo(NEW.id); IF (NEW.phone <> '') THEN CALL pbx.phone_isValid(NEW.phone); @@ -13,9 +15,5 @@ BEGIN IF (NEW.mobile <> '') THEN CALL pbx.phone_isValid(NEW.mobile); END IF; - - SET NEW.accountingAccount = 4300000000 + NEW.id; - - SET NEW.lastSalesPersonFk = NEW.salesPersonFk; END$$ DELIMITER ; diff --git a/db/routines/vn/triggers/client_beforeUpdate.sql b/db/routines/vn/triggers/client_beforeUpdate.sql index 7142d6604..00418a9e7 100644 --- a/db/routines/vn/triggers/client_beforeUpdate.sql +++ b/db/routines/vn/triggers/client_beforeUpdate.sql @@ -72,5 +72,11 @@ BEGIN IF NOT (NEW.businessTypeFk <=> OLD.businessTypeFk) AND (NEW.businessTypeFk = 'individual' OR OLD.businessTypeFk = 'individual') THEN SET NEW.isTaxDataChecked = 0; END IF; + + IF NOT (NEW.provinceFk <=> OLD.provinceFk) + OR (NEW.postcode <=> OLD.postcode) THEN + + SET NEW.geoFk = client_getGeo(NEW.id); + END IF; END$$ DELIMITER ; diff --git a/db/routines/vn/triggers/supplier_beforeInsert.sql b/db/routines/vn/triggers/supplier_beforeInsert.sql index b141ec8fb..5bbfc79a1 100644 --- a/db/routines/vn/triggers/supplier_beforeInsert.sql +++ b/db/routines/vn/triggers/supplier_beforeInsert.sql @@ -4,5 +4,6 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` TRIGGER `vn`.`supplier_beforeInsert` FOR EACH ROW BEGIN SET NEW.editorFk = account.myUser_getId(); + SET NEW.geoFk = supplier_getGeo(NEW.id); END$$ DELIMITER ; diff --git a/db/routines/vn/triggers/supplier_beforeUpdate.sql b/db/routines/vn/triggers/supplier_beforeUpdate.sql index af730b49d..10b63ee72 100644 --- a/db/routines/vn/triggers/supplier_beforeUpdate.sql +++ b/db/routines/vn/triggers/supplier_beforeUpdate.sql @@ -40,5 +40,10 @@ BEGIN SET NEW.isPayMethodChecked = FALSE; END IF; + IF NOT (NEW.provinceFk <=> OLD.provinceFk) + OR (NEW.postcode <=> OLD.postcode) THEN + + SET NEW.geoFk = client_getGeo(NEW.id); + END IF; END$$ DELIMITER ; diff --git a/db/versions/11346-yellowPhormium/02-supplier.sql b/db/versions/11346-yellowPhormium/02-supplier.sql index ef5e04a43..b3e25bd7e 100644 --- a/db/versions/11346-yellowPhormium/02-supplier.sql +++ b/db/versions/11346-yellowPhormium/02-supplier.sql @@ -8,13 +8,13 @@ ALTER TABLE vn.supplier CREATE OR REPLACE TEMPORARY TABLE tSupplierGeo (PRIMARY KEY (id)) ENGINE = MEMORY - SELECT sa.supplierFk id, p.geoFk - FROM supplierAddress sa - JOIN town t ON t.provinceFk = sa.provinceFk + SELECT s.id, p.geoFk + FROM supplier s + JOIN town t ON t.provinceFk = s.provinceFk JOIN postCode p ON p.townFk = t.id - AND p.`code` = sa.postalCode - GROUP BY sa.supplierFk - ORDER BY (sa.city SOUNDS LIKE t.`name`) DESC; + AND p.`code` = s.postCode + GROUP BY s.id + ORDER BY (s.city SOUNDS LIKE t.`name`) DESC; UPDATE supplier s JOIN tSupplierGeo tsg ON tsg.id = s.id