From 87799fbc64451bef6cc95847b7e1efefdfd7dc86 Mon Sep 17 00:00:00 2001 From: robert Date: Fri, 1 Mar 2024 12:30:37 +0100 Subject: [PATCH] fix: rutasAnalyzeHotFix --- db/routines/bi/procedures/rutasAnalyze.sql | 37 +++++++++---------- .../bi/procedures/rutasAnalyze_launcher.sql | 2 +- 2 files changed, 19 insertions(+), 20 deletions(-) diff --git a/db/routines/bi/procedures/rutasAnalyze.sql b/db/routines/bi/procedures/rutasAnalyze.sql index 8b56fa74d..b68a67aa5 100644 --- a/db/routines/bi/procedures/rutasAnalyze.sql +++ b/db/routines/bi/procedures/rutasAnalyze.sql @@ -1,7 +1,7 @@ DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`rutasAnalyze`( - vYear INT, - vMonth INT + vdatedFrom INT, + vdatedTo INT ) BEGIN /** @@ -9,8 +9,16 @@ BEGIN * y lo almacena en la tabla bi.rutasBoard */ DELETE FROM rutasBoard - WHERE YEAR(Fecha) = vYear - AND MONTH(Fecha) = vMonth; + WHERE Fecha BETWEEN vdatedFrom AND vdatedTo; + + DELETE rb.* + FROM rutasBoard rb + JOIN vn.route r ON r.id = rb.Id_Ruta + JOIN vn.ticket t ON t.routeFk = r.id + LEFT JOIN vn.`zone` z ON z.id = t.zoneFk + JOIN vn.expeditionBoxVol ebv ON ebv.code = 'transportBox' + WHERE r.created BETWEEN vdatedFrom AND vdatedTo + AND z.isVolumetric; -- Rellenamos la tabla con los datos de las rutas VOLUMETRICAS, especialmente con los bultos "virtuales" INSERT INTO rutasBoard( @@ -27,7 +35,7 @@ BEGIN 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 YEAR(r.created) = vYear AND MONTH(r.created) = vMonth + WHERE r.created BETWEEN vdatedFrom AND vdatedTo AND z.isVolumetric GROUP BY r.id; @@ -44,8 +52,7 @@ BEGIN FROM vn.route r JOIN vn.ticket t ON t.routeFk = r.id LEFT JOIN vn.`zone` z ON z.id = t.zoneFk - WHERE YEAR(r.created) = vYear - AND MONTH(r.created) = vMonth + WHERE r.created BETWEEN vdatedFrom AND vdatedTo AND NOT z.isVolumetric GROUP BY r.id ON DUPLICATE KEY UPDATE Bultos = Bultos + VALUES(Bultos); @@ -56,15 +63,13 @@ BEGIN SELECT t.routeFk, SUM(s.quantity * sc.value) totalPractice 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.code = 'FREIGHT' - AND tm.`year` = vYear - AND tm.`month` = vMonth + 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); @@ -76,14 +81,12 @@ BEGIN SUM(t.zonePrice/ ebv.ratio) / COUNT(*) averageTheoreticalVolume 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.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 tm.`year` = vYear - AND tm.`month` = vMonth + WHERE r.created BETWEEN vdatedFrom AND vdatedTo AND NOT z.isVolumetric GROUP BY t.routeFk ) sub ON r.Id_Ruta = sub.routeFk @@ -96,12 +99,10 @@ BEGIN SUM(freight) averageTheoreticalVolume 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 + WHERE r.created BETWEEN vdatedFrom AND vdatedTo AND z.isVolumetric GROUP BY t.routeFk ) sub ON r.Id_Ruta = sub.routeFk @@ -114,11 +115,9 @@ BEGIN SUM(g.amount) 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 + WHERE r.created BETWEEN vdatedFrom AND vdatedTo AND gt.code = 'freightDifference' GROUP BY t.routeFk ) sub ON r.Id_Ruta = sub.routeFk diff --git a/db/routines/bi/procedures/rutasAnalyze_launcher.sql b/db/routines/bi/procedures/rutasAnalyze_launcher.sql index bc50b7905..02f5e1b9c 100644 --- a/db/routines/bi/procedures/rutasAnalyze_launcher.sql +++ b/db/routines/bi/procedures/rutasAnalyze_launcher.sql @@ -4,6 +4,6 @@ BEGIN /** * Call rutasAnalyze */ - CALL rutasAnalyze(YEAR(util.VN_CURDATE()), MONTH(util.VN_CURDATE())); + CALL rutasAnalyze(util.VN_CURDATE() - INTERVAL 30 DAY , util.VN_CURDATE()); END$$ DELIMITER ;