deliveryDate
gitea/salix/pipeline/pr-dev This commit looks good Details

This commit is contained in:
Pako Natek 2024-03-18 14:03:16 +01:00
parent 67b55ae845
commit 8f54a7f12d
3 changed files with 37 additions and 22 deletions

View File

@ -404,3 +404,12 @@ INSERT INTO floranet.builder(
FROM vn.item FROM vn.item
WHERE name = 'Ramo Terranova'; 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);

View File

@ -2,34 +2,28 @@ DROP PROCEDURE IF EXISTS floranet.deliveryDate_get;
DELIMITER $$ DELIMITER $$
$$ $$
CREATE DEFINER=`root`@`localhost` PROCEDURE floranet.deliveryDate_get(vPostalCode VARCHAR(15)) CREATE DEFINER=`root`@`localhost` PROCEDURE `floranet`.`deliveryDate_get`(vPostalCode VARCHAR(15))
READS SQL DATA READS SQL DATA
BEGIN BEGIN
/** /**
* Returns available dates for this postalCode * Returns available dates for this postalCode, in the next seven days
* *
* @param vPostalCode Delivery address postal code * @param vPostalCode Delivery address postal code
*/ */
CREATE OR REPLACE TEMPORARY TABLE tmp.deliveryDate DECLARE vCurrentDayOfWeek INT;
(dated DATE PRIMARY KEY)
ENGINE = MEMORY;
IF vPostalCode != "00000" THEN SET vCurrentDayOfWeek = DAYOFWEEK(NOW());
INSERT INTO tmp.deliveryDate
SET dated = CURDATE() + INTERVAL 1 DAY;
INSERT INTO tmp.deliveryDate SELECT DISTINCT nextDay
SET dated = CURDATE() + INTERVAL 2 DAY; FROM (
SELECT CURDATE() + INTERVAL IF(
INSERT INTO tmp.deliveryDate apc.dayOfWeek >= vCurrentDayOfWeek,
SET dated = CURDATE() + INTERVAL 4 DAY; apc.dayOfWeek - vCurrentDayOfWeek,
7 - apc.dayOfWeek
INSERT INTO tmp.deliveryDate ) DAY nextDay,
SET dated = CURDATE() + INTERVAL 7 DAY; NOW() + INTERVAL apc.hoursInAdvance - 12 HOUR minDeliveryTime
END IF; FROM addressPostCode apc
WHERE apc.postCode = vPostalCode
SELECT * FROM tmp.deliveryDate; HAVING nextDay > minDeliveryTime) sub;
DROP TEMPORARY TABLE tmp.deliveryDate;
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -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';