Refactor agency SQL scripts
This commit is contained in:
parent
3d4b7601be
commit
445668d57f
|
@ -3,70 +3,14 @@ DROP PROCEDURE IF EXISTS `vn`.`zone_getAvailable`;
|
||||||
DELIMITER $$
|
DELIMITER $$
|
||||||
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zone_getAvailable`(vAddress INT, vLanded DATE)
|
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zone_getAvailable`(vAddress INT, vLanded DATE)
|
||||||
BEGIN
|
BEGIN
|
||||||
DECLARE vHour TIME DEFAULT TIME(NOW());
|
|
||||||
|
|
||||||
CALL zone_getFromGeo(address_getGeo(vAddress));
|
CALL zone_getFromGeo(address_getGeo(vAddress));
|
||||||
|
CALL zone_getOptionsForDate(vLanded);
|
||||||
DELETE t FROM tmp.zone t
|
|
||||||
JOIN zoneExclusion e
|
|
||||||
ON e.zoneFk = t.id AND e.`day` = vLanded;
|
|
||||||
|
|
||||||
DROP TEMPORARY TABLE IF EXISTS tAvailableZones;
|
SELECT * FROM tmp.zoneOption;
|
||||||
CREATE TEMPORARY TABLE tAvailableZones
|
|
||||||
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
|
DROP TEMPORARY TABLE
|
||||||
|
tmp.zone,
|
||||||
INSERT INTO tAvailableZones
|
tmp.zoneOption;
|
||||||
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;
|
|
||||||
|
|
||||||
DROP TEMPORARY TABLE tmp.zone;
|
|
||||||
|
|
||||||
UPDATE tAvailableZones 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 tAvailableZones
|
|
||||||
WHERE (@shipped := TIMESTAMPADD(DAY, -travelingDays, vLanded)) < CURDATE()
|
|
||||||
OR @shipped = CURDATE() AND vHour > `hour`;
|
|
||||||
|
|
||||||
SELECT *
|
|
||||||
FROM (
|
|
||||||
SELECT * FROM tAvailableZones
|
|
||||||
ORDER BY zoneFk, specificity
|
|
||||||
) t
|
|
||||||
GROUP BY zoneFk;
|
|
||||||
|
|
||||||
DROP TEMPORARY TABLE tAvailableZones;
|
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
||||||
|
|
||||||
|
|
|
@ -4,10 +4,10 @@ DELIMITER $$
|
||||||
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zone_getFromGeo`(vGeoFk INT)
|
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zone_getFromGeo`(vGeoFk INT)
|
||||||
BEGIN
|
BEGIN
|
||||||
/**
|
/**
|
||||||
* Returns available zones for the passed address.
|
* Returns all zones which have the passed geo included.
|
||||||
*
|
*
|
||||||
* @param vAddress The address id
|
* @param vGeoFk The geo id
|
||||||
* @return tmp.zone(id) The available zones
|
* @return tmp.zone(id) The list of zones
|
||||||
*/
|
*/
|
||||||
DECLARE vChildFk INT DEFAULT vGeoFk;
|
DECLARE vChildFk INT DEFAULT vGeoFk;
|
||||||
DECLARE vParentFk INT;
|
DECLARE vParentFk INT;
|
||||||
|
@ -40,6 +40,7 @@ BEGIN
|
||||||
DROP TEMPORARY TABLE IF EXISTS tmp.zone;
|
DROP TEMPORARY TABLE IF EXISTS tmp.zone;
|
||||||
CREATE TEMPORARY TABLE tmp.zone
|
CREATE TEMPORARY TABLE tmp.zone
|
||||||
(INDEX (id))
|
(INDEX (id))
|
||||||
|
ENGINE = MEMORY
|
||||||
SELECT id FROM (
|
SELECT id FROM (
|
||||||
SELECT zoneFk id, isIncluded
|
SELECT zoneFk id, isIncluded
|
||||||
FROM (
|
FROM (
|
||||||
|
|
|
@ -0,0 +1,79 @@
|
||||||
|
|
||||||
|
DROP PROCEDURE IF EXISTS `vn`.`zone_getOptionsForDate`;
|
||||||
|
DELIMITER $$
|
||||||
|
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zone_getOptionsForDate`(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 ;
|
||||||
|
|
Loading…
Reference in New Issue