SQL scripts

This commit is contained in:
Juan Ferrer 2019-09-26 10:08:37 +02:00
parent 2a0cc1dc8b
commit 3d4b7601be
6 changed files with 328 additions and 0 deletions

View File

@ -0,0 +1,27 @@
DROP FUNCTION IF EXISTS `vn`.`address_getGeo`;
DELIMITER $$
CREATE DEFINER=`root`@`%` FUNCTION `vn`.`address_getGeo` (vSelf INT)
RETURNS INT
DETERMINISTIC
BEGIN
/**
* Returns the geo for the passed address.
*
* @param vSelf The address id
* @return The geo id
*/
DECLARE vGeoFk INT;
SELECT p.geoFk INTO vGeoFk
FROM address a
JOIN town t ON t.provinceFk = a.provinceFk
JOIN postCode p ON p.townFk = t.id AND p.`code` = a.postalCode
WHERE a.id = vSelf
ORDER BY (a.city SOUNDS LIKE t.`name`) DESC
LIMIT 1;
RETURN vGeoFk;
END$$
DELIMITER ;

View File

@ -0,0 +1,37 @@
CREATE TABLE vn.`zoneWarehouse` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`zoneFk` int(11) NOT NULL,
`warehouseFk` smallint(6) unsigned NOT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `zoneFk` (`zoneFk`,`warehouseFk`),
KEY `warehouseFk` (`warehouseFk`),
CONSTRAINT `zoneWarehouse_ibfk_1` FOREIGN KEY (`zoneFk`) REFERENCES `zone` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `zoneWarehouse_ibfk_2` FOREIGN KEY (`warehouseFk`) REFERENCES `vn2008`.`warehouse` (`id`)
) ENGINE=InnoDB AUTO_INCREMENT=8 DEFAULT CHARSET=utf8;
CREATE TABLE vn.`zoneEvent` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`zoneFk` int(11) NOT NULL,
`from` date DEFAULT NULL,
`to` date DEFAULT NULL,
`weekDays` set('mon','tue','wed','thu','fri','sat','sun') NOT NULL,
`hour` datetime DEFAULT NULL,
`travelingDays` int(11) DEFAULT NULL,
`price` decimal(10,2) DEFAULT NULL,
`bonus` decimal(10,2) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `zoneFk` (`zoneFk`),
CONSTRAINT `zoneEvent_ibfk_1` FOREIGN KEY (`zoneFk`) REFERENCES `zone` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB AUTO_INCREMENT=31 DEFAULT CHARSET=utf8;
CREATE TABLE vn.`zoneExclusion` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`zoneFk` int(11) NOT NULL,
`day` date NOT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `zoneFk_2` (`zoneFk`,`day`),
KEY `zoneFk` (`zoneFk`),
CONSTRAINT `zoneExclusion_ibfk_1` FOREIGN KEY (`zoneFk`) REFERENCES `zone` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB AUTO_INCREMENT=5 DEFAULT CHARSET=utf8;

View File

@ -0,0 +1,72 @@
DROP PROCEDURE IF EXISTS `vn`.`zone_getAvailable`;
DELIMITER $$
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zone_getAvailable`(vAddress INT, vLanded DATE)
BEGIN
DECLARE vHour TIME DEFAULT TIME(NOW());
CALL zone_getFromGeo(address_getGeo(vAddress));
DELETE t FROM tmp.zone t
JOIN zoneExclusion e
ON e.zoneFk = t.id AND e.`day` = vLanded;
DROP TEMPORARY TABLE IF EXISTS tAvailableZones;
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
INSERT INTO tAvailableZones
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$$
DELIMITER ;

View File

@ -0,0 +1,47 @@
DROP PROCEDURE IF EXISTS `vn`.`zone_getEvents`;
DELIMITER $$
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zone_getEvents`(
vAgencyModeFk INT,
vProvinceFk INT,
vPostCode VARCHAR(255))
BEGIN
/**
* Returns available events for the passed province/postcode and agency.
*
* @param vAgencyModeFk The agency mode id
* @param vProvinceFk The province id
* @param vPostCode The postcode or %NULL to use the province
*/
DECLARE vGeoFk INT;
IF vPostCode IS NOT NULL THEN
SELECT p.geoFk INTO vGeoFk
FROM postCode p
JOIN town t ON t.id = p.townFk
WHERE p.`code` = vPostCode
AND t.provinceFk = vProvinceFk;
ELSE
SELECT geoFk INTO vGeoFk
FROM province
WHERE id = vProvinceFk;
END IF;
CALL zone_getFromGeo(vGeoFk);
DELETE t FROM tmp.zone t
JOIN zone z ON z.id = t.id
WHERE z.agencyModeFk != vAgencyModeFk;
SELECT e.`from`, e.`to`, e.weekDays
FROM tmp.zone t
JOIN zoneEvent e ON e.zoneFk = t.id;
SELECT DISTINCT e.`day`
FROM tmp.zone t
JOIN zoneExclusion e ON e.zoneFk = t.id;
DROP TEMPORARY TABLE tmp.zone;
END$$
DELIMITER ;

View File

@ -0,0 +1,57 @@
DROP PROCEDURE IF EXISTS `vn`.`zone_getFromGeo`;
DELIMITER $$
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zone_getFromGeo`(vGeoFk INT)
BEGIN
/**
* Returns available zones for the passed address.
*
* @param vAddress The address id
* @return tmp.zone(id) The available zones
*/
DECLARE vChildFk INT DEFAULT vGeoFk;
DECLARE vParentFk INT;
DECLARE vLevel INT DEFAULT 1;
DROP TEMPORARY TABLE IF EXISTS tNodes;
CREATE TEMPORARY TABLE tNodes
(PRIMARY KEY (id))
ENGINE = MEMORY
SELECT vGeoFk id, vLevel `level`;
myLoop: LOOP
SELECT parentFk INTO vParentFk
FROM zoneGeo
WHERE id = vChildFk;
SET vChildFk = vParentFk;
SET vLevel = vLevel + 1;
INSERT IGNORE INTO tNodes
SELECT vChildFk, vLevel
FROM DUAL
WHERE vChildFk IS NOT NULL;
IF ROW_COUNT() = 0 THEN
LEAVE myLoop;
END IF;
END LOOP;
DROP TEMPORARY TABLE IF EXISTS tmp.zone;
CREATE TEMPORARY TABLE tmp.zone
(INDEX (id))
SELECT id FROM (
SELECT zoneFk id, isIncluded
FROM (
SELECT i.zoneFk, i.isIncluded
FROM tNodes n
JOIN zoneIncluded i ON i.geoFk = n.id
ORDER BY zoneFk, n.`level`
) t
GROUP BY id HAVING isIncluded
) t;
DROP TEMPORARY TABLE tNodes;
END$$
DELIMITER ;

View File

@ -0,0 +1,88 @@
DROP procedure IF EXISTS `vn`.`zone_getLeaves`;
DELIMITER $$
CREATE DEFINER=`root`@`%` PROCEDURE `vn`.`zone_getLeaves`(
vSelf INT,
vParentFk INT,
vSearch VARCHAR(255)
)
BEGIN
DECLARE vIsNumber BOOL;
DECLARE vIsSearch BOOL DEFAULT vSearch IS NOT NULL AND vSearch != '';
DROP TEMPORARY TABLE IF EXISTS tNodes;
CREATE TEMPORARY TABLE tNodes
(UNIQUE (id))
ENGINE = MEMORY
SELECT id FROM zoneGeo LIMIT 0;
IF vIsSearch THEN
SET vIsNumber = vSearch REGEXP '^[0-9]+$';
INSERT INTO tNodes
SELECT id FROM zoneGeo
WHERE (vIsNumber AND `name` = vSearch)
OR (!vIsNumber AND `name` LIKE CONCAT('%', vSearch, '%'))
LIMIT 1000;
ELSEIF vParentFk IS NULL THEN
INSERT INTO tNodes
SELECT geoFk FROM zoneIncluded
WHERE zoneFk = vSelf;
END IF;
IF vParentFk IS NULL THEN
DROP TEMPORARY TABLE IF EXISTS tChilds;
CREATE TEMPORARY TABLE tChilds
ENGINE = MEMORY
SELECT id FROM tNodes;
DROP TEMPORARY TABLE IF EXISTS tParents;
CREATE TEMPORARY TABLE tParents
ENGINE = MEMORY
SELECT id FROM zoneGeo LIMIT 0;
myLoop: LOOP
DELETE FROM tParents;
INSERT INTO tParents
SELECT parentFk id
FROM zoneGeo g
JOIN tChilds c ON c.id = g.id
WHERE g.parentFk IS NOT NULL;
INSERT IGNORE INTO tNodes
SELECT id FROM tParents;
IF ROW_COUNT() = 0 THEN
LEAVE myLoop;
END IF;
DELETE FROM tChilds;
INSERT INTO tChilds
SELECT id FROM tParents;
END LOOP;
DROP TEMPORARY TABLE
tChilds,
tParents;
END IF;
IF !vIsSearch THEN
INSERT IGNORE INTO tNodes
SELECT id FROM zoneGeo
WHERE parentFk <=> vParentFk;
END IF;
SELECT g.id,
g.`name`,
g.parentFk,
g.sons,
isIncluded selected
FROM zoneGeo g
JOIN tNodes n ON n.id = g.id
LEFT JOIN zoneIncluded i
ON i.geoFk = g.id AND i.zoneFk = vSelf
ORDER BY depth, selected DESC, `name`;
DROP TEMPORARY TABLE tNodes;
END$$
DELIMITER ;