salix/db/changes/10100-AllSaints/04-zone_getOptionsForShipme...

66 lines
1.8 KiB
SQL

USE `vn`;
DROP procedure IF EXISTS `zone_getOptionsForShipment`;
DELIMITER $$
USE `vn`$$
CREATE DEFINER=`root`@`%` PROCEDURE `zone_getOptionsForShipment`(vShipped DATE)
BEGIN
/**
* Gets computed options for the passed zones and shipping date.
*
* @table tmp.zones(id) The zones ids
* @param vShipped The shipping date
* @return tmp.zoneOption(zoneFk, hour, travelingDays, price, bonus, specificity) 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,
TIME(e.`hour`) `hour`,
e.travelingDays,
e.price,
e.bonus,
CASE
WHEN e.`from` IS NULL AND e.`to` IS NULL
THEN 3
WHEN e.`to` IS NULL
THEN 2
ELSE 1
END specificity
FROM tmp.zone t
JOIN zoneEvent e ON e.zoneFk = t.id
WHERE (e.`from` = TIMESTAMPADD(DAY, e.travelingDays, vShipped) AND e.`to` IS NULL)
OR (
(e.`from` IS NULL OR TIMESTAMPADD(DAY, e.travelingDays, vShipped) BETWEEN e.`from` AND e.`to`)
AND e.weekDays & (1 << WEEKDAY(TIMESTAMPADD(DAY, e.travelingDays, vShipped)))
);
DELETE t FROM tTemp t
JOIN zoneExclusion e
ON e.zoneFk = t.zoneFk AND TIMESTAMPADD(DAY,-t.travelingDays, e.`day`) = vShipped;
UPDATE tTemp t
JOIN zone z ON z.id = t.zoneFk
SET t.`hour` = IFNULL(t.`hour`, TIME(z.`hour`)),
t.travelingDays = IFNULL(t.travelingDays, z.travelingDays),
t.price = IFNULL(t.price, z.price),
t.bonus = IFNULL(t.bonus, z.bonus);
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 ;