From 712bfe73680a149bb6b292a18ef99a058db66616 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Carlos=20Andr=C3=A9s?= Date: Thu, 19 Sep 2024 20:15:38 +0200 Subject: [PATCH] fix: refs #7965 UnifyProblems --- .../vn/procedures/productionControl.sql | 61 +++--- .../vn/procedures/sale_getProblems.sql | 168 +++++++++++++++++ .../procedures/sale_getProblemsByTicket.sql | 19 +- .../vn/procedures/ticket_getProblems.sql | 177 ++---------------- 4 files changed, 226 insertions(+), 199 deletions(-) create mode 100644 db/routines/vn/procedures/sale_getProblems.sql diff --git a/db/routines/vn/procedures/productionControl.sql b/db/routines/vn/procedures/productionControl.sql index b33224e80c..294ac3486f 100644 --- a/db/routines/vn/procedures/productionControl.sql +++ b/db/routines/vn/procedures/productionControl.sql @@ -36,6 +36,19 @@ proc: BEGIN CREATE OR REPLACE TEMPORARY TABLE tmp.productionBuffer (PRIMARY KEY(ticketFk), previaParking VARCHAR(255)) ENGINE = MEMORY + WITH saleProblemsDescription AS( + SELECT s.ticketFk, + LEFT(CONCAT('F: ', GROUP_CONCAT(CONCAT(i.id, ' ', i.longName) SEPARATOR ', ')), 250) itemShortage, + LEFT(CONCAT('R: ', GROUP_CONCAT(CONCAT(i2.id, ' ', i2.longName) SEPARATOR ', ')), 250) itemDelay, + LEFT(CONCAT('I: ', GROUP_CONCAT(CONCAT(i3.id, ' ', i3.longName) SEPARATOR ', ')), 250) itemLost + FROM tmp.saleProblems sp + JOIN vn.sale s ON s.id = sp.saleFk + LEFT JOIN vn.item i ON i.id = s.itemFk AND sp.hasItemShortage + LEFT JOIN vn.item i2 ON i2.id = s.itemFk AND sp.hasItemDelay + LEFT JOIN vn.item i3 ON i3.id = s.itemFk AND sp.hasItemLost + WHERE hasItemShortage OR hasItemDelay OR hasItemLost + GROUP BY s.ticketFk + ) SELECT tt.ticketFk, t.clientFk, t.warehouseFk, @@ -55,9 +68,9 @@ proc: BEGIN 0 `lines`, CAST( 0 AS DECIMAL(5,2)) m3, CAST( 0 AS DECIMAL(5,2)) preparationRate, - TRIM(CAST(CONCAT( IFNULL(tpr.itemShortage, ''), - IFNULL(tpr.itemDelay, ''), - IFNULL(tpr.itemLost, ''), + TRIM(CAST(CONCAT( IFNULL(sp.itemShortage, ''), + IFNULL(sp.itemDelay, ''), + IFNULL(sp.itemLost, ''), IF(tpr.isFreezed, ' CONGELADO',''), IF(tpr.hasHighRisk, ' RIESGO',''), IF(tpr.hasTicketRequest, ' COD 100',''), @@ -85,30 +98,31 @@ proc: BEGIN ag.isOwn, rm.bufferFk FROM tmp.productionTicket tt - JOIN ticket t ON tt.ticketFk = t.id - JOIN alertLevel al ON al.code = 'FREE' - LEFT JOIN ticketStateToday tst ON tst.ticketFk = t.id - LEFT JOIN `state` st ON st.id = tst.state - LEFT JOIN client c ON c.id = t.clientFk - LEFT JOIN worker wk ON wk.id = c.salesPersonFk - JOIN address a ON a.id = t.addressFk - LEFT JOIN province p ON p.id = a.provinceFk - JOIN agencyMode am ON am.id = t.agencyModeFk - JOIN deliveryMethod dm ON dm.id = am.deliveryMethodFk - JOIN agency ag ON ag.id = am.agencyFk - LEFT JOIN ticketState tls ON tls.ticketFk = tt.ticketFk - LEFT JOIN ticketLastUpdated tlu ON tlu.ticketFk = tt.ticketFk - LEFT JOIN worker w ON w.id = tls.userFk - LEFT JOIN routesMonitor rm ON rm.routeFk = t.routeFk - LEFT JOIN `zone` z ON z.id = t.zoneFk - LEFT JOIN zoneClosure zc ON zc.zoneFk = t.zoneFk + JOIN vn.ticket t ON tt.ticketFk = t.id + JOIN vn.alertLevel al ON al.code = 'FREE' + LEFT JOIN vn.ticketStateToday tst ON tst.ticketFk = t.id + LEFT JOIN vn.`state` st ON st.id = tst.state + LEFT JOIN vn.client c ON c.id = t.clientFk + LEFT JOIN vn.worker wk ON wk.id = c.salesPersonFk + JOIN vn.address a ON a.id = t.addressFk + LEFT JOIN vn.province p ON p.id = a.provinceFk + JOIN vn.agencyMode am ON am.id = t.agencyModeFk + JOIN vn.deliveryMethod dm ON dm.id = am.deliveryMethodFk + JOIN vn.agency ag ON ag.id = am.agencyFk + LEFT JOIN vn.ticketState tls ON tls.ticketFk = tt.ticketFk + LEFT JOIN vn.ticketLastUpdated tlu ON tlu.ticketFk = tt.ticketFk + LEFT JOIN vn.worker w ON w.id = tls.userFk + LEFT JOIN vn.routesMonitor rm ON rm.routeFk = t.routeFk + LEFT JOIN vn.`zone` z ON z.id = t.zoneFk + LEFT JOIN vn.zoneClosure zc ON zc.zoneFk = t.zoneFk AND DATE(t.shipped) = zc.dated - LEFT JOIN ticketParking tp ON tp.ticketFk = t.id - LEFT JOIN parking pk ON pk.id = tp.parkingFk + LEFT JOIN vn.ticketParking tp ON tp.ticketFk = t.id + LEFT JOIN vn.parking pk ON pk.id = tp.parkingFk LEFT JOIN tmp.ticketProblems tpr ON tpr.ticketFk = tt.ticketFk + LEFT JOIN saleProblemsDescription sp ON sp.ticketFk = tt.ticketFk WHERE t.warehouseFk = vWarehouseFk AND dm.code IN ('AGENCY', 'DELIVERY', 'PICKUP'); - + UPDATE tmp.productionBuffer pb JOIN ( SELECT pb.ticketFk, GROUP_CONCAT(p.code) previaParking @@ -260,6 +274,7 @@ proc: BEGIN DROP TEMPORARY TABLE tmp.productionTicket, tmp.ticketProblems, + tmp.saleProblems, tmp.ticketWithPrevia, tItemShelvingStock, tItemPackingType; diff --git a/db/routines/vn/procedures/sale_getProblems.sql b/db/routines/vn/procedures/sale_getProblems.sql new file mode 100644 index 0000000000..a8388034f9 --- /dev/null +++ b/db/routines/vn/procedures/sale_getProblems.sql @@ -0,0 +1,168 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`sale_getProblems`( + vIsTodayRelative TINYINT(1) +) +BEGIN +/** + * Calcula los problemas para un conjunto de sale + * + * @table tmp.sale(saleFk) Identificadores de los sale a calcular + * @return tmp.saleProblems + */ + DECLARE vWarehouseFk INT; + DECLARE vDate DATE; + DECLARE vAvailableCache INT; + DECLARE vVisibleCache INT; + DECLARE vDone BOOL; + DECLARE vCursor CURSOR FOR + SELECT t.warehouseFk, IF(vIsTodayRelative, util.VN_CURDATE(), DATE(t.shipped)) dated + FROM tmp.sale ts + JOIN sale s ON s.id = ts.saleFk + JOIN ticket t ON t.id = s.ticketFk + WHERE t.shipped BETWEEN util.VN_CURDATE() + AND util.dayEnd(util.VN_CURDATE() + INTERVAL IF(vIsTodayRelative, 9.9, 1.9) DAY) + GROUP BY warehouseFk, dated; + + DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; + + CREATE OR REPLACE TEMPORARY TABLE tmp.saleProblems( + saleFk INT(11), + hasItemShortage BOOL DEFAULT FALSE, + hasItemLost BOOL DEFAULT FALSE, + hasItemDelay BOOL DEFAULT FALSE, + hasRounding BOOL DEFAULT FALSE, + PRIMARY KEY (saleFk) + ) ENGINE = MEMORY; + + CREATE OR REPLACE TEMPORARY TABLE tItemShelving + (INDEX (itemFk, warehouseFk)) + ENGINE = MEMORY + SELECT ish.itemFk itemFk, + SUM(ish.visible) visible, + s.warehouseFk warehouseFk + FROM itemShelving ish + JOIN shelving sh ON sh.code = ish.shelvingFk + JOIN parking p ON p.id = sh.parkingFk + JOIN sector s ON s.id = p.sectorFk + GROUP BY ish.itemFk, s.warehouseFk; + + -- Disponible, faltas, inventario y retrasos + OPEN vCursor; + l: LOOP + SET vDone = FALSE; + FETCH vCursor INTO vWarehouseFk, vDate; + + IF vDone THEN + LEAVE l; + END IF; + + -- Disponible: no va a haber suficiente producto para preparar todos los pedidos + CALL cache.available_refresh(vAvailableCache, FALSE, vWarehouseFk, vDate); + + -- Faltas: visible, disponible y ubicado son menores que la cantidad vendida + CALL cache.visible_refresh(vVisibleCache, FALSE, vWarehouseFk); + + INSERT INTO tmp.saleProblems(saleFk, hasItemShortage) + SELECT s.id, TRUE + FROM tmp.sale ts + JOIN sale s ON s.id = ts.saleFk + JOIN ticket t ON t.id = s.ticketFk + JOIN item i ON i.id = s.itemFk + JOIN itemType it ON it.id = i.typeFk + JOIN itemCategory ic ON ic.id = it.categoryFk + LEFT JOIN cache.visible v ON v.item_id = i.id + AND v.calc_id = vVisibleCache + LEFT JOIN cache.available av ON av.item_id = i.id + AND av.calc_id = vAvailableCache + LEFT JOIN tItemShelving tis ON tis.itemFk = i.id + AND tis.warehouseFk = t.warehouseFk + WHERE IFNULL(v.visible, 0) < s.quantity + AND IFNULL(av.available, 0) < s.quantity + AND IFNULL(tis.visible, 0) < s.quantity + AND NOT s.isPicked + AND NOT s.reserved + AND ic.merchandise + AND IF(vIsTodayRelative, TRUE, DATE(t.shipped) = vDate) + AND NOT i.generic + AND util.VN_CURDATE() = vDate + AND t.warehouseFk = vWarehouseFk + GROUP BY s.id; + + -- Inventario: Visible suficiente, pero ubicado menor a la cantidad vendida + INSERT INTO tmp.saleProblems(saleFk, hasItemLost) + SELECT s.id, TRUE + FROM tmp.sale ts + JOIN sale s ON s.id = ts.saleFk + JOIN ticket t ON t.id = s.ticketFk + JOIN item i ON i.id = s.itemFk + JOIN itemType it ON it.id = i.typeFk + JOIN itemCategory ic ON ic.id = it.categoryFk + LEFT JOIN cache.visible v ON v.item_id = s.itemFk + AND v.calc_id = vVisibleCache + LEFT JOIN tItemShelving tis ON tis.itemFk = i.id + AND tis.warehouseFk = t.warehouseFk + WHERE IFNULL(v.visible, 0) >= s.quantity + AND IFNULL(tis.visible, 0) < s.quantity + AND s.quantity > 0 + AND NOT s.isPicked + AND NOT s.reserved + AND ic.merchandise + AND IF(vIsTodayRelative, TRUE, DATE(t.shipped) = vDate) + AND NOT i.generic + AND util.VN_CURDATE() = vDate + AND t.warehouseFk = vWarehouseFk + GROUP BY s.id + ON DUPLICATE KEY UPDATE hasItemLost = TRUE; + + -- Retraso: Disponible suficiente, pero no visible ni ubicado + INSERT INTO tmp.saleProblems(saleFk, hasItemDelay) + SELECT s.id, TRUE + FROM tmp.sale ts + JOIN sale s ON s.id = ts.saleFk + JOIN ticket t ON t.id = s.ticketFk + JOIN item i ON i.id = s.itemFk + JOIN itemType it ON it.id = i.typeFk + JOIN itemCategory ic ON ic.id = it.categoryFk + LEFT JOIN cache.visible v ON v.item_id = s.itemFk + AND v.calc_id = vVisibleCache + LEFT JOIN cache.available av ON av.item_id = i.id + AND av.calc_id = vAvailableCache + LEFT JOIN tItemShelving tis ON tis.itemFk = i.id + AND tis.warehouseFk = t.warehouseFk + WHERE IFNULL(v.visible, 0) < s.quantity + AND IFNULL(av.available, 0) >= s.quantity + AND IFNULL(tis.visible, 0) < s.quantity + AND s.quantity > 0 + AND NOT s.isPicked + AND NOT s.reserved + AND ic.merchandise + AND IF(vIsTodayRelative, TRUE, DATE(t.shipped) = vDate) + AND NOT i.generic + AND util.VN_CURDATE() = vDate + AND t.warehouseFk = vWarehouseFk + GROUP BY s.id + ON DUPLICATE KEY UPDATE hasItemDelay = TRUE; + + -- Redondeo: cantidad incorrecta con respecto al grouping + CALL buy_getUltimate(NULL, vWarehouseFk, vDate); + + INSERT INTO tmp.saleProblems(saleFk, hasRounding) + SELECT s.id, TRUE + FROM tmp.sale ts + JOIN sale s ON s.id = ts.saleFk + JOIN ticket t ON t.id = s.ticketFk + AND t.warehouseFk = vWarehouseFk + JOIN item i ON i.id = s.itemFk + JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk + JOIN buy b ON b.id = bu.buyFk + WHERE MOD(s.quantity, b.`grouping`) + GROUP BY s.id + ON DUPLICATE KEY UPDATE hasRounding = TRUE; + + DROP TEMPORARY TABLE tmp.buyUltimate; + END LOOP; + CLOSE vCursor; + + DROP TEMPORARY TABLE tItemShelving, tmp.sale; +END$$ +DELIMITER ; diff --git a/db/routines/vn/procedures/sale_getProblemsByTicket.sql b/db/routines/vn/procedures/sale_getProblemsByTicket.sql index af69e84300..708938cba0 100644 --- a/db/routines/vn/procedures/sale_getProblemsByTicket.sql +++ b/db/routines/vn/procedures/sale_getProblemsByTicket.sql @@ -5,22 +5,19 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`sale_getProblemsByTic ) BEGIN /** - * Calcula los problemas de cada venta - * para un conjunto de tickets. + * Calcula los problemas de cada venta para un tickets. * * @return Problems result */ - CREATE OR REPLACE TEMPORARY TABLE tmp.ticket - (INDEX (ticketFk)) - ENGINE = MEMORY - SELECT vTicketFk ticketFk; + CREATE OR REPLACE TEMPORARY TABLE tmp.sale + (INDEX (saleFk)) + ENGINE = MEMORY + SELECT id saleFk FROM sale WHERE ticketFk = vTicketFk; - CALL ticket_getProblems(vIsTodayRelative); + CALL sale_getProblems(vIsTodayRelative); - SELECT * FROM tmp.saleProblems; + SELECT * FROM tmp.saleProblems; - DROP TEMPORARY TABLE - tmp.ticket, - tmp.ticketProblems; + DROP TEMPORARY TABLE tmp.saleProblems; END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/ticket_getProblems.sql b/db/routines/vn/procedures/ticket_getProblems.sql index f718893eb1..c5a1532ff7 100644 --- a/db/routines/vn/procedures/ticket_getProblems.sql +++ b/db/routines/vn/procedures/ticket_getProblems.sql @@ -5,163 +5,23 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`ticket_getProblems`( BEGIN /** * Calcula los problemas para un conjunto de tickets. - * Agrupados por ticket * * @table tmp.ticket(ticketFk) Identificadores de los tickets a calcular - * @return tmp.ticketProblems + * @return tmp.ticketProblems, tmp.saleProblems */ - DECLARE vWarehouseFk INT; - DECLARE vDate DATE; - DECLARE vAvailableCache INT; - DECLARE vVisibleCache INT; - DECLARE vDone BOOL; - DECLARE vCursor CURSOR FOR - SELECT DISTINCT t.warehouseFk, IF(vIsTodayRelative, util.VN_CURDATE(), DATE(t.shipped)) - FROM tmp.ticket t - JOIN ticket t ON t.id = t.ticketFk - WHERE t.shipped BETWEEN util.VN_CURDATE() - AND util.dayEnd(util.VN_CURDATE() + INTERVAL IF(vIsTodayRelative, 9.9, 1.9) DAY); - - DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; - - CREATE OR REPLACE TEMPORARY TABLE tmp.saleProblems( - ticketFk INT(11), + CREATE OR REPLACE TEMPORARY TABLE tmp.sale ( saleFk INT(11), - hasItemShortage BOOL DEFAULT FALSE, - hasItemLost BOOL DEFAULT FALSE, - hasItemDelay BOOL DEFAULT FALSE, - hasRounding BOOL DEFAULT FALSE, - PRIMARY KEY (ticketFk, saleFk) - ) ENGINE = MEMORY; - - CREATE OR REPLACE TEMPORARY TABLE tItemShelving - (INDEX (itemFk, warehouseFk)) - ENGINE = MEMORY - SELECT ish.itemFk itemFk, - SUM(ish.visible) visible, - s.warehouseFk warehouseFk - FROM itemShelving ish - JOIN shelving sh ON sh.code = ish.shelvingFk - JOIN parking p ON p.id = sh.parkingFk - JOIN sector s ON s.id = p.sectorFk - GROUP BY ish.itemFk, s.warehouseFk; - - -- Disponible, faltas, inventario y retrasos - OPEN vCursor; - l: LOOP - SET vDone = FALSE; - FETCH vCursor INTO vWarehouseFk, vDate; - - IF vDone THEN - LEAVE l; - END IF; - - -- Disponible: no va a haber suficiente producto para preparar todos los pedidos - CALL cache.available_refresh(vAvailableCache, FALSE, vWarehouseFk, vDate); - - -- Faltas: visible, disponible y ubicado son menores que la cantidad vendida - CALL cache.visible_refresh(vVisibleCache, FALSE, vWarehouseFk); - - INSERT INTO tmp.saleProblems(ticketFk, saleFk, hasItemShortage) - SELECT tt.ticketFk, s.id, TRUE - FROM tmp.ticket tt - JOIN ticket t ON t.id = tt.ticketFk - JOIN sale s ON s.ticketFk = t.id - JOIN item i ON i.id = s.itemFk - JOIN itemType it ON it.id = i.typeFk - JOIN itemCategory ic ON ic.id = it.categoryFk - LEFT JOIN cache.visible v ON v.item_id = i.id - AND v.calc_id = vVisibleCache - LEFT JOIN cache.available av ON av.item_id = i.id - AND av.calc_id = vAvailableCache - LEFT JOIN tItemShelving tis ON tis.itemFk = i.id - AND tis.warehouseFk = t.warehouseFk - WHERE IFNULL(v.visible, 0) < s.quantity - AND IFNULL(av.available, 0) < s.quantity - AND IFNULL(tis.visible, 0) < s.quantity - AND NOT s.isPicked - AND NOT s.reserved - AND ic.merchandise - AND IF(vIsTodayRelative, TRUE, DATE(t.shipped) = vDate) - AND NOT i.generic - AND util.VN_CURDATE() = vDate - AND t.warehouseFk = vWarehouseFk + PRIMARY KEY (saleFk) + ) ENGINE = MEMORY + SELECT DISTINCT s.id saleFk + FROM tmp.ticket tt + JOIN ticket t ON t.id = tt.ticketFk + JOIN sale s ON s.ticketFk = t.id + WHERE t.shipped BETWEEN util.VN_CURDATE() + AND util.dayEnd(util.VN_CURDATE() + INTERVAL IF(vIsTodayRelative, 9.9, 1.9) DAY) GROUP BY s.id; - -- Inventario: Visible suficiente, pero ubicado menor a la cantidad vendida - INSERT INTO tmp.saleProblems(ticketFk, saleFk, hasItemLost) - SELECT tt.ticketFk, s.id, TRUE - FROM tmp.ticket tt - JOIN ticket t ON t.id = tt.ticketFk - JOIN sale s ON s.ticketFk = t.id - JOIN item i ON i.id = s.itemFk - JOIN itemType it ON it.id = i.typeFk - JOIN itemCategory ic ON ic.id = it.categoryFk - LEFT JOIN cache.visible v ON v.item_id = s.itemFk - AND v.calc_id = vVisibleCache - LEFT JOIN tItemShelving tis ON tis.itemFk = i.id - AND tis.warehouseFk = t.warehouseFk - WHERE IFNULL(v.visible, 0) >= s.quantity - AND IFNULL(tis.visible, 0) < s.quantity - AND s.quantity > 0 - AND NOT s.isPicked - AND NOT s.reserved - AND ic.merchandise - AND IF(vIsTodayRelative, TRUE, DATE(t.shipped) = vDate) - AND NOT i.generic - AND util.VN_CURDATE() = vDate - AND t.warehouseFk = vWarehouseFk - GROUP BY s.id - ON DUPLICATE KEY UPDATE hasItemLost = TRUE; - - -- Retraso: Disponible suficiente, pero no visible ni ubicado - INSERT INTO tmp.saleProblems(ticketFk, saleFk, hasItemDelay) - SELECT tt.ticketFk, s.id, TRUE - FROM tmp.ticket tt - JOIN ticket t ON t.id = tt.ticketFk - JOIN sale s ON s.ticketFk = t.id - JOIN item i ON i.id = s.itemFk - JOIN itemType it ON it.id = i.typeFk - JOIN itemCategory ic ON ic.id = it.categoryFk - LEFT JOIN cache.visible v ON v.item_id = s.itemFk - AND v.calc_id = vVisibleCache - LEFT JOIN cache.available av ON av.item_id = i.id - AND av.calc_id = vAvailableCache - LEFT JOIN tItemShelving tis ON tis.itemFk = i.id - AND tis.warehouseFk = t.warehouseFk - WHERE IFNULL(v.visible, 0) < s.quantity - AND IFNULL(av.available, 0) >= s.quantity - AND IFNULL(tis.visible, 0) < s.quantity - AND s.quantity > 0 - AND NOT s.isPicked - AND NOT s.reserved - AND ic.merchandise - AND IF(vIsTodayRelative, TRUE, DATE(t.shipped) = vDate) - AND NOT i.generic - AND util.VN_CURDATE() = vDate - AND t.warehouseFk = vWarehouseFk - GROUP BY s.id - ON DUPLICATE KEY UPDATE hasItemDelay = TRUE; - - -- Redondeo: cantidad incorrecta con respecto al grouping - CALL buy_getUltimate(NULL, vWarehouseFk, vDate); - - INSERT INTO tmp.saleProblems(ticketFk, saleFk, hasRounding) - SELECT tt.ticketFk, s.id, TRUE - FROM tmp.ticket tt - JOIN ticket t ON t.id = tt.ticketFk - AND t.warehouseFk = vWarehouseFk - JOIN sale s ON s.ticketFk = tt.ticketFk - JOIN item i ON i.id = s.itemFk - JOIN tmp.buyUltimate bu ON bu.itemFk = s.itemFk - JOIN buy b ON b.id = bu.buyFk - WHERE MOD(s.quantity, b.`grouping`) - GROUP BY s.id - ON DUPLICATE KEY UPDATE hasRounding = TRUE; - - DROP TEMPORARY TABLE tmp.buyUltimate; - END LOOP; - CLOSE vCursor; + CALL sale_getProblems(vIsTodayRelative); CREATE OR REPLACE TEMPORARY TABLE tmp.ticketProblems ( ticketFk INT(11), @@ -195,27 +55,14 @@ BEGIN SUM(IFNULL(ts.hasItemDelay,0)) hasItemDelay, SUM(IFNULL(ts.hasItemLost,0)) hasItemLost, IF(FIND_IN_SET('hasComponentLack', s.problem), TRUE, FALSE) hasComponentLack, - SUM(IFNULL(ts.hasRounding,0)) hasRounding, - LEFT(CONCAT('F: ',GROUP_CONCAT(CONCAT(i.id, ' ', i.longName) SEPARATOR ', ')), 250) itemShortage, - LEFT(CONCAT('R: ',GROUP_CONCAT(CONCAT(i2.id, ' ', i2.longName) SEPARATOR ', ')), 250) itemDelay, - LEFT(CONCAT('I: ',GROUP_CONCAT(CONCAT(i3.id, ' ', i3.longName) SEPARATOR ', ')), 250) itemLost, - LEFT(CONCAT('C: ',GROUP_CONCAT(CONCAT(i4.id, ' ', i4.longName) SEPARATOR ', ')), 250) componentLack, - LEFT(CONCAT('RE: ',GROUP_CONCAT(CONCAT(i5.id, ' ', i5.longName) SEPARATOR ', ')), 250) rounding + SUM(IFNULL(ts.hasRounding,0)) hasRounding FROM tmp.ticket tt JOIN ticket t ON t.id = tt.ticketFk JOIN client c ON c.id = t.clientFk LEFT JOIN sale s ON s.ticketFk = t.id LEFT JOIN tmp.saleProblems ts ON ts.saleFk = s.id - LEFT JOIN item i ON i.id = s.itemFk AND ts.hasItemShortage - LEFT JOIN item i2 ON i2.id = s.itemFk AND ts.hasItemDelay - LEFT JOIN item i3 ON i3.id = s.itemFk AND ts.hasItemLost - LEFT JOIN item i4 ON i4.id = s.itemFk AND FIND_IN_SET('hasComponentLack', s.problem) - LEFT JOIN item i5 ON i5.id = s.itemFk AND ts.hasRounding LEFT JOIN zoneClosure zc ON zc.zoneFk = t.zoneFk AND zc.dated = util.VN_CURDATE() - WHERE s.problem <> '' OR t.problem <> '' OR t.risk GROUP BY t.id; - - DROP TEMPORARY TABLE tItemShelving; END$$ DELIMITER ;