172 lines
5.6 KiB
MySQL
172 lines
5.6 KiB
MySQL
|
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 ;
|
||
|
|