68 lines
1.6 KiB
SQL
68 lines
1.6 KiB
SQL
USE `vn`;
|
|
DROP procedure IF EXISTS `zone_getOptionsForLanding`;
|
|
|
|
DELIMITER $$
|
|
USE `vn`$$
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `zone_getOptionsForLanding`(vLanded DATE)
|
|
BEGIN
|
|
/**
|
|
* Gets computed options for the passed zones and delivery date.
|
|
*
|
|
* @table tmp.zones(id) The zones ids
|
|
* @param vLanded The delivery date
|
|
* @return tmp.zoneOption The computed options
|
|
*/
|
|
DECLARE vHour TIME DEFAULT TIME(NOW());
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tTemp;
|
|
CREATE TEMPORARY TABLE tTemp
|
|
ENGINE = MEMORY
|
|
SELECT t.id zoneFk,
|
|
IFNULL(TIME(e.`hour`), TIME(z.`hour`)) `hour`,
|
|
IFNULL(e.travelingDays, z.travelingDays) travelingDays,
|
|
IFNULL(e.price, z.price) price,
|
|
IFNULL(e.bonus, z.bonus) bonus,
|
|
CASE
|
|
WHEN e.`type` = 'day'
|
|
THEN 1
|
|
WHEN e.`type` = 'range'
|
|
THEN 2
|
|
ELSE 3
|
|
END specificity
|
|
FROM tmp.zone t
|
|
JOIN zone z ON z.id = t.id
|
|
JOIN zoneEvent e ON e.zoneFk = t.id
|
|
WHERE (
|
|
e.`type` = 'day'
|
|
AND e.dated = vLanded
|
|
) OR (
|
|
e.`type` != 'day'
|
|
AND e.weekDays & (1 << WEEKDAY(vLanded))
|
|
AND (e.`started` IS NULL OR vLanded >= e.`started`)
|
|
AND (e.`ended` IS NULL OR vLanded <= e.`ended`)
|
|
);
|
|
|
|
DELETE t FROM tTemp t
|
|
JOIN zoneExclusion e
|
|
ON e.zoneFk = t.zoneFk AND e.`dated` = vLanded;
|
|
|
|
DELETE FROM tTemp
|
|
WHERE (@shipped := TIMESTAMPADD(DAY, -travelingDays, vLanded)) < CURDATE()
|
|
OR @shipped = CURDATE() AND vHour > `hour`;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp.zoneOption;
|
|
CREATE TEMPORARY TABLE tmp.zoneOption
|
|
ENGINE = MEMORY
|
|
SELECT *
|
|
FROM (
|
|
SELECT * FROM tTemp
|
|
ORDER BY zoneFk, specificity
|
|
) t
|
|
GROUP BY zoneFk;
|
|
|
|
DROP TEMPORARY TABLE tTemp;
|
|
END$$
|
|
|
|
DELIMITER ;
|
|
|