From 8f54a7f12dc2acba9310f2bc67ccd6fe41777923 Mon Sep 17 00:00:00 2001 From: Pako Date: Mon, 18 Mar 2024 14:03:16 +0100 Subject: [PATCH] deliveryDate --- db/dump/fixtures.local.sql | 9 +++++ .../floranet/procedures/deliveryDate_get.sql | 38 ++++++++----------- .../10956-brownBirch/00-firstScript.sql | 12 ++++++ 3 files changed, 37 insertions(+), 22 deletions(-) create mode 100644 db/versions/10956-brownBirch/00-firstScript.sql diff --git a/db/dump/fixtures.local.sql b/db/dump/fixtures.local.sql index 64d22f480..3714a85fc 100644 --- a/db/dump/fixtures.local.sql +++ b/db/dump/fixtures.local.sql @@ -404,3 +404,12 @@ INSERT INTO floranet.builder( FROM vn.item WHERE name = 'Ramo Terranova'; +INSERT IGNORE INTO floranet.addressPostCode (id, addressFk, postCode, hoursInAdvance, dayOfWeek, deliveryCost) + VALUES (1, 4, '46680', 48, 2, 6.00), + (5, 4, '46680', 24, 3, 6.00), + (6, 4, '46680', 24, 4, 6.00), + (7, 4, '46680', 24, 5, 6.00), + (8, 4, '46680', 24, 6, 0.00), + (9, 4, '46680', 24, 7, 20.00), + (2, 3, '46680', 24, 2, 9.25), + (3, 3, '46440', 24, 3, 0.00); \ No newline at end of file diff --git a/db/routines/floranet/procedures/deliveryDate_get.sql b/db/routines/floranet/procedures/deliveryDate_get.sql index 06a8ae1ad..29751ebe4 100644 --- a/db/routines/floranet/procedures/deliveryDate_get.sql +++ b/db/routines/floranet/procedures/deliveryDate_get.sql @@ -2,34 +2,28 @@ DROP PROCEDURE IF EXISTS floranet.deliveryDate_get; DELIMITER $$ $$ -CREATE DEFINER=`root`@`localhost` PROCEDURE floranet.deliveryDate_get(vPostalCode VARCHAR(15)) -READS SQL DATA +CREATE DEFINER=`root`@`localhost` PROCEDURE `floranet`.`deliveryDate_get`(vPostalCode VARCHAR(15)) + READS SQL DATA BEGIN /** - * Returns available dates for this postalCode + * Returns available dates for this postalCode, in the next seven days * * @param vPostalCode Delivery address postal code */ - CREATE OR REPLACE TEMPORARY TABLE tmp.deliveryDate - (dated DATE PRIMARY KEY) - ENGINE = MEMORY; + DECLARE vCurrentDayOfWeek INT; - IF vPostalCode != "00000" THEN - INSERT INTO tmp.deliveryDate - SET dated = CURDATE() + INTERVAL 1 DAY; + SET vCurrentDayOfWeek = DAYOFWEEK(NOW()); - INSERT INTO tmp.deliveryDate - SET dated = CURDATE() + INTERVAL 2 DAY; - - INSERT INTO tmp.deliveryDate - SET dated = CURDATE() + INTERVAL 4 DAY; - - INSERT INTO tmp.deliveryDate - SET dated = CURDATE() + INTERVAL 7 DAY; - END IF; - - SELECT * FROM tmp.deliveryDate; - - DROP TEMPORARY TABLE tmp.deliveryDate; + SELECT DISTINCT nextDay + FROM ( + SELECT CURDATE() + INTERVAL IF( + apc.dayOfWeek >= vCurrentDayOfWeek, + apc.dayOfWeek - vCurrentDayOfWeek, + 7 - apc.dayOfWeek + ) DAY nextDay, + NOW() + INTERVAL apc.hoursInAdvance - 12 HOUR minDeliveryTime + FROM addressPostCode apc + WHERE apc.postCode = vPostalCode + HAVING nextDay > minDeliveryTime) sub; END$$ DELIMITER ; \ No newline at end of file diff --git a/db/versions/10956-brownBirch/00-firstScript.sql b/db/versions/10956-brownBirch/00-firstScript.sql new file mode 100644 index 000000000..bcd15432c --- /dev/null +++ b/db/versions/10956-brownBirch/00-firstScript.sql @@ -0,0 +1,12 @@ +CREATE TABLE floranet.`addressPostCode` ( + `id` int(10) unsigned NOT NULL AUTO_INCREMENT, + `addressFk` int(11) NOT NULL, + `postCode` varchar(30) NOT NULL, + `hoursInAdvance` int(10) unsigned NOT NULL DEFAULT 24, + `dayOfWeek` int(10) unsigned NOT NULL, + `deliveryCost` decimal(10,2) NOT NULL DEFAULT 0.00, + PRIMARY KEY (`id`), + UNIQUE KEY `addressPostCode_unique` (`postCode`,`addressFk`,`dayOfWeek`), + KEY `addressPostCode_address_FK` (`addressFk`), + CONSTRAINT `addressPostCode_address_FK` FOREIGN KEY (`addressFk`) REFERENCES `vn`.`address` (`id`) ON DELETE CASCADE ON UPDATE CASCADE +) ENGINE=InnoDB AUTO_INCREMENT=5 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci COMMENT='Client''s address registered for floranet network'; \ No newline at end of file