DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`greuge_dif_porte_add`() BEGIN /** * Calculates the greuge based on a specific date in the 'grievanceConfig' table */ DECLARE vDateStarted DATETIME; DECLARE vDateEnded DATETIME DEFAULT (util.VN_CURDATE() - INTERVAL 1 DAY); DECLARE vDaysAgoOffset INT; SELECT daysAgoOffset INTO vDaysAgoOffset FROM vn.greugeConfig; SET vDateStarted = util.VN_CURDATE() - INTERVAL vDaysAgoOffset DAY; DROP TEMPORARY TABLE IF EXISTS tmp.dp; -- Agencias que no cobran por volumen CREATE TEMPORARY TABLE tmp.dp (PRIMARY KEY (ticketFk)) ENGINE = MEMORY SELECT t.id ticketFk, SUM((t.zonePrice - t.zoneBonus) * ebv.ratio) teorico, 00000.00 practico, 00000.00 greuge, t.clientFk, t.shipped FROM vn.ticket t JOIN vn.client c ON c.id = t.clientFk LEFT JOIN vn.expedition e ON e.ticketFk = t.id JOIN vn.expeditionBoxVol ebv ON ebv.boxFk = e.freightItemFk JOIN vn.zone z ON t.zoneFk = z.id JOIN vn.company cp ON cp.id = t.companyFk WHERE t.shipped BETWEEN vDateStarted AND vDateEnded AND c.isRelevant AND cp.code IN ('VNL', 'VNH') AND NOT z.isVolumetric GROUP BY t.id; -- Agencias que cobran por volumen INSERT INTO tmp.dp SELECT sv.ticketFk, SUM(IFNULL(sv.freight,0)) teorico, 00000.00 practico, 00000.00 greuge, sv.clientFk, sv.shipped FROM vn.saleVolume sv JOIN vn.zone z ON z.id = sv.zoneFk AND sv.shipped BETWEEN vDateStarted AND vDateEnded AND z.isVolumetric != FALSE GROUP BY sv.ticketFk; DROP TEMPORARY TABLE IF EXISTS tmp.dp_aux; CREATE TEMPORARY TABLE tmp.dp_aux (PRIMARY KEY (ticketFk)) ENGINE = MEMORY SELECT dp.ticketFk, SUM(s.quantity * sc.value) valor FROM tmp.dp JOIN vn.sale s ON s.ticketFk = dp.ticketFk JOIN vn.saleComponent sc ON sc.saleFk = s.id JOIN vn.component c ON c.id = sc.componentFk WHERE c.code = 'delivery' GROUP BY dp.ticketFk; UPDATE tmp.dp JOIN tmp.dp_aux USING(ticketFk) SET practico = IFNULL(valor,0); DROP TEMPORARY TABLE tmp.dp_aux; CREATE TEMPORARY TABLE tmp.dp_aux (PRIMARY KEY (ticketFk)) ENGINE = MEMORY SELECT dp.ticketFk, SUM(g.amount) Importe FROM tmp.dp JOIN vn.greuge g ON g.ticketFk = dp.ticketFk JOIN vn.greugeType gt ON gt.id = g.greugeTypeFk WHERE gt.code = 'freightDifference' -- dif_porte GROUP BY dp.ticketFk; UPDATE tmp.dp JOIN tmp.dp_aux USING(ticketFk) SET greuge = IFNULL(Importe,0); INSERT INTO vn.greuge (clientFk,description,amount,shipped,greugeTypeFk,ticketFk) SELECT dp.clientFk, CONCAT('dif_porte ', dp.ticketFk), ROUND(IFNULL(dp.teorico,0) - IFNULL(dp.practico,0) - IFNULL(dp.greuge,0),2) Importe, date(dp.shipped), 1, dp.ticketFk FROM tmp.dp JOIN vn.client c ON c.id = dp.clientFk WHERE ABS(IFNULL(dp.teorico,0) - IFNULL(dp.practico,0) - IFNULL(dp.greuge,0)) > 1 AND c.isRelevant; DROP TEMPORARY TABLE tmp.dp, tmp.dp_aux; END$$ DELIMITER ;