From 5e630562ce365e5e5be6ff84a7790f6d8468ace2 Mon Sep 17 00:00:00 2001 From: Juan Ferrer Toribio Date: Mon, 24 Feb 2025 18:05:21 +0100 Subject: [PATCH] fix: refs #4409 don't cache parent ids --- .../stock/procedures/buyLot_refresh.sql | 95 ++++++------------- .../stock/procedures/buyOut_refresh.sql | 82 +++++++++------- .../stock/procedures/buyOut_refreshBuy.sql | 55 ++++------- .../stock/procedures/buyOut_refreshOrder.sql | 51 +++------- .../stock/procedures/buyOut_refreshSale.sql | 57 ++++------- db/versions/11009-tealRuscus/02-buyLot.sql | 6 +- db/versions/11009-tealRuscus/04-buyOut.sql | 2 +- db/versions/11009-tealRuscus/05-buyOutBuy.sql | 8 -- .../11009-tealRuscus/05-buyOutOrder.sql | 6 -- .../11009-tealRuscus/05-buyOutSale.sql | 6 -- 10 files changed, 128 insertions(+), 240 deletions(-) delete mode 100644 db/versions/11009-tealRuscus/05-buyOutBuy.sql delete mode 100644 db/versions/11009-tealRuscus/05-buyOutOrder.sql delete mode 100644 db/versions/11009-tealRuscus/05-buyOutSale.sql diff --git a/db/routines/stock/procedures/buyLot_refresh.sql b/db/routines/stock/procedures/buyLot_refresh.sql index 45d22e1daf..ceccdbcd49 100644 --- a/db/routines/stock/procedures/buyLot_refresh.sql +++ b/db/routines/stock/procedures/buyLot_refresh.sql @@ -1,22 +1,9 @@ DELIMITER $$ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `stock`.`buyLot_refresh`( - `vTable` ENUM('buy', 'entry', 'travel'), + `vTable` ENUM('lot', 'entry', 'travel'), `vId` INT) BEGIN - START TRANSACTION; - - -- Update cache - - CREATE OR REPLACE TEMPORARY TABLE tLotOld - ENGINE = MEMORY - SELECT lotFk - FROM buyLot - WHERE - (vTable = 'buy' AND lotFk = vId) - OR (vTable = 'entry' AND entryFk = vId) - OR (vTable = 'travel' AND travelFk = vId); - - CREATE OR REPLACE TEMPORARY TABLE tLotNew + CREATE OR REPLACE TEMPORARY TABLE tBuyAlive ENGINE = MEMORY SELECT t.id travelFk, @@ -30,29 +17,37 @@ BEGIN b.itemFk, b.life, b.quantity - FROM vn.buy b + FROM tLotStatus oo + JOIN vn.buy b ON b.lotFk = oo.lotFk JOIN vn.entry e ON e.id = b.entryFk JOIN vn.travel t ON t.id = e.travelFk - JOIN vn.item i ON i.id = b.itemFk - WHERE b.quantity > 0 - AND b.isAlive - AND ( - (vTable = 'buy' AND b.lotFk = vId) - OR (vTable = 'entry' AND e.id = vId) - OR (vTable = 'travel' AND t.id = vId) - ); + WHERE oo.isAlive; - DELETE FROM buyLot - WHERE lotFk IN ( - SELECT lotFk FROM tLotOld - EXCEPT - SELECT lotFk FROM tLotNew - ); + START TRANSACTION; + + -- Delete excluded/deleted/dead lots + + DELETE l FROM buyLot l + JOIN tLotStatus oo USING(lotFk) + WHERE oo.isExcluded OR NOT oo.isAlive; + + -- Delete undead lot picks + + UPDATE buyOut o + JOIN buyPick p ON p.outFk = o.outFk + JOIN tLotStatus oo ON oo.lotFk = p.lotFk + SET o.isSync = FALSE, + o.lack = o.lack + p.quantity + WHERE oo.isExcluded OR oo.isAlive; + + DELETE p FROM buyPick p + JOIN tLotStatus oo USING(lotFk) + WHERE oo.isExcluded OR oo.isAlive; + + -- Update alive outs INSERT INTO buyLot ( lotFk, - entryFk, - travelFk, isSync, isPicked, warehouseFk, @@ -64,8 +59,6 @@ BEGIN ) SELECT lotFk, - entryFk, - travelFk, FALSE, isReceived, warehouseInFk, @@ -74,10 +67,8 @@ BEGIN @dated + INTERVAL life DAY, quantity, NULL - FROM tLotNew + FROM tBuyAlive ON DUPLICATE KEY UPDATE - entryFk = VALUES(entryFk), - travelFk = VALUES(travelFk), isSync = VALUES(isSync), isPicked = VALUES(isPicked), warehouseFk = VALUES(warehouseFk), @@ -87,36 +78,8 @@ BEGIN quantity = VALUES(quantity), available = VALUES(available); - -- Remove picks from updated and removed lots - - CREATE OR REPLACE TEMPORARY TABLE tLotPrune - ENGINE = MEMORY - SELECT lotFk FROM tLotNew - UNION - SELECT o.lotFk FROM tLotOld o - LEFT JOIN vn.buy b ON b.id = o.lotFk - WHERE b.lotFk IS NULL; - - UPDATE buyOut o - JOIN buyPick p - ON p.outFk = o.outFk - JOIN tLotPrune pl - ON pl.lotFk = p.lotFk - SET o.isSync = FALSE, - o.lack = o.lack + p.quantity; - - DELETE p FROM buyPick p - JOIN tLotPrune pl USING(lotFk); - - DROP TEMPORARY TABLE - tLotOld, - tLotNew, - tLotPrune; - COMMIT; - -- Refresh outs - - CALL buyOut_refreshBuy(vTable, vId); + DROP TEMPORARY TABLE tBuyAlive; END$$ DELIMITER ; diff --git a/db/routines/stock/procedures/buyOut_refresh.sql b/db/routines/stock/procedures/buyOut_refresh.sql index 02fd70257e..a4dd59001f 100644 --- a/db/routines/stock/procedures/buyOut_refresh.sql +++ b/db/routines/stock/procedures/buyOut_refresh.sql @@ -1,41 +1,71 @@ DELIMITER $$ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `stock`.`buyOut_refresh`( - `vTable` VARCHAR(255)) + `vTable` VARCHAR(255), + `vId` INT, + `vSource` VARCHAR(255)) BEGIN - CREATE TEMPORARY TABLE tOutPrune - ENGINE = MEMORY - SELECT outFk FROM tOutOld - EXCEPT - SELECT outFk FROM tOutNew; + DECLARE vLotExists INT; - DELETE o FROM buyOut o JOIN tOutPrune d USING(outFk); + IF vTable = 'lot' THEN + SET vLotExists = (SELECT COUNT(*) > 0 FROM tLotStatus); + + IF NOT vLotExists THEN + INSERT INTO tLotStatus + SET lotFk = vId, + isExcluded = TRUE, + isAlive = FALSE; + END IF; + END IF; + + START TRANSACTION; + + -- Delete excluded/deleted/dead outs + + DELETE o FROM buyOut o + JOIN tLotStatus oo ON oo.lotFk = o.outFk + WHERE oo.isExcluded OR NOT oo.isAlive; + + -- Delete undead out picks + + UPDATE buyLot l + JOIN buyPick p ON p.lotFk = l.lotFk + JOIN tLotStatus oo ON oo.lotFk = p.outFk + SET l.isSync = FALSE, + l.available = l.available + p.quantity + WHERE oo.isExcluded OR oo.isAlive; + + DELETE p FROM buyPick p + JOIN tLotStatus oo ON oo.lotFk = p.outFk + WHERE oo.isExcluded OR oo.isAlive; + + -- Update alive outs INSERT INTO buyOut ( - tableName, outFk, + source, + isSync, warehouseFk, dated, itemFk, quantity, lack, created, - isPicked, - isSync + isPicked ) SELECT - vTable, - outFk, + lotFk, + vSource, + FALSE, warehouseFk, dated, itemFk, quantity, quantity, created, - isPicked, - FALSE - FROM tOutNew + isPicked + FROM tLotAlive ON DUPLICATE KEY UPDATE - tableName = VALUES(tableName), + source = VALUES(source), warehouseFk = VALUES(warehouseFk), dated = VALUES(dated), itemFk = VALUES(itemFk), @@ -45,24 +75,6 @@ BEGIN isPicked = VALUES(isPicked), isSync = VALUES(isSync); - CREATE OR REPLACE TEMPORARY TABLE tPickPrune - ENGINE = MEMORY - SELECT id FROM buyPick - WHERE outFk IN ( - SELECT outFk FROM tOutDel - UNION - SELECT outFk FROM tOutNew - ); - - UPDATE buyLot l - JOIN buyPick p ON p.lotFk = l.lotFk - JOIN tPickPrune pp ON pp.id = p.id - SET l.isSync = FALSE, - l.available = l.available + p.quantity; - - DELETE p FROM buyPick p - JOIN tPickPrune pp USING (id); - - DROP TEMPORARY TABLE tPickPrune; + COMMIT; END$$ DELIMITER ; diff --git a/db/routines/stock/procedures/buyOut_refreshBuy.sql b/db/routines/stock/procedures/buyOut_refreshBuy.sql index 63303107c4..1219ef881a 100644 --- a/db/routines/stock/procedures/buyOut_refreshBuy.sql +++ b/db/routines/stock/procedures/buyOut_refreshBuy.sql @@ -3,58 +3,37 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `stock`.`buyOut_refreshBuy` `vTable` VARCHAR(255), `vId` INT) BEGIN - CREATE OR REPLACE TEMPORARY TABLE tOutOld + CREATE OR REPLACE TEMPORARY TABLE tLotStatus ENGINE = MEMORY - SELECT outFk - FROM buyOutBuy + SELECT lotFk, + b.quantity <= 0 isExcluded, + b.isAlive + FROM vn.buy b + JOIN vn.entry e ON e.id = b.entryFk WHERE - (vTable = 'buy' AND outFk = vId) - OR (vTable = 'entry' AND entryFk = vId) - OR (vTable = 'travel' AND travelFk = vId); + (vTable = 'lot' AND b.lotFk = vId) + OR (vTable = 'entry' AND e.id = vId) + OR (vTable = 'travel' AND e.travelFk = vId); - CREATE OR REPLACE TEMPORARY TABLE tOutNew + CREATE OR REPLACE TEMPORARY TABLE tLotAlive ENGINE = MEMORY SELECT - t.id travelFk, - e.id entryFk, - b.lotFk outFk, + oo.lotFk, t.warehouseOutFk warehouseFk, ADDTIME(t.shipped, IFNULL(shipmentHour, '00:00:00')) dated, t.isDelivered isPicked, b.itemFk, b.quantity, b.created - FROM vn.buy b + FROM tLotStatus oo + JOIN vn.buy b ON b.lotFk = oo.lotFk JOIN vn.entry e ON e.id = b.entryFk JOIN vn.travel t ON t.id = e.travelFk - WHERE b.quantity > 0 - AND b.isAlive - AND ( - (vTable = 'buy' AND b.lotFk = vId) - OR (vTable = 'entry' AND e.id = vId) - OR (vTable = 'travel' AND t.id = vId) - ); + WHERE oo.isAlive; - CREATE OR REPLACE TEMPORARY TABLE tOutDel - ENGINE = MEMORY - SELECT o.outFk FROM tOutOld o - LEFT JOIN vn.buy b ON b.lotFk = o.outFk - WHERE b.lotFk IS NULL; + CALL buyOut_refresh(vTable, vId, 'buy'); + CALL buyLot_refresh(vTable, vId); - START TRANSACTION; - - CALL buyOut_refresh('buy'); - - DELETE o FROM buyOutBuy o JOIN tOutPrune d USING(outFk); - - INSERT INTO buyOutBuy (outFk, entryFk, travelFk) - SELECT outFk, entryFk, travelFk FROM tOutNew - ON DUPLICATE KEY UPDATE - travelFk = VALUES(travelFk), - entryFk = VALUES(entryFk); - - COMMIT; - - DROP TEMPORARY TABLE tOutNew, tOutOld, tOutPrune, tOutDel; + DROP TEMPORARY TABLE tLotStatus, tLotAlive; END$$ DELIMITER ; diff --git a/db/routines/stock/procedures/buyOut_refreshOrder.sql b/db/routines/stock/procedures/buyOut_refreshOrder.sql index bfa4b3842a..c0ca71d762 100644 --- a/db/routines/stock/procedures/buyOut_refreshOrder.sql +++ b/db/routines/stock/procedures/buyOut_refreshOrder.sql @@ -9,55 +9,34 @@ BEGIN INTO vExpired FROM hedera.orderConfig LIMIT 1; - CREATE OR REPLACE TEMPORARY TABLE tOutOld + CREATE OR REPLACE TEMPORARY TABLE tLotStatus ENGINE = MEMORY - SELECT outFk - FROM buyOutOrder + SELECT lotFk, + o.confirmed OR r.created < vExpired OR r.amount <= 0 isExcluded, + TRUE isAlive + FROM hedera.orderRow r + JOIN hedera.`order` o ON o.id = r.orderFk WHERE - (vTable = 'orderRow' AND outFk = vId) - OR (vTable = 'order' AND orderFk = vId); + (vTable = 'lot' AND r.lotFk = vId) + OR (vTable = 'order' AND o.id = vId); - CREATE OR REPLACE TEMPORARY TABLE tOutNew + CREATE OR REPLACE TEMPORARY TABLE tLotAlive ENGINE = MEMORY SELECT - o.id orderFk, - r.lotFk outFk, + oo.lotFk, r.warehouseFk, r.shipment dated, r.itemFk, r.amount quantity, r.created, FALSE isPicked - FROM hedera.orderRow r + FROM tLotStatus oo + JOIN hedera.orderRow r ON r.lotFk = oo.lotFk JOIN hedera.`order` o ON o.id = r.orderFk - WHERE !o.confirmed - AND r.created >= vExpired - AND r.amount > 0 - AND ( - (vTable = 'orderRow' AND r.lotFk = vId) - OR (vTable = 'order' AND o.id = vId) - ); + WHERE oo.isAlive; - CREATE OR REPLACE TEMPORARY TABLE tOutDel - ENGINE = MEMORY - SELECT o.outFk FROM tOutOld o - LEFT JOIN hedera.orderRow r ON r.lotFk = o.outFk - WHERE r.lotFk IS NULL; + CALL buyOut_refresh(vTable, vId, 'orderRow'); - START TRANSACTION; - - CALL buyOut_refresh('orderRow'); - - DELETE o FROM buyOutOrder o - JOIN tOutPrune d USING(outFk); - - INSERT INTO buyOutOrder (outFk, orderFk) - SELECT outFk, orderFk FROM tOutNew - ON DUPLICATE KEY UPDATE - orderFk = VALUES(orderFk); - - COMMIT; - - DROP TEMPORARY TABLE tOutNew, tOutOld, tOutPrune, tOutDel; + DROP TEMPORARY TABLE tLotStatus, tLotAlive; END$$ DELIMITER ; diff --git a/db/routines/stock/procedures/buyOut_refreshSale.sql b/db/routines/stock/procedures/buyOut_refreshSale.sql index 8d73201469..795f477a24 100644 --- a/db/routines/stock/procedures/buyOut_refreshSale.sql +++ b/db/routines/stock/procedures/buyOut_refreshSale.sql @@ -3,59 +3,38 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `stock`.`buyOut_refreshSale `vTable` VARCHAR(255), `vId` INT) BEGIN - DECLARE vPreparation INT; + DECLARE vAliveDate DATE; - SELECT id INTO vPreparation - FROM vn.alertLevel WHERE code = 'ON_PREPARATION'; + SET vAliveDate = CURDATE() - INTERVAL 1 MONTH; - CREATE OR REPLACE TEMPORARY TABLE tOutOld + CREATE OR REPLACE TEMPORARY TABLE tLotStatus ENGINE = MEMORY - SELECT outFk - FROM buyOutSale + SELECT lotFk, + s.quantity < 0 isExcluded, + t.landed >= vAliveDate isAlive + FROM vn.sale s + JOIN vn.ticket t ON t.id = s.ticketFk WHERE - (vTable = 'sale' AND outFk = vId) - OR (vTable = 'ticket' AND ticketFk = vId); + (vTable = 'lot' AND s.lotFk = vId) + OR (vTable = 'ticket' AND t.id = vId); - CREATE OR REPLACE TEMPORARY TABLE tOutNew + CREATE OR REPLACE TEMPORARY TABLE tLotAlive ENGINE = MEMORY SELECT - t.id ticketFk, - s.lotFk outFk, + oo.lotFk, t.warehouseFk, t.shipped dated, s.itemFk, s.quantity, s.created, - s.isPicked OR ts.alertLevel > vPreparation isPicked - FROM vn.sale s + s.isPicked + FROM tLotStatus oo + JOIN vn.sale s ON s.lotFk = oo.lotFk JOIN vn.ticket t ON t.id = s.ticketFk - JOIN vn.ticketState ts ON s.ticketFk = t.id - WHERE s.quantity >= 0 - AND ( - (vTable = 'sale' AND s.lotFk = vId) - OR (vTable = 'ticket' AND t.id = vId) - ); + WHERE oo.isAlive; - CREATE OR REPLACE TEMPORARY TABLE tOutDel - ENGINE = MEMORY - SELECT o.outFk FROM tOutOld o - LEFT JOIN vn.sale s ON s.lotFk = o.outFk - WHERE s.lotFk IS NULL; + CALL buyOut_refresh(vTable, vId, 'sale'); - START TRANSACTION; - - CALL buyOut_refresh('sale'); - - DELETE o FROM buyOutSale o - JOIN tOutPrune d USING(outFk); - - INSERT INTO buyOutSale (outFk, ticketFk) - SELECT outFk, ticketFk FROM tOutNew - ON DUPLICATE KEY UPDATE - ticketFk = VALUES(ticketFk); - - COMMIT; - - DROP TEMPORARY TABLE tOutNew, tOutOld, tOutPrune, tOutDel; + DROP TEMPORARY TABLE tLotStatus, tLotAlive; END$$ DELIMITER ; diff --git a/db/versions/11009-tealRuscus/02-buyLot.sql b/db/versions/11009-tealRuscus/02-buyLot.sql index 3a89e73fb1..cfdca064b9 100644 --- a/db/versions/11009-tealRuscus/02-buyLot.sql +++ b/db/versions/11009-tealRuscus/02-buyLot.sql @@ -4,11 +4,7 @@ ALTER TABLE stock.buyLot DROP KEY source, DROP COLUMN tableName, CHANGE tableId lotFk int(10) unsigned NOT NULL, - ADD entryFk INT UNSIGNED NOT NULL, - CHANGE entryFk entryFk INT UNSIGNED NOT NULL AFTER lotFk, - ADD travelFk INT UNSIGNED NOT NULL, - CHANGE travelFk travelFk INT UNSIGNED NOT NULL AFTER entryFk, - CHANGE isSync isSync tinyint(4) NOT NULL AFTER travelFk, + CHANGE isSync isSync tinyint(4) NOT NULL AFTER lotFk, DROP PRIMARY KEY, DROP COLUMN id, ADD PRIMARY KEY (lotFk); diff --git a/db/versions/11009-tealRuscus/04-buyOut.sql b/db/versions/11009-tealRuscus/04-buyOut.sql index b3ec7df2c6..d7867ad99b 100644 --- a/db/versions/11009-tealRuscus/04-buyOut.sql +++ b/db/versions/11009-tealRuscus/04-buyOut.sql @@ -1,7 +1,7 @@ RENAME TABLE IF EXISTS stock.outbound TO stock.buyOut; ALTER TABLE stock.buyOut - MODIFY COLUMN tableName enum('buy','sale','orderRow') CHARACTER SET utf8mb3 COLLATE utf8mb3_general_ci NOT NULL, + CHANGE tableName source enum('buy','sale','orderRow') CHARACTER SET utf8mb3 COLLATE utf8mb3_general_ci NOT NULL, CHANGE id outFk int(10) UNSIGNED NOT NULL, DROP INDEX source, DROP COLUMN tableId, diff --git a/db/versions/11009-tealRuscus/05-buyOutBuy.sql b/db/versions/11009-tealRuscus/05-buyOutBuy.sql deleted file mode 100644 index d3a610e91b..0000000000 --- a/db/versions/11009-tealRuscus/05-buyOutBuy.sql +++ /dev/null @@ -1,8 +0,0 @@ -CREATE TABLE IF NOT EXISTS stock.buyOutBuy ( - outFk INT UNSIGNED, - entryFk INT, - travelFk INT, - UNIQUE(outFk), - INDEX(entryFk), - INDEX(travelFk) -); diff --git a/db/versions/11009-tealRuscus/05-buyOutOrder.sql b/db/versions/11009-tealRuscus/05-buyOutOrder.sql deleted file mode 100644 index d8bedd9158..0000000000 --- a/db/versions/11009-tealRuscus/05-buyOutOrder.sql +++ /dev/null @@ -1,6 +0,0 @@ -CREATE TABLE IF NOT EXISTS stock.buyOutOrder ( - outFk INT UNSIGNED, - orderFk INT, - UNIQUE(outFk), - INDEX(orderFk) -); diff --git a/db/versions/11009-tealRuscus/05-buyOutSale.sql b/db/versions/11009-tealRuscus/05-buyOutSale.sql deleted file mode 100644 index fd536ec6d2..0000000000 --- a/db/versions/11009-tealRuscus/05-buyOutSale.sql +++ /dev/null @@ -1,6 +0,0 @@ -CREATE TABLE IF NOT EXISTS stock.buyOutSale ( - outFk INT UNSIGNED, - ticketFk INT, - UNIQUE(outFk), - INDEX(ticketFk) -);