salix/db/routines/vn/procedures/routeMonitor_calculate.sql

115 lines
3.4 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`routeMonitor_calculate`(
vDate DATE,
vDaysAgo INT
)
BEGIN
DECLARE vDateEnd DATETIME;
SET vDate = vDate - INTERVAL vDaysAgo DAY;
SET vDateEnd = util.dayend(vDate);
CREATE OR REPLACE TEMPORARY TABLE tmp.routesMonitor
(INDEX (routeFk))
ENGINE = MEMORY
SELECT DISTINCT(t.routeFk) routeFk
FROM vn.ticket t
WHERE t.shipped BETWEEN vDate AND vDateEnd
AND t.routeFk IS NOT NULL;
INSERT IGNORE INTO routesMonitor(routeFk)
SELECT routeFk
FROM tmp.routesMonitor;
UPDATE routesMonitor rm
JOIN route r ON r.id = rm.routeFk
JOIN agencyMode a ON a.id = r.agencyModeFk
SET rm.`name` = a.name,
rm.ticketFree = 0,
rm.ticketProduction = 0,
rm.ticketPacked = 0,
rm.dated = r.created;
UPDATE routesMonitor rm
JOIN (
SELECT t.routeFk, COUNT(*) AS ticketFree
FROM vn.ticket t
JOIN tmp.routesMonitor rm ON rm.routeFk = t.routeFk
JOIN ticketLastState ts ON t.id = ts.ticketFk
JOIN ticketTracking tt ON tt.id = ts.ticketTrackingFk
JOIN state s ON s.id = tt.stateFk
JOIN vn.alertLevel al ON al.id = s.alertLevel
AND al.code = "FREE"
GROUP BY t.routeFk
) sub ON sub.routeFk = rm.routeFk
SET rm.ticketFree = sub.ticketFree;
UPDATE routesMonitor rm
JOIN(
SELECT t.routeFk, COUNT(*) AS ticketPacked
FROM vn.ticket t
JOIN tmp.routesMonitor rm ON rm.routeFk = t.routeFk
JOIN ticketLastState ts ON t.id = ts.ticketFk
JOIN ticketTracking tt ON tt.id = ts.ticketTrackingFk
JOIN state s ON s.id = tt.stateFk
JOIN vn.alertLevel al ON al.id = s.alertLevel
AND al.code = "PACKED"
GROUP BY t.routeFk
) sub ON sub.routeFk = rm.routeFk
SET rm.ticketPacked = sub.ticketPacked;
UPDATE routesMonitor rm
JOIN(
SELECT t.routeFk, COUNT(*) AS ticketProduction
FROM vn.ticket t
JOIN tmp.routesMonitor rm ON rm.routeFk = t.routeFk
JOIN ticketLastState ts ON t.id = ts.ticketFk
JOIN ticketTracking tt ON tt.id = ts.ticketTrackingFk
JOIN state s ON s.id = tt.stateFk
JOIN vn.alertLevel al ON al.id = s.alertLevel
AND al.code = "DELIVERED"
GROUP BY t.routeFk
) sub ON sub.routeFk = rm.routeFk
SET rm.ticketProduction = sub.ticketProduction;
UPDATE routesMonitor rm
JOIN (
SELECT t.routeFk, COUNT(*) packages
FROM vn.ticket t
JOIN tmp.routesMonitor rm ON rm.routeFk = t.routeFk
JOIN expedition e ON e.ticketFk = t.id
GROUP BY t.routeFk
) sub ON sub.routeFk = rm.routeFk
SET rm.packages = sub.packages;
UPDATE routesMonitor rm
JOIN( SELECT t.routeFk, SUM(sv.volume) m3
FROM vn.ticket t
JOIN tmp.routesMonitor rm ON rm.routeFk = t.routeFk
JOIN vn.saleVolume sv ON sv.ticketFk = t.id
GROUP BY t.routeFk
) sub ON sub.routeFk = rm.routeFk
SET rm.m3 = sub.m3;
UPDATE routesMonitor rm
JOIN (
SELECT t.routeFk,
SUM(IFNULL(pk.volume,
pk.width * pk.height * pk.`depth`
)
) / 1000000 m3boxes
FROM vn.ticket t
JOIN tmp.routesMonitor rm ON rm.routeFk = t.routeFk
JOIN vn.expedition e ON e.ticketFk = t.id
JOIN vn.packaging pk ON pk.id = e.packagingFk
GROUP BY t.routeFk
) sub ON sub.routeFk = rm.routeFk
SET rm.m3boxes = sub.m3boxes;
UPDATE routesMonitor rm
JOIN vn.roadmapStop rs ON rs.id = rm.roadmapStopFk
SET rm.etd = rs.eta;
DROP TEMPORARY TABLE tmp.routesMonitor;
END$$
DELIMITER ;