DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`rutasAnalyze`( vDatedFrom INT, vDatedTo INT ) BEGIN /** * Analiza los costes de las rutas de reparto * y lo almacena en la tabla bi.rutasBoard */ DELETE FROM rutasBoard WHERE Fecha BETWEEN vDatedFrom AND vDatedTo; -- Rellenamos la tabla con los datos de las rutas VOLUMETRICAS, especialmente con los bultos "virtuales" INSERT INTO rutasBoard( Id_Ruta, Id_Agencia, Fecha, bultos) SELECT r.id, r.agencyModeFk, r.created, SUM(sv.volume / ebv.m3) FROM vn.route r JOIN vn.ticket t ON t.routeFk = r.id LEFT JOIN vn.`zone` z ON z.id = t.zoneFk JOIN vn.saleVolume sv ON sv.ticketFk = t.id JOIN vn.expeditionBoxVol ebv ON ebv.code = 'transportBox' WHERE r.created BETWEEN vDatedFrom AND vDatedTo 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 rutasBoard( Id_Ruta, Id_Agencia, Fecha, Bultos) SELECT r.id, r.agencyModeFk, r.created, SUM(t.packages) FROM vn.route r JOIN vn.ticket t ON t.routeFk = r.id LEFT JOIN vn.`zone` z ON z.id = t.zoneFk WHERE r.created BETWEEN vDatedFrom AND vDatedTo AND NOT z.isVolumetric GROUP BY r.id ON DUPLICATE KEY UPDATE Bultos = Bultos + VALUES(Bultos); -- Coste PRACTICO de cada bulto, de acuerdo con los componentes de tipo AGENCIA en cada linea de venta UPDATE rutasBoard r JOIN ( SELECT t.routeFk, SUM(s.quantity * sc.value) totalPractice FROM vn.route r 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.code = 'FREIGHT' AND r.created BETWEEN vDatedFrom AND vDatedTo GROUP BY r.id ) sub ON sub.routeFk = r.Id_Ruta SET r.practico = IFNULL(sub.totalPractice / r.Bultos, 0); -- Coste TEORICO de una caja "virtual" para cada ruta, teniendo en cuenta que hay carros, pallets, etc UPDATE rutasBoard r JOIN ( SELECT t.routeFk, SUM(t.zonePrice/ ebv.ratio) / COUNT(*) averageTheoreticalVolume FROM vn.ticket t JOIN vn.route r ON r.id = t.routeFk JOIN vn.expedition e ON e.ticketFk = t.id JOIN vn.expeditionBoxVol ebv ON ebv.boxFk = e.freightItemFk 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 r.created BETWEEN vDatedFrom AND vDatedTo AND NOT z.isVolumetric GROUP BY t.routeFk ) sub ON r.Id_Ruta = sub.routeFk SET r.teorico = IFNULL(sub.averageTheoreticalVolume, 0); -- Coste VOLUMETRICO TEORICO de una caja "virtual" para cada ruta UPDATE rutasBoard r JOIN ( SELECT t.routeFk, SUM(freight) averageTheoreticalVolume FROM vn.ticket t JOIN vn.route r ON r.id = t.routeFk 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 r.created BETWEEN vDatedFrom AND vDatedTo AND z.isVolumetric GROUP BY t.routeFk ) sub ON r.Id_Ruta = sub.routeFk SET r.teorico = IFNULL(sub.averageTheoreticalVolume / r.Bultos, 0); -- La diferencia entre el teorico y el practico se deberia de cobrar en greuges, cada noche UPDATE rutasBoard r JOIN ( SELECT t.routeFk, SUM(g.amount) greuge FROM vn.ticket t JOIN vn.route r ON r.id = t.routeFk JOIN vn.greuge g ON g.ticketFk = t.id JOIN vn.greugeType gt ON gt.id = g.greugeTypeFk WHERE r.created BETWEEN vDatedFrom AND vDatedTo AND gt.code = 'freightDifference' GROUP BY t.routeFk ) sub ON r.Id_Ruta = sub.routeFk SET r.greuge = sub.greuge / r.Bultos; END$$ DELIMITER ;