CREATE TABLE `vn`.`zoneExclusionGeo` ( `id` int(11) NOT NULL AUTO_INCREMENT, `zoneExclusionFk` int(11) NOT NULL, `geoFk` int(11) NOT NULL, PRIMARY KEY (`id`), UNIQUE KEY `zoneExclusionGeo_UN` (`zoneExclusionFk`,`geoFk`), KEY `zoneExclusionGeo2_FK_1` (`geoFk`), CONSTRAINT `zoneExclusionGeo_FK` FOREIGN KEY (`geoFk`) REFERENCES `zoneGeo` (`id`) ON UPDATE CASCADE, CONSTRAINT `zoneExclusionGeo_FK_1` FOREIGN KEY (`zoneExclusionFk`) REFERENCES `zoneExclusion` (`id`) ON DELETE CASCADE ON UPDATE CASCADE ) ENGINE=InnoDB AUTO_INCREMENT=2 DEFAULT CHARSET=utf8; DROP PROCEDURE IF EXISTS `vn`.`zone_excludeFromGeo`; DELIMITER $$ CREATE DEFINER=`root`@`localhost` PROCEDURE `vn`.`zone_excludeFromGeo`(vZoneGeo INT) BEGIN /** * Excluye zonas a partir un geoFk. * * @table tmp.zoneOption(zoneFk, hour, travelingDays, price, bonus, landed, shipped) The computed options * @param vZoneGeo The zone geo * @return tmp.zoneOption The computed options */ DELETE t FROM tmp.zoneOption t JOIN zoneExclusion e ON e.zoneFk = t.zoneFk AND e.`dated` = t.landed LEFT JOIN zoneExclusionGeo eg ON eg.zoneExclusionFk = e.id JOIN zoneGeo zg1 ON zg1.id = eg.geoFk JOIN zoneGeo zg2 ON zg2.id = vZoneGeo WHERE zg2.`path` LIKE CONCAT(zg1.`path`,'%'); END$$ DELIMITER ; DROP PROCEDURE IF EXISTS `vn`.`zone_getEvents`; DELIMITER $$ CREATE DEFINER=`root`@`localhost` PROCEDURE `vn`.`zone_getEvents`( vGeoFk INT, vAgencyModeFk INT) BEGIN /** * Returns available events for the passed province/postcode and agency. * * @param vGeoFk The geo id * @param vAgencyModeFk The agency mode id */ DECLARE vDeliveryMethodFk VARCHAR(255); DROP TEMPORARY TABLE IF EXISTS tZone; CREATE TEMPORARY TABLE tZone (id INT PRIMARY KEY) ENGINE = MEMORY; SELECT dm.`code` INTO vDeliveryMethodFk FROM agencyMode am JOIN deliveryMethod dm ON dm.id = am.deliveryMethodFk WHERE am.id = vAgencyModeFk; IF vDeliveryMethodFk = 'PICKUP' THEN INSERT INTO tZone SELECT id FROM zone WHERE agencyModeFk = vAgencyModeFk; ELSE CALL zone_getFromGeo(vGeoFk); IF vAgencyModeFk IS NOT NULL THEN INSERT INTO tZone SELECT t.id FROM tmp.zone t JOIN zone z ON z.id = t.id WHERE z.agencyModeFk = vAgencyModeFk; ELSE INSERT INTO tZone SELECT t.id FROM tmp.zone t JOIN zone z ON z.id = t.id JOIN agencyMode am ON am.id = z.agencyModeFk JOIN deliveryMethod dm ON dm.id = am.deliveryMethodFk WHERE dm.`code` IN ('AGENCY', 'DELIVERY'); END IF; DROP TEMPORARY TABLE tmp.zone; END IF; SELECT e.zoneFk, e.`type`, e.dated, e.`started`, e.`ended`, e.weekDays FROM tZone t JOIN zoneEvent e ON e.zoneFk = t.id; SELECT e.zoneFk, e.dated FROM tZone t JOIN zoneExclusion e ON e.zoneFk = t.id LEFT JOIN zoneExclusionGeo eg ON eg.zoneExclusionFk = e.id JOIN zoneGeo zg1 ON zg1.id = eg.geoFk JOIN zoneGeo zg2 ON zg2.id = vGeoFk WHERE eg.zoneExclusionFk IS NULL OR zg2.`path` LIKE CONCAT(zg1.`path`,'%'); DROP TEMPORARY TABLE tZone; END$$ DELIMITER ; DROP PROCEDURE IF EXISTS `vn`.`zone_getLanded`; DELIMITER $$ CREATE DEFINER=`root`@`localhost` PROCEDURE `vn`.`zone_getLanded`(vShipped DATE, vAddressFk INT, vAgencyModeFk INT, vWarehouseFk INT, vShowExpiredZones BOOLEAN) BEGIN /** * Devuelve una tabla temporal con el dia de recepcion para vShipped. * Excluye las que tengan cajas preparadas * * @param vShipped Fecha de preparacion de mercancia * @param vAddressFk Id de consignatario, %NULL para recogida * @param vAgencyModeFk Id agencia * @param vWarehouseFk vWarehouseFk * @table tmp.zoneGetLanded Datos de recepción */ DECLARE vZoneGeo INT; SELECT address_getGeo(vAddressFk) INTO vZoneGeo; CALL vn.zone_getFromGeo(vZoneGeo); CALL vn.zone_getOptionsForShipment(vShipped, vShowExpiredZones); CALL vn.zone_excludeFromGeo(vZoneGeo); CALL vn.zone_getClosed(); DROP TEMPORARY TABLE IF EXISTS tmp.zoneGetLanded; CREATE TEMPORARY TABLE tmp.zoneGetLanded ENGINE = MEMORY SELECT vWarehouseFk warehouseFk, TIMESTAMPADD(DAY,zo.travelingDays, vShipped) landed, zo.zoneFk FROM tmp.zoneOption zo JOIN vn.`zone` z ON z.id = zo.zoneFk JOIN vn.zoneWarehouse zw ON zw.zoneFk = z.id LEFT JOIN tmp.closedZones cz ON cz.warehouseFk = zw.warehouseFk AND cz.zoneFk = zw.zoneFk AND zo.shipped = CURDATE() WHERE z.agencyModeFk = vAgencyModeFk AND zw.warehouseFk = vWarehouseFk AND (ISNULL(cz.zoneFk) OR vShowExpiredZones); DROP TEMPORARY TABLE tmp.`zone`, tmp.zoneOption, tmp.closedZones; END$$ DELIMITER ; DROP PROCEDURE IF EXISTS `vn`.`zone_getOptionsForLanding`; DELIMITER $$ CREATE DEFINER=`root`@`localhost` PROCEDURE `vn`.`zone_getOptionsForLanding`(vLanded DATE, vShowExpiredZones BOOLEAN) BEGIN /** * Gets computed options for the passed zones and delivery date. * * @table tmp.zone(id) The zones ids * @param vLanded The delivery date * @return tmp.zoneOption The computed options */ DROP TEMPORARY TABLE IF EXISTS tmp.zoneOption; CREATE TEMPORARY TABLE tmp.zoneOption ENGINE = MEMORY SELECT zoneFk, `hour`, travelingDays, price, bonus, vLanded landed, TIMESTAMPADD(DAY, -travelingDays, vLanded) shipped FROM ( SELECT t.id zoneFk, TIME(IFNULL(e.`hour`, z.`hour`)) `hour`, IFNULL(e.travelingDays, z.travelingDays) travelingDays, IFNULL(e.price, z.price) price, IFNULL(e.bonus, z.bonus) bonus 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`) ) ORDER BY zoneFk, CASE WHEN e.`type` = 'day' THEN 1 WHEN e.`type` = 'range' THEN 2 ELSE 3 END ) t GROUP BY zoneFk; DELETE t FROM tmp.zoneOption t JOIN zoneExclusion e ON e.zoneFk = t.zoneFk AND e.`dated` = t.landed LEFT JOIN zoneExclusionGeo eg ON eg.zoneExclusionFk = e.id WHERE eg.zoneExclusionFk IS NULL; IF NOT vShowExpiredZones THEN DELETE FROM tmp.zoneOption WHERE shipped < CURDATE() OR (shipped = CURDATE() AND CURTIME() > `hour`); END IF; END$$ DELIMITER ; DROP PROCEDURE IF EXISTS `vn`.`zone_getOptionsForShipment`; DELIMITER $$ CREATE DEFINER=`root`@`localhost` PROCEDURE `vn`.`zone_getOptionsForShipment`(vShipped DATE, vShowExpiredZones BOOLEAN) 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 tLandings; CREATE TEMPORARY TABLE tLandings (INDEX (eventFk)) ENGINE = MEMORY SELECT e.id eventFk, @travelingDays := IFNULL(e.travelingDays, z.travelingDays) travelingDays, TIMESTAMPADD(DAY, @travelingDays, vShipped) landed FROM tmp.zone t JOIN zone z ON z.id = t.id JOIN zoneEvent e ON e.zoneFk = t.id; DROP TEMPORARY TABLE IF EXISTS tmp.zoneOption; CREATE TEMPORARY TABLE tmp.zoneOption ENGINE = MEMORY SELECT * FROM ( SELECT t.id zoneFk, TIME(IFNULL(e.`hour`, z.`hour`)) `hour`, l.travelingDays, IFNULL(e.price, z.price) price, IFNULL(e.bonus, z.bonus) bonus, l.landed, vShipped shipped FROM tmp.zone t JOIN zone z ON z.id = t.id JOIN zoneEvent e ON e.zoneFk = t.id JOIN tLandings l ON l.eventFk = e.id WHERE ( e.`type` = 'day' AND e.`dated` = l.landed ) OR ( e.`type` != 'day' AND e.weekDays & (1 << WEEKDAY(l.landed)) AND (e.`started` IS NULL OR l.landed >= e.`started`) AND (e.`ended` IS NULL OR l.landed <= e.`ended`) ) ORDER BY zoneFk, CASE WHEN e.`type` = 'day' THEN 1 WHEN e.`type` = 'range' THEN 2 ELSE 3 END ) t GROUP BY zoneFk; DROP TEMPORARY TABLE tLandings; DELETE t FROM tmp.zoneOption t JOIN zoneExclusion e ON e.zoneFk = t.zoneFk AND e.`dated` = t.landed LEFT JOIN zoneExclusionGeo eg ON eg.zoneExclusionFk = e.id WHERE eg.zoneExclusionFk IS NULL; IF NOT vShowExpiredZones THEN DELETE FROM tmp.zoneOption WHERE vShipped < CURDATE() OR (vShipped = CURDATE() AND CURTIME() > `hour`); END IF; END$$ DELIMITER ; DROP PROCEDURE IF EXISTS `vn`.`zone_getShipped`; DELIMITER $$ CREATE DEFINER=`root`@`localhost` PROCEDURE `vn`.`zone_getShipped`(vLanded DATE, vAddressFk INT, vAgencyModeFk INT, vShowExpiredZones BOOLEAN) BEGIN /** * Devuelve la mínima fecha de envío para cada warehouse * Excluye aquellas zonas que ya tienen cajas preparadas en ese almacén * * @param vLanded La fecha de recepcion * @param vAddressFk Id del consignatario * @param vAgencyModeFk Id de la agencia * @return tmp.zoneGetShipped */ DECLARE vZoneGeo INT; SELECT address_getGeo(vAddressFk) INTO vZoneGeo; CALL vn.zone_getFromGeo(vZoneGeo); CALL vn.zone_getOptionsForLanding(vLanded, vShowExpiredZones); CALL vn.zone_excludeFromGeo(vZoneGeo); CALL vn.zone_getClosed(); DROP TEMPORARY TABLE IF EXISTS tmp.zoneGetShipped; CREATE TEMPORARY TABLE tmp.zoneGetShipped ENGINE = MEMORY SELECT * FROM ( SELECT zo.zoneFk, zo.shipped, zo.`hour`, zw.warehouseFk, z.agencyModeFk, zo.price, zo.bonus FROM tmp.zoneOption zo JOIN vn.zoneWarehouse zw ON zw.zoneFk = zo.zoneFk JOIN vn.`zone` z ON z.id = zo.zoneFk LEFT JOIN tmp.closedZones cz ON cz.warehouseFk = zw.warehouseFk AND cz.zoneFk = zw.zoneFk AND zo.shipped = CURDATE() WHERE z.agencyModeFk = vAgencyModeFk AND (ISNULL(cz.zoneFk) OR vShowExpiredZones) ORDER BY shipped) t GROUP BY warehouseFk; DROP TEMPORARY TABLE tmp.`zone`, tmp.zoneOption, tmp.closedZones; END$$ DELIMITER ; DROP PROCEDURE IF EXISTS `vn`.`zone_upcomingDeliveries`; DELIMITER $$ CREATE DEFINER=`root`@`localhost` PROCEDURE `vn`.`zone_upcomingDeliveries`() BEGIN DECLARE vForwardDays INT; SELECT forwardDays INTO vForwardDays FROM zoneConfig; CALL util.time_createTable(CURDATE(), DATE_ADD(CURDATE(), INTERVAL vForwardDays DAY)); DROP TEMPORARY TABLE IF EXISTS tLandings; CREATE TEMPORARY TABLE tLandings (INDEX (eventFk)) ENGINE = MEMORY SELECT e.id eventFk, @travelingDays := IFNULL(e.travelingDays, z.travelingDays) travelingDays, TIMESTAMPADD(DAY, @travelingDays, ti.dated) landed, ti.dated shipped FROM zone z JOIN zoneEvent e ON e.zoneFk = z.id JOIN tmp.time ti ON ti.dated BETWEEN curdate() AND TIMESTAMPADD(DAY, vForwardDays, curdate()); DROP TEMPORARY TABLE IF EXISTS tmp.zoneOption; CREATE TEMPORARY TABLE tmp.zoneOption ENGINE = MEMORY SELECT * FROM ( SELECT z.id zoneFk, TIME(IFNULL(e.`hour`, z.`hour`)) `hour`, l.travelingDays, IFNULL(e.price, z.price) price, IFNULL(e.bonus, z.bonus) bonus, l.landed, l.shipped FROM zone z JOIN zoneEvent e ON e.zoneFk = z.id JOIN tLandings l ON l.eventFk = e.id WHERE ( e.`type` = 'day' AND e.`dated` = l.landed ) OR ( e.`type` != 'day' AND e.weekDays & (1 << WEEKDAY(l.landed)) AND (e.`started` IS NULL OR l.landed >= e.`started`) AND (e.`ended` IS NULL OR l.landed <= e.`ended`) ) ORDER BY zoneFk, CASE WHEN e.`type` = 'day' THEN 1 WHEN e.`type` = 'range' THEN 2 ELSE 3 END ) t GROUP BY zoneFk, landed; DELETE t FROM tmp.zoneOption t JOIN zoneExclusion e ON e.zoneFk = t.zoneFk AND e.`dated` = t.landed LEFT JOIN zoneExclusionGeo eg ON eg.zoneExclusionFk = e.id WHERE eg.zoneExclusionFk IS NULL; SELECT MAX(zo.`hour`) `hour`, zg.`name`, zo.shipped, zo.zoneFk FROM tmp.zoneOption zo JOIN `zone` z ON z.id = zo.zoneFk JOIN agencyMode am ON am.id = z.agencyModeFk JOIN deliveryMethod dm ON dm.id = am.deliveryMethodFk JOIN zoneIncluded zi ON zi.zoneFk = z.id JOIN zoneGeo zg ON zg.id = zi.geoFk AND zg.type = 'province' WHERE dm.code = 'DELIVERY' GROUP BY shipped, zg.`name` ORDER BY shipped, zg.`name`; DROP TEMPORARY TABLE tmp.time, tLandings; END$$ DELIMITER ;