DROP PROCEDURE IF EXISTS `vn`.`zone_getOptionsForLanding`; DELIMITER $$ CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`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, 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` = vLanded AND e.`to` IS NULL) OR ( (e.`from` IS NULL OR vLanded BETWEEN e.`from` AND e.`to`) AND e.weekDays & (1 << WEEKDAY(vLanded)) ); -- XXX: Compatibility with the deprecated #zoneCalendar table INSERT INTO tTemp SELECT t.id zoneFk, NULL, NULL, c.price, c.bonus, 4 FROM tmp.zone t JOIN zoneCalendar c ON c.zoneFk = t.id WHERE c.delivered = vLanded; DELETE t FROM tTemp t JOIN zoneExclusion e ON e.zoneFk = t.zoneFk AND e.`day` = vLanded; 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); 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 ;