zoneClosure fase 2
gitea/salix/test This commit looks good
Details
gitea/salix/test This commit looks good
Details
This commit is contained in:
parent
ea5a337942
commit
03f0a415f9
|
@ -3,9 +3,9 @@ ADD COLUMN `zonePrice` DECIMAL(10,2) NULL DEFAULT NULL AFTER `collectionFk`,
|
||||||
ADD COLUMN `zoneBonus` DECIMAL(10,2) NULL DEFAULT NULL AFTER `zonePrice`,
|
ADD COLUMN `zoneBonus` DECIMAL(10,2) NULL DEFAULT NULL AFTER `zonePrice`,
|
||||||
ADD COLUMN `zoneClosure` TIME NULL AFTER `zoneBonus`;
|
ADD COLUMN `zoneClosure` TIME NULL AFTER `zoneBonus`;
|
||||||
|
|
||||||
CREATE TABLE vn.`zoneCalcTicket` (
|
CREATE TABLE `vn`.`zoneCalcTicket` (
|
||||||
`zoneFk` int(11) NOT NULL PRIMARY KEY,
|
`zoneFk` int(11) NOT NULL PRIMARY KEY,
|
||||||
CONSTRAINT `zoneCalcTicketfk_1` FOREIGN KEY (`zoneFk`) REFERENCES `zone` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
|
CONSTRAINT `zoneCalcTicketfk_1` FOREIGN KEY (`zoneFk`) REFERENCES `vn`.`zone` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci;
|
||||||
|
|
||||||
DROP EVENT IF EXISTS vn.`zone_doCalc`;
|
DROP EVENT IF EXISTS vn.`zone_doCalc`;
|
||||||
|
|
|
@ -1 +0,0 @@
|
||||||
USE `vn`;
|
|
|
@ -0,0 +1,62 @@
|
||||||
|
USE `vn`;
|
||||||
|
DROP procedure IF EXISTS `zone_doCalcInitialize`;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
USE `vn`$$
|
||||||
|
CREATE DEFINER=`root`@`%` PROCEDURE `zone_doCalcInitialize`()
|
||||||
|
proc: BEGIN
|
||||||
|
/**
|
||||||
|
* Initialize ticket
|
||||||
|
*/
|
||||||
|
DECLARE vDone BOOL;
|
||||||
|
DECLARE vTicketFk INT;
|
||||||
|
DECLARE vLanded DATE;
|
||||||
|
DECLARE vZoneFk INT;
|
||||||
|
|
||||||
|
DECLARE cCur CURSOR FOR
|
||||||
|
SELECT t.id, t.landed, t.zoneFk
|
||||||
|
FROM ticket t
|
||||||
|
WHERE (zonePrice IS NULL OR zoneBonus IS NULL OR zoneClosure IS NULL)
|
||||||
|
AND landed >= '2019-01-01' AND shipped >= '2019-01-01'
|
||||||
|
GROUP BY landed, zoneFk;
|
||||||
|
|
||||||
|
DECLARE CONTINUE HANDLER FOR NOT FOUND
|
||||||
|
SET vDone = TRUE;
|
||||||
|
|
||||||
|
OPEN cCur;
|
||||||
|
|
||||||
|
myLoop: LOOP
|
||||||
|
SET vDone = FALSE;
|
||||||
|
FETCH cCur INTO vTicketFk, vLanded, vZoneFk;
|
||||||
|
|
||||||
|
IF vDone THEN
|
||||||
|
LEAVE myLoop;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE IF EXISTS tmp.zone;
|
||||||
|
CREATE TEMPORARY TABLE tmp.zone
|
||||||
|
(INDEX (id))
|
||||||
|
ENGINE = MEMORY
|
||||||
|
SELECT vZoneFk id;
|
||||||
|
|
||||||
|
CALL zone_getOptionsForLanding(vLanded, TRUE);
|
||||||
|
|
||||||
|
UPDATE ticket t
|
||||||
|
LEFT JOIN tmp.zoneOption zo ON TRUE
|
||||||
|
SET zonePrice = zo.price, zoneBonus = zo.bonus, zoneClosure = zo.`hour`
|
||||||
|
WHERE t.zoneFk = vZoneFk AND landed = vLanded;
|
||||||
|
|
||||||
|
UPDATE ticket t
|
||||||
|
LEFT JOIN vn.zone z ON z.id = t.zoneFk
|
||||||
|
SET zonePrice = z.price, zoneBonus = z.bonus, zoneClosure = z.`hour`
|
||||||
|
WHERE t.zonePrice IS NULL AND z.id = vZoneFk
|
||||||
|
AND landed >= '2019-01-01' AND shipped >= '2019-01-01';
|
||||||
|
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
CLOSE cCur;
|
||||||
|
|
||||||
|
DELETE FROM zoneCalcTicket;
|
||||||
|
END$$
|
||||||
|
|
||||||
|
DELIMITER ;
|
|
@ -0,0 +1,66 @@
|
||||||
|
USE `vn`;
|
||||||
|
DROP procedure IF EXISTS `zone_getOptionsForLanding`;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
USE `vn`$$
|
||||||
|
CREATE DEFINER=`root`@`%` PROCEDURE `zone_getOptionsForLanding`(vLanded DATE, vShowExpiredZones BOOLEAN)
|
||||||
|
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
|
||||||
|
*/
|
||||||
|
DROP TEMPORARY TABLE IF EXISTS tmp.zoneOption;
|
||||||
|
CREATE TEMPORARY TABLE tmp.zoneOption
|
||||||
|
ENGINE = MEMORY
|
||||||
|
SELECT
|
||||||
|
zoneFk,
|
||||||
|
`hour`,
|
||||||
|
travelingDays,
|
||||||
|
price,
|
||||||
|
bonus,
|
||||||
|
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` = vLanded;
|
||||||
|
|
||||||
|
IF NOT vShowExpiredZones THEN
|
||||||
|
DELETE FROM tmp.zoneOption
|
||||||
|
WHERE shipped < CURDATE()
|
||||||
|
OR (shipped = CURDATE() AND CURTIME() > `hour`);
|
||||||
|
END IF;
|
||||||
|
END$$
|
||||||
|
|
||||||
|
DELIMITER ;
|
|
@ -0,0 +1,171 @@
|
||||||
|
USE `vn`;
|
||||||
|
DROP procedure IF EXISTS `rutasAnalyze`;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
USE `vn`$$
|
||||||
|
CREATE DEFINER=`root`@`%` PROCEDURE `rutasAnalyze`(vYear INT, vMonth INT)
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
/* Analiza los costes de las rutas de reparto y lo almacena en la tabla Rutas_Master
|
||||||
|
*
|
||||||
|
* PAK 15/4/2019
|
||||||
|
*/
|
||||||
|
|
||||||
|
DELETE FROM bi.rutasBoard
|
||||||
|
WHERE year = vYear AND month = vMonth;
|
||||||
|
|
||||||
|
-- Rellenamos la tabla con los datos de las rutas VOLUMETRICAS, especialmente con los bultos "virtuales"
|
||||||
|
INSERT INTO bi.rutasBoard(year,
|
||||||
|
month,
|
||||||
|
warehouse_id,
|
||||||
|
Id_Ruta,
|
||||||
|
Id_Agencia,
|
||||||
|
km,
|
||||||
|
Dia,
|
||||||
|
Fecha,
|
||||||
|
Bultos,
|
||||||
|
Matricula,
|
||||||
|
Tipo,
|
||||||
|
Terceros)
|
||||||
|
SELECT YEAR(r.created),
|
||||||
|
MONTH(r.created),
|
||||||
|
GREATEST(1,a.warehouseFk),
|
||||||
|
r.id,
|
||||||
|
r.agencyModeFk,
|
||||||
|
r.kmEnd - r.kmStart,
|
||||||
|
DAYNAME(r.created),
|
||||||
|
r.created,
|
||||||
|
SUM(sv.volume / ebv.m3),
|
||||||
|
v.numberPlate,
|
||||||
|
IF(ISNULL(`r`.`cost`), 'P', 'A'),
|
||||||
|
r.cost
|
||||||
|
FROM vn.route r
|
||||||
|
JOIN vn.ticket t ON t.routeFk = r.id
|
||||||
|
LEFT JOIN vn.zone z ON z.id = t.zoneFk
|
||||||
|
LEFT JOIN vn.agencyMode am ON am.id = r.agencyModeFk
|
||||||
|
LEFT JOIN vn.agency a ON a.id = am.agencyFk
|
||||||
|
LEFT JOIN vn.vehicle v ON v.id = r.vehicleFk
|
||||||
|
JOIN vn.saleVolume sv ON sv.ticketFk = t.id
|
||||||
|
JOIN vn.expeditionBoxVol ebv ON ebv.boxFk = 71
|
||||||
|
WHERE YEAR(r.created) = vYear AND MONTH(r.created) = vMonth
|
||||||
|
AND z.isVolumetric
|
||||||
|
GROUP BY r.id;
|
||||||
|
|
||||||
|
-- Rellenamos la tabla con los datos de las rutas NO VOLUMETRICAS, especialmente con los bultos "virtuales"
|
||||||
|
INSERT INTO bi.rutasBoard(year,
|
||||||
|
month,
|
||||||
|
warehouse_id,
|
||||||
|
Id_Ruta,
|
||||||
|
Id_Agencia,
|
||||||
|
km,
|
||||||
|
Dia,
|
||||||
|
Fecha,
|
||||||
|
Bultos,
|
||||||
|
Matricula,
|
||||||
|
Tipo,
|
||||||
|
Terceros)
|
||||||
|
SELECT YEAR(r.created),
|
||||||
|
MONTH(r.created),
|
||||||
|
GREATEST(1,a.warehouseFk),
|
||||||
|
r.id,
|
||||||
|
r.agencyModeFk,
|
||||||
|
r.kmEnd - r.kmStart,
|
||||||
|
DAYNAME(r.created),
|
||||||
|
r.created,
|
||||||
|
SUM(t.packages),
|
||||||
|
v.numberPlate,
|
||||||
|
IF(ISNULL(`r`.`cost`), 'P', 'A'),
|
||||||
|
r.cost
|
||||||
|
FROM vn.route r
|
||||||
|
JOIN vn.ticket t ON t.routeFk = r.id
|
||||||
|
LEFT JOIN vn.zone z ON z.id = t.zoneFk
|
||||||
|
LEFT JOIN vn.agencyMode am ON am.id = r.agencyModeFk
|
||||||
|
LEFT JOIN vn.agency a ON a.id = am.agencyFk
|
||||||
|
LEFT JOIN vn.vehicle v ON v.id = r.vehicleFk
|
||||||
|
WHERE YEAR(r.created) = vYear AND MONTH(r.created) = vMonth
|
||||||
|
AND z.isVolumetric = FALSE
|
||||||
|
GROUP BY r.id
|
||||||
|
ON DUPLICATE KEY UPDATE Bultos = Bultos + VALUES(Bultos);
|
||||||
|
|
||||||
|
-- Coste REAL de cada bulto "virtual", de acuerdo con el valor apuntado a mano en la ruta
|
||||||
|
UPDATE bi.rutasBoard r
|
||||||
|
INNER JOIN vn2008.Rutas_Master rm ON rm.año = r.year AND rm.mes = r.month AND rm.warehouse_id = r.warehouse_id
|
||||||
|
SET r.coste_bulto = IF(r.Tipo ='A', r.Terceros, r.km * rm.coste_km ) / r.Bultos
|
||||||
|
WHERE r.Bultos > 0
|
||||||
|
AND rm.año = vYear
|
||||||
|
AND rm.mes = vMonth;
|
||||||
|
|
||||||
|
-- Coste PRACTICO de cada bulto, de acuerdo con los componentes de tipo AGENCIA en cada linea de venta
|
||||||
|
UPDATE bi.rutasBoard r
|
||||||
|
JOIN (
|
||||||
|
SELECT t.routeFk, sum(s.quantity * sc.value) practicoTotal
|
||||||
|
FROM vn.route r
|
||||||
|
JOIN vn.time tm ON tm.dated = r.created
|
||||||
|
JOIN vn.ticket t ON t.routeFk = r.id
|
||||||
|
JOIN vn.sale s ON s.ticketFk = t.id
|
||||||
|
JOIN vn.saleComponent sc ON sc.saleFk = s.id
|
||||||
|
JOIN vn.`component` c ON c.id = sc.componentFk
|
||||||
|
JOIN vn.componentType ct ON ct.id = c.typeFk
|
||||||
|
WHERE ct.type = 'agencia'
|
||||||
|
AND tm.year = vYear
|
||||||
|
AND tm.month = vMonth
|
||||||
|
GROUP BY r.id
|
||||||
|
) sub ON sub.routeFk = r.Id_Ruta
|
||||||
|
SET r.practico = sub.practicoTotal / r.Bultos;
|
||||||
|
|
||||||
|
-- Coste TEORICO de una caja "virtual" para cada ruta, teniendo en cuenta que hay carros, pallets, etc
|
||||||
|
UPDATE bi.rutasBoard r
|
||||||
|
JOIN (
|
||||||
|
SELECT t.routeFk,
|
||||||
|
SUM(t.zonePrice/ ebv.ratio)/ count(*) AS BultoTeoricoMedio
|
||||||
|
FROM vn.ticket t
|
||||||
|
JOIN vn.route r ON r.id = t.routeFk
|
||||||
|
JOIN vn.time tm ON tm.dated = r.created
|
||||||
|
JOIN vn.expedition e ON e.ticketFk = t.id
|
||||||
|
JOIN vn.expeditionBoxVol ebv ON ebv.boxFk = e.isBox
|
||||||
|
JOIN vn.address ad ON ad.id = t.addressFk
|
||||||
|
JOIN vn.client c ON c.id = ad.clientFk
|
||||||
|
LEFT JOIN vn.zone z ON z.id = t.zoneFk
|
||||||
|
WHERE tm.year = vYear
|
||||||
|
AND tm.month = vMonth
|
||||||
|
AND z.isVolumetric = FALSE
|
||||||
|
GROUP BY t.routeFk) sub ON r.Id_Ruta = sub.routeFk
|
||||||
|
SET r.teorico = sub.BultoTeoricoMedio;
|
||||||
|
|
||||||
|
-- Coste VOLUMETRICO TEORICO de una caja "virtual" para cada ruta
|
||||||
|
UPDATE bi.rutasBoard r
|
||||||
|
JOIN (
|
||||||
|
SELECT t.routeFk,
|
||||||
|
SUM(freight) AS BultoTeoricoMedio
|
||||||
|
FROM vn.ticket t
|
||||||
|
JOIN vn.route r ON r.id = t.routeFk
|
||||||
|
JOIN vn.time tm ON tm.dated = r.created
|
||||||
|
JOIN vn.saleVolume sf ON sf.ticketFk = t.id
|
||||||
|
JOIN vn.client c ON c.id = t.clientFk
|
||||||
|
JOIN vn.zone z ON z.id = t.zoneFk
|
||||||
|
WHERE tm.year = vYear
|
||||||
|
AND tm.month = vMonth
|
||||||
|
AND z.isVolumetric != FALSE
|
||||||
|
GROUP BY t.routeFk) sub ON r.Id_Ruta = sub.routeFk
|
||||||
|
SET r.teorico = sub.BultoTeoricoMedio / r.Bultos;
|
||||||
|
|
||||||
|
-- La diferencia entre el teorico y el practico se deberia de cobrar en greuges, cada noche
|
||||||
|
UPDATE bi.rutasBoard r
|
||||||
|
JOIN (
|
||||||
|
SELECT t.routeFk,
|
||||||
|
Sum(g.amount) AS greuge
|
||||||
|
FROM vn.ticket t
|
||||||
|
JOIN vn.route r ON r.id = t.routeFk
|
||||||
|
JOIN vn.time tm ON tm.dated = r.created
|
||||||
|
JOIN vn.greuge g ON g.ticketFk = t.id
|
||||||
|
JOIN vn.greugeType gt ON gt.id = g.greugeTypeFk
|
||||||
|
WHERE tm.year = vYear
|
||||||
|
AND tm.month = vMonth
|
||||||
|
AND gt.name = 'Diferencia portes'
|
||||||
|
GROUP BY t.routeFk) sub ON r.Id_Ruta = sub.routeFk
|
||||||
|
SET r.greuge = sub.greuge / r.Bultos;
|
||||||
|
|
||||||
|
END$$
|
||||||
|
|
||||||
|
DELIMITER ;
|
||||||
|
|
|
@ -0,0 +1,26 @@
|
||||||
|
USE `vn`;
|
||||||
|
CREATE
|
||||||
|
OR REPLACE ALGORITHM = UNDEFINED
|
||||||
|
DEFINER = `root`@`%`
|
||||||
|
SQL SECURITY DEFINER
|
||||||
|
VIEW `saleVolume` AS
|
||||||
|
SELECT
|
||||||
|
`s`.`ticketFk` AS `ticketFk`,
|
||||||
|
`s`.`id` AS `saleFk`,
|
||||||
|
IFNULL(ROUND(((((`i`.`compression` * (GREATEST(`i`.`density`, 167) / 167)) * `ic`.`cm3`) * `s`.`quantity`) / 1000),
|
||||||
|
2),
|
||||||
|
0) AS `litros`,
|
||||||
|
`t`.`routeFk` AS `routeFk`,
|
||||||
|
`t`.`shipped` AS `shipped`,
|
||||||
|
(((`s`.`quantity` * `ic`.`cm3`) * `i`.`compression`) / 1000000) AS `volume`,
|
||||||
|
((((`s`.`quantity` * `ic`.`cm3`) * `i`.`compression`) * (GREATEST(`i`.`density`, 167) / 167)) / 1000000) AS `physicalWeight`,
|
||||||
|
(((`s`.`quantity` * `ic`.`cm3`) * `i`.`density`) / 1000000) AS `weight`,
|
||||||
|
(((`s`.`quantity` * `ic`.`cm3`) * `i`.`compression`) / 1000000) AS `physicalVolume`,
|
||||||
|
((((`s`.`quantity` * `ic`.`cm3`) * `t`.`zonePrice`) * `i`.`compression`) / `cb`.`volume`) AS `freight`
|
||||||
|
FROM
|
||||||
|
((((`sale` `s`
|
||||||
|
JOIN `item` `i` ON ((`i`.`id` = `s`.`itemFk`)))
|
||||||
|
JOIN `ticket` `t` ON ((`t`.`id` = `s`.`ticketFk`)))
|
||||||
|
JOIN `packaging` `cb` ON ((`cb`.`id` = '94')))
|
||||||
|
JOIN `itemCost` `ic` ON (((`ic`.`itemFk` = `s`.`itemFk`)
|
||||||
|
AND (`ic`.`warehouseFk` = `t`.`warehouseFk`))));
|
|
@ -0,0 +1,24 @@
|
||||||
|
DROP VIEW IF EXISTS `vn`.`saleFreight` ;
|
||||||
|
USE `vn`;
|
||||||
|
CREATE
|
||||||
|
OR REPLACE ALGORITHM = UNDEFINED
|
||||||
|
DEFINER = `root`@`%`
|
||||||
|
SQL SECURITY DEFINER
|
||||||
|
VIEW `saleFreight__` AS
|
||||||
|
SELECT
|
||||||
|
`s`.`ticketFk` AS `ticketFk`,
|
||||||
|
`t`.`clientFk` AS `clientFk`,
|
||||||
|
`t`.`routeFk` AS `routeFk`,
|
||||||
|
`s`.`id` AS `saleFk`,
|
||||||
|
`t`.`zoneFk` AS `zoneFk`,
|
||||||
|
`t`.`companyFk` AS `companyFk`,
|
||||||
|
`t`.`shipped` AS `shipped`,
|
||||||
|
`t`.`zonePrice` AS `price`,
|
||||||
|
((((`s`.`quantity` * `r`.`cm3`) * `t`.`zonePrice`) * `i`.`compression`) / `cb`.`volume`) AS `freight`
|
||||||
|
FROM
|
||||||
|
((((`vn`.`sale` `s`
|
||||||
|
JOIN `vn`.`item` `i` ON ((`i`.`id` = `s`.`itemFk`)))
|
||||||
|
JOIN `vn`.`ticket` `t` ON ((`t`.`id` = `s`.`ticketFk`)))
|
||||||
|
JOIN `vn`.`packaging` `cb` ON ((`cb`.`id` = '94')))
|
||||||
|
JOIN `bi`.`rotacion` `r` ON (((`r`.`Id_Article` = `s`.`itemFk`)
|
||||||
|
AND (`r`.`warehouse_id` = `t`.`warehouseFk`))));
|
|
@ -0,0 +1,41 @@
|
||||||
|
USE `vn`;
|
||||||
|
DROP procedure IF EXISTS `zone_getShippedWarehouse`;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
USE `vn`$$
|
||||||
|
CREATE DEFINER=`root`@`%` PROCEDURE `zone_getShippedWarehouse`(vLanded DATE, vAddressFk INT, vAgencyModeFk INT)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Devuelve la mÃnima fecha de envÃo para cada warehouse
|
||||||
|
*
|
||||||
|
* @param vLanded La fecha de recepcion
|
||||||
|
* @param vAddressFk Id del consignatario
|
||||||
|
* @param vAgencyModeFk Id de la agencia
|
||||||
|
* @return tmp.zoneGetShipped
|
||||||
|
*/
|
||||||
|
|
||||||
|
CALL zone_getFromGeo(address_getGeo(vAddressFk));
|
||||||
|
CALL zone_getOptionsForLanding(vLanded,TRUE);
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE IF EXISTS tmp.zoneGetShipped;
|
||||||
|
CREATE TEMPORARY TABLE tmp.zoneGetShipped
|
||||||
|
ENGINE = MEMORY
|
||||||
|
SELECT * FROM (
|
||||||
|
SELECT zo.zoneFk,
|
||||||
|
TIMESTAMPADD(DAY,-zo.travelingDays, vLanded) shipped,
|
||||||
|
zo.`hour`,
|
||||||
|
zw.warehouseFk,
|
||||||
|
z.agencyModeFk
|
||||||
|
FROM tmp.zoneOption zo
|
||||||
|
JOIN zoneWarehouse zw ON zw.zoneFk = zo.zoneFk
|
||||||
|
JOIN zone z ON z.id = zo.zoneFk
|
||||||
|
WHERE z.agencyModeFk = vAgencyModeFk
|
||||||
|
ORDER BY shipped) t
|
||||||
|
GROUP BY warehouseFk;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE
|
||||||
|
tmp.zone,
|
||||||
|
tmp.zoneOption;
|
||||||
|
END$$
|
||||||
|
|
||||||
|
DELIMITER ;
|
|
@ -0,0 +1,42 @@
|
||||||
|
USE `vn`;
|
||||||
|
DROP procedure IF EXISTS `zone_getAgency`;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
USE `vn`$$
|
||||||
|
CREATE DEFINER=`root`@`%` PROCEDURE `zone_getAgency`(vAddress INT, vLanded DATE)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Devuelve el listado de agencias disponibles para la fecha
|
||||||
|
* y dirección pasadas.
|
||||||
|
*
|
||||||
|
* @param vAddress Id de dirección de envío, %NULL si es recogida
|
||||||
|
* @param vLanded Fecha de recogida
|
||||||
|
* @select Listado de agencias disponibles
|
||||||
|
*/
|
||||||
|
|
||||||
|
CALL zone_getFromGeo(address_getGeo(vAddress));
|
||||||
|
CALL zone_getOptionsForLanding(vLanded, FALSE);
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE IF EXISTS tmp.zoneGetAgency;
|
||||||
|
CREATE TEMPORARY TABLE tmp.zoneGetAgency
|
||||||
|
(INDEX (agencyModeFk)) ENGINE = MEMORY
|
||||||
|
SELECT am.name agencyMode,
|
||||||
|
am.description,
|
||||||
|
z.agencyModeFk,
|
||||||
|
am.deliveryMethodFk,
|
||||||
|
TIMESTAMPADD(DAY,-zo.travelingDays, vLanded) shipped,
|
||||||
|
TRUE isIncluded,
|
||||||
|
zo.zoneFk
|
||||||
|
FROM tmp.zoneOption zo
|
||||||
|
JOIN zone z ON z.id = zo.zoneFk
|
||||||
|
JOIN agencyMode am ON am.id = z.agencyModeFk
|
||||||
|
GROUP BY agencyModeFk;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE
|
||||||
|
tmp.zone,
|
||||||
|
tmp.zoneOption;
|
||||||
|
|
||||||
|
END$$
|
||||||
|
|
||||||
|
DELIMITER ;
|
||||||
|
|
|
@ -0,0 +1,18 @@
|
||||||
|
USE `vn`;
|
||||||
|
DROP procedure IF EXISTS `zone_getAvailable`;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
USE `vn`$$
|
||||||
|
CREATE DEFINER=`root`@`%` PROCEDURE `zone_getAvailable`(vAddress INT, vLanded DATE)
|
||||||
|
BEGIN
|
||||||
|
CALL zone_getFromGeo(address_getGeo(vAddress));
|
||||||
|
CALL zone_getOptionsForLanding(vLanded, FALSE);
|
||||||
|
|
||||||
|
SELECT * FROM tmp.zoneOption;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE
|
||||||
|
tmp.zone,
|
||||||
|
tmp.zoneOption;
|
||||||
|
END$$
|
||||||
|
|
||||||
|
DELIMITER ;
|
|
@ -0,0 +1,41 @@
|
||||||
|
USE `vn`;
|
||||||
|
DROP procedure IF EXISTS `zone_getWarehouse`;
|
||||||
|
|
||||||
|
DELIMITER $$
|
||||||
|
USE `vn`$$
|
||||||
|
CREATE DEFINER=`root`@`%` PROCEDURE `zone_getWarehouse`(vAddress INT, vLanded DATE, vWarehouse INT)
|
||||||
|
BEGIN
|
||||||
|
/**
|
||||||
|
* Devuelve el listado de agencias disponibles para la fecha,
|
||||||
|
* dirección y almacén pasados.
|
||||||
|
*
|
||||||
|
* @param vAddress
|
||||||
|
* @param vWarehouse warehouse
|
||||||
|
* @param vLanded Fecha de recogida
|
||||||
|
* @select Listado de agencias disponibles
|
||||||
|
*/
|
||||||
|
|
||||||
|
CALL zone_getFromGeo(address_getGeo(vAddress));
|
||||||
|
CALL zone_getOptionsForLanding(vLanded, FALSE);
|
||||||
|
|
||||||
|
SELECT am.id agencyModeFk,
|
||||||
|
am.name agencyMode,
|
||||||
|
am.description,
|
||||||
|
am.deliveryMethodFk,
|
||||||
|
TIMESTAMPADD(DAY, -zo.travelingDays, vLanded) shipped,
|
||||||
|
zw.warehouseFk,
|
||||||
|
z.id zoneFk
|
||||||
|
FROM tmp.zoneOption zo
|
||||||
|
JOIN zone z ON z.id = zo.zoneFk
|
||||||
|
JOIN agencyMode am ON am.id = z.agencyModeFk
|
||||||
|
JOIN zoneWarehouse zw ON zw.zoneFk = zo.zoneFk
|
||||||
|
WHERE zw.warehouseFk
|
||||||
|
GROUP BY z.agencyModeFk
|
||||||
|
ORDER BY agencyMode;
|
||||||
|
|
||||||
|
DROP TEMPORARY TABLE
|
||||||
|
tmp.zone,
|
||||||
|
tmp.zoneOption;
|
||||||
|
END$$
|
||||||
|
|
||||||
|
DELIMITER ;
|
Loading…
Reference in New Issue