From aa46d7a53659188933d6cc4a1307f6961f74f168 Mon Sep 17 00:00:00 2001 From: guillermo Date: Fri, 5 Jul 2024 09:46:09 +0200 Subject: [PATCH] refs #6769 item_getBalance optimization --- db/routines/vn/procedures/item_getBalance.sql | 68 +++++++++++-------- .../11135-whiteErica/00-firstScript.sql | 1 + 2 files changed, 39 insertions(+), 30 deletions(-) create mode 100644 db/versions/11135-whiteErica/00-firstScript.sql diff --git a/db/routines/vn/procedures/item_getBalance.sql b/db/routines/vn/procedures/item_getBalance.sql index a12397aa6..15be8c926 100644 --- a/db/routines/vn/procedures/item_getBalance.sql +++ b/db/routines/vn/procedures/item_getBalance.sql @@ -21,14 +21,14 @@ BEGIN FROM config c JOIN util.config uc; - SELECT COALESCE(vDated, vDateInventory) - INTERVAL MAX(life) DAY + SELECT vDateInventory - INTERVAL MAX(life) DAY INTO vLifeScope FROM itemType; SELECT warehouseOutFk, supplierFk INTO vWarehouseInventoryFk, vSupplierInventoryFk FROM inventoryConfig; - + IF NOT vWarehouseInventoryFk OR NOT vSupplierInventoryFk THEN CALL util.throw('Config variables are not set'); END IF; @@ -50,30 +50,32 @@ BEGIN JOIN warehouse w ON w.id = t.warehouseInFk JOIN item i ON i.id = b.itemFk JOIN itemType it ON it.id = i.typeFk - WHERE t.landed BETWEEN vLifeScope AND COALESCE(vDated, vDateInventory) + WHERE t.landed BETWEEN vLifeScope AND vDateInventory AND t.warehouseInFk = vWarehouseFk AND t.warehouseOutFk <> vWarehouseInventoryFk AND it.life + AND i.id = vItemFk AND NOT e.isExcludedFromAvailable GROUP BY b.itemFk ) c ON i.id = c.itemFk JOIN itemType it ON it.id = i.typeFk - HAVING ended >= COALESCE(vDated, vDateInventory) OR life IS NULL; + WHERE i.id = vItemFk + HAVING ended >= vDateInventory OR life IS NULL; CREATE OR REPLACE TEMPORARY TABLE tItemDiary ENGINE = MEMORY WITH entriesIn AS ( SELECT 'entry' originType, - e.id origin, + e.id originId, tr.landed shipped, b.quantity `in`, NULL `out`, st.alertLevel , st.name stateName, - s.name `name`, e.invoiceNumber reference, 'supplier' entityType, - s.id entity, + s.id entityId, + s.name entityName, IF(st.`code` = 'DELIVERED', TRUE, FALSE) isPicked, FALSE isTicket, b.id lineFk, @@ -104,10 +106,10 @@ BEGIN b.quantity, st.alertLevel, st.name stateName, - s.name, e.invoiceNumber, 'supplier' entityType, - s.id entity, + s.id entityId, + s.name, IF(st.`code` = 'DELIVERED' , TRUE, FALSE), FALSE isTicket, b.id, @@ -125,7 +127,7 @@ BEGIN 'DELIVERED', 'FREE') WHERE tr.shipped >= vDateInventory - AND vWarehouseFk = tr.warehouseOutFk + AND tr.warehouseOutFk = vWarehouseFk AND (s.id <> vSupplierInventoryFk OR vDated IS NULL) AND b.itemFk = vItemFk AND NOT e.isExcludedFromAvailable @@ -138,29 +140,30 @@ BEGIN s.quantity, st2.alertLevel, st2.name, - t.nickname, t.refFk, t.id ticketFk, 'client' entityType, - t.clientFk entity, + t.clientFk entityId, + t.nickname, s.id saleFk, st.`order`, c.typeFk, cb.claimFk FROM vn.sale s JOIN vn.ticket t ON t.id = s.ticketFk - LEFT JOIN vn.ticketState ts ON ts.ticketFk = t.id - LEFT JOIN vn.state st ON st.`code` = ts.`code` + LEFT JOIN vn.ticketLastState tls ON tls.ticketFk = t.id + LEFT JOIN vn.ticketTracking tt ON tt.id = tls.ticketTrackingFk + LEFT JOIN vn.state st ON st.id = tt.stateFk JOIN vn.client c ON c.id = t.clientFk JOIN vn.state st2 ON st2.`code` = IF(t.shipped < util.VN_CURDATE(), 'DELIVERED', IF (t.shipped > util.dayEnd(util.VN_CURDATE()), 'FREE', - IFNULL(ts.code, 'FREE'))) - LEFT JOIN vn.claimBeginning cb ON s.id = cb.saleFk + IFNULL(st.code, 'FREE'))) + LEFT JOIN vn.claimBeginning cb ON cb.saleFk = s.id WHERE t.shipped >= vDateInventory AND s.itemFk = vItemFk - AND vWarehouseFk = t.warehouseFk + AND t.warehouseFk = vWarehouseFk ) SELECT 'ticket', s.ticketFk, @@ -169,10 +172,10 @@ BEGIN s.quantity, s.alertLevel, s.name, - s.nickname, s.refFk, s.entityType, - s.entity, + s.entityId, + s.nickname, IF(stk.saleFk, TRUE, FALSE), TRUE, s.saleFk, @@ -188,16 +191,16 @@ BEGIN ), orders AS ( SELECT 'order' originType, - o.id origin, + o.id originId, r.shipment, NULL 'in', r.amount, NULL alertLevel, NULL stateName, - c.name, NULL invoiceNumber, 'client' entityType, c.id, + c.name, FALSE, FALSE isTicket, NULL buyFk, @@ -212,6 +215,10 @@ BEGIN WHERE r.shipment >= vDateInventory AND (ir.ended IS NULL OR r.shipment <= ir.ended) AND r.warehouseFk = vWarehouseFk + AND r.created >= ( + SELECT SUBTIME(util.VN_NOW(), reserveTime) + FROM hedera.orderConfig + ) AND NOT o.confirmed AND r.itemFk = vItemFk ) @@ -223,7 +230,7 @@ BEGIN UNION ALL SELECT * FROM orders ORDER BY shipped, - (inventorySupplierFk = entity) DESC, + (inventorySupplierFk = entityId) DESC, alertLevel DESC, isTicket, `order` DESC, @@ -237,14 +244,14 @@ BEGIN SET @shipped := ''; SELECT t.originType, - t.origin, + t.originId, DATE(@shipped:= t.shipped) shipped, t.alertLevel, t.stateName, t.reference, t.entityType, - t.entity, - t.name, + t.entityId, + t.entityName, t.`in` invalue, t.`out`, @a := @a + IFNULL(t.`in`, 0) - IFNULL(t.`out`, 0) balance, @@ -266,13 +273,13 @@ BEGIN WHERE shipped < vDated; SELECT NULL originType, - NULL origin, + NULL originId, vDated shipped, NULL alertLevel, NULL stateName, NULL reference, NULL entityType, - NULL entity, + NULL entityId, 'Inventario calculado', @a invalue, NULL `out`, @@ -286,14 +293,15 @@ BEGIN NULL `order` UNION ALL SELECT originType, - origin, + originId, shipped, alertlevel, stateName, reference, entityType, - entity, - name, `in`, + entityId, + entityName, + `in`, `out`, @a := @a + IFNULL(`in`, 0) - IFNULL(`out`, 0), 0, diff --git a/db/versions/11135-whiteErica/00-firstScript.sql b/db/versions/11135-whiteErica/00-firstScript.sql new file mode 100644 index 000000000..902608a3e --- /dev/null +++ b/db/versions/11135-whiteErica/00-firstScript.sql @@ -0,0 +1 @@ +CREATE INDEX travel_landed_IDX USING BTREE ON vn.travel (landed DESC,warehouseInFk,warehouseOutFk);