fix: refs #4409 don't cache parent ids
gitea/salix/pipeline/pr-dev There was a failure building this commit Details

This commit is contained in:
Juan Ferrer 2025-02-24 18:05:21 +01:00
parent 1c77e69ae4
commit 5e630562ce
10 changed files with 128 additions and 240 deletions

View File

@ -1,22 +1,9 @@
DELIMITER $$ DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `stock`.`buyLot_refresh`( CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `stock`.`buyLot_refresh`(
`vTable` ENUM('buy', 'entry', 'travel'), `vTable` ENUM('lot', 'entry', 'travel'),
`vId` INT) `vId` INT)
BEGIN BEGIN
START TRANSACTION; CREATE OR REPLACE TEMPORARY TABLE tBuyAlive
-- 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
ENGINE = MEMORY ENGINE = MEMORY
SELECT SELECT
t.id travelFk, t.id travelFk,
@ -30,29 +17,37 @@ BEGIN
b.itemFk, b.itemFk,
b.life, b.life,
b.quantity 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.entry e ON e.id = b.entryFk
JOIN vn.travel t ON t.id = e.travelFk JOIN vn.travel t ON t.id = e.travelFk
JOIN vn.item i ON i.id = b.itemFk WHERE oo.isAlive;
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)
);
DELETE FROM buyLot START TRANSACTION;
WHERE lotFk IN (
SELECT lotFk FROM tLotOld -- Delete excluded/deleted/dead lots
EXCEPT
SELECT lotFk FROM tLotNew 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 ( INSERT INTO buyLot (
lotFk, lotFk,
entryFk,
travelFk,
isSync, isSync,
isPicked, isPicked,
warehouseFk, warehouseFk,
@ -64,8 +59,6 @@ BEGIN
) )
SELECT SELECT
lotFk, lotFk,
entryFk,
travelFk,
FALSE, FALSE,
isReceived, isReceived,
warehouseInFk, warehouseInFk,
@ -74,10 +67,8 @@ BEGIN
@dated + INTERVAL life DAY, @dated + INTERVAL life DAY,
quantity, quantity,
NULL NULL
FROM tLotNew FROM tBuyAlive
ON DUPLICATE KEY UPDATE ON DUPLICATE KEY UPDATE
entryFk = VALUES(entryFk),
travelFk = VALUES(travelFk),
isSync = VALUES(isSync), isSync = VALUES(isSync),
isPicked = VALUES(isPicked), isPicked = VALUES(isPicked),
warehouseFk = VALUES(warehouseFk), warehouseFk = VALUES(warehouseFk),
@ -87,36 +78,8 @@ BEGIN
quantity = VALUES(quantity), quantity = VALUES(quantity),
available = VALUES(available); 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; COMMIT;
-- Refresh outs DROP TEMPORARY TABLE tBuyAlive;
CALL buyOut_refreshBuy(vTable, vId);
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -1,41 +1,71 @@
DELIMITER $$ DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `stock`.`buyOut_refresh`( CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `stock`.`buyOut_refresh`(
`vTable` VARCHAR(255)) `vTable` VARCHAR(255),
`vId` INT,
`vSource` VARCHAR(255))
BEGIN BEGIN
CREATE TEMPORARY TABLE tOutPrune DECLARE vLotExists INT;
ENGINE = MEMORY
SELECT outFk FROM tOutOld
EXCEPT
SELECT outFk FROM tOutNew;
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 ( INSERT INTO buyOut (
tableName,
outFk, outFk,
source,
isSync,
warehouseFk, warehouseFk,
dated, dated,
itemFk, itemFk,
quantity, quantity,
lack, lack,
created, created,
isPicked, isPicked
isSync
) )
SELECT SELECT
vTable, lotFk,
outFk, vSource,
FALSE,
warehouseFk, warehouseFk,
dated, dated,
itemFk, itemFk,
quantity, quantity,
quantity, quantity,
created, created,
isPicked, isPicked
FALSE FROM tLotAlive
FROM tOutNew
ON DUPLICATE KEY UPDATE ON DUPLICATE KEY UPDATE
tableName = VALUES(tableName), source = VALUES(source),
warehouseFk = VALUES(warehouseFk), warehouseFk = VALUES(warehouseFk),
dated = VALUES(dated), dated = VALUES(dated),
itemFk = VALUES(itemFk), itemFk = VALUES(itemFk),
@ -45,24 +75,6 @@ BEGIN
isPicked = VALUES(isPicked), isPicked = VALUES(isPicked),
isSync = VALUES(isSync); isSync = VALUES(isSync);
CREATE OR REPLACE TEMPORARY TABLE tPickPrune COMMIT;
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;
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -3,58 +3,37 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `stock`.`buyOut_refreshBuy`
`vTable` VARCHAR(255), `vTable` VARCHAR(255),
`vId` INT) `vId` INT)
BEGIN BEGIN
CREATE OR REPLACE TEMPORARY TABLE tOutOld CREATE OR REPLACE TEMPORARY TABLE tLotStatus
ENGINE = MEMORY ENGINE = MEMORY
SELECT outFk SELECT lotFk,
FROM buyOutBuy b.quantity <= 0 isExcluded,
b.isAlive
FROM vn.buy b
JOIN vn.entry e ON e.id = b.entryFk
WHERE WHERE
(vTable = 'buy' AND outFk = vId) (vTable = 'lot' AND b.lotFk = vId)
OR (vTable = 'entry' AND entryFk = vId) OR (vTable = 'entry' AND e.id = vId)
OR (vTable = 'travel' AND travelFk = vId); OR (vTable = 'travel' AND e.travelFk = vId);
CREATE OR REPLACE TEMPORARY TABLE tOutNew CREATE OR REPLACE TEMPORARY TABLE tLotAlive
ENGINE = MEMORY ENGINE = MEMORY
SELECT SELECT
t.id travelFk, oo.lotFk,
e.id entryFk,
b.lotFk outFk,
t.warehouseOutFk warehouseFk, t.warehouseOutFk warehouseFk,
ADDTIME(t.shipped, IFNULL(shipmentHour, '00:00:00')) dated, ADDTIME(t.shipped, IFNULL(shipmentHour, '00:00:00')) dated,
t.isDelivered isPicked, t.isDelivered isPicked,
b.itemFk, b.itemFk,
b.quantity, b.quantity,
b.created 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.entry e ON e.id = b.entryFk
JOIN vn.travel t ON t.id = e.travelFk JOIN vn.travel t ON t.id = e.travelFk
WHERE b.quantity > 0 WHERE oo.isAlive;
AND b.isAlive
AND (
(vTable = 'buy' AND b.lotFk = vId)
OR (vTable = 'entry' AND e.id = vId)
OR (vTable = 'travel' AND t.id = vId)
);
CREATE OR REPLACE TEMPORARY TABLE tOutDel CALL buyOut_refresh(vTable, vId, 'buy');
ENGINE = MEMORY CALL buyLot_refresh(vTable, vId);
SELECT o.outFk FROM tOutOld o
LEFT JOIN vn.buy b ON b.lotFk = o.outFk
WHERE b.lotFk IS NULL;
START TRANSACTION; DROP TEMPORARY TABLE tLotStatus, tLotAlive;
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;
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -9,55 +9,34 @@ BEGIN
INTO vExpired INTO vExpired
FROM hedera.orderConfig LIMIT 1; FROM hedera.orderConfig LIMIT 1;
CREATE OR REPLACE TEMPORARY TABLE tOutOld CREATE OR REPLACE TEMPORARY TABLE tLotStatus
ENGINE = MEMORY ENGINE = MEMORY
SELECT outFk SELECT lotFk,
FROM buyOutOrder 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 WHERE
(vTable = 'orderRow' AND outFk = vId) (vTable = 'lot' AND r.lotFk = vId)
OR (vTable = 'order' AND orderFk = vId); OR (vTable = 'order' AND o.id = vId);
CREATE OR REPLACE TEMPORARY TABLE tOutNew CREATE OR REPLACE TEMPORARY TABLE tLotAlive
ENGINE = MEMORY ENGINE = MEMORY
SELECT SELECT
o.id orderFk, oo.lotFk,
r.lotFk outFk,
r.warehouseFk, r.warehouseFk,
r.shipment dated, r.shipment dated,
r.itemFk, r.itemFk,
r.amount quantity, r.amount quantity,
r.created, r.created,
FALSE isPicked 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 JOIN hedera.`order` o ON o.id = r.orderFk
WHERE !o.confirmed WHERE oo.isAlive;
AND r.created >= vExpired
AND r.amount > 0
AND (
(vTable = 'orderRow' AND r.lotFk = vId)
OR (vTable = 'order' AND o.id = vId)
);
CREATE OR REPLACE TEMPORARY TABLE tOutDel CALL buyOut_refresh(vTable, vId, 'orderRow');
ENGINE = MEMORY
SELECT o.outFk FROM tOutOld o
LEFT JOIN hedera.orderRow r ON r.lotFk = o.outFk
WHERE r.lotFk IS NULL;
START TRANSACTION; DROP TEMPORARY TABLE tLotStatus, tLotAlive;
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;
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -3,59 +3,38 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `stock`.`buyOut_refreshSale
`vTable` VARCHAR(255), `vTable` VARCHAR(255),
`vId` INT) `vId` INT)
BEGIN BEGIN
DECLARE vPreparation INT; DECLARE vAliveDate DATE;
SELECT id INTO vPreparation SET vAliveDate = CURDATE() - INTERVAL 1 MONTH;
FROM vn.alertLevel WHERE code = 'ON_PREPARATION';
CREATE OR REPLACE TEMPORARY TABLE tOutOld CREATE OR REPLACE TEMPORARY TABLE tLotStatus
ENGINE = MEMORY ENGINE = MEMORY
SELECT outFk SELECT lotFk,
FROM buyOutSale s.quantity < 0 isExcluded,
t.landed >= vAliveDate isAlive
FROM vn.sale s
JOIN vn.ticket t ON t.id = s.ticketFk
WHERE WHERE
(vTable = 'sale' AND outFk = vId) (vTable = 'lot' AND s.lotFk = vId)
OR (vTable = 'ticket' AND ticketFk = vId); OR (vTable = 'ticket' AND t.id = vId);
CREATE OR REPLACE TEMPORARY TABLE tOutNew CREATE OR REPLACE TEMPORARY TABLE tLotAlive
ENGINE = MEMORY ENGINE = MEMORY
SELECT SELECT
t.id ticketFk, oo.lotFk,
s.lotFk outFk,
t.warehouseFk, t.warehouseFk,
t.shipped dated, t.shipped dated,
s.itemFk, s.itemFk,
s.quantity, s.quantity,
s.created, s.created,
s.isPicked OR ts.alertLevel > vPreparation isPicked s.isPicked
FROM vn.sale s FROM tLotStatus oo
JOIN vn.sale s ON s.lotFk = oo.lotFk
JOIN vn.ticket t ON t.id = s.ticketFk JOIN vn.ticket t ON t.id = s.ticketFk
JOIN vn.ticketState ts ON s.ticketFk = t.id WHERE oo.isAlive;
WHERE s.quantity >= 0
AND (
(vTable = 'sale' AND s.lotFk = vId)
OR (vTable = 'ticket' AND t.id = vId)
);
CREATE OR REPLACE TEMPORARY TABLE tOutDel CALL buyOut_refresh(vTable, vId, 'sale');
ENGINE = MEMORY
SELECT o.outFk FROM tOutOld o
LEFT JOIN vn.sale s ON s.lotFk = o.outFk
WHERE s.lotFk IS NULL;
START TRANSACTION; DROP TEMPORARY TABLE tLotStatus, tLotAlive;
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;
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -4,11 +4,7 @@ ALTER TABLE stock.buyLot
DROP KEY source, DROP KEY source,
DROP COLUMN tableName, DROP COLUMN tableName,
CHANGE tableId lotFk int(10) unsigned NOT NULL, CHANGE tableId lotFk int(10) unsigned NOT NULL,
ADD entryFk INT UNSIGNED NOT NULL, CHANGE isSync isSync tinyint(4) NOT NULL AFTER lotFk,
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,
DROP PRIMARY KEY, DROP PRIMARY KEY,
DROP COLUMN id, DROP COLUMN id,
ADD PRIMARY KEY (lotFk); ADD PRIMARY KEY (lotFk);

View File

@ -1,7 +1,7 @@
RENAME TABLE IF EXISTS stock.outbound TO stock.buyOut; RENAME TABLE IF EXISTS stock.outbound TO stock.buyOut;
ALTER TABLE 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, CHANGE id outFk int(10) UNSIGNED NOT NULL,
DROP INDEX source, DROP INDEX source,
DROP COLUMN tableId, DROP COLUMN tableId,

View File

@ -1,8 +0,0 @@
CREATE TABLE IF NOT EXISTS stock.buyOutBuy (
outFk INT UNSIGNED,
entryFk INT,
travelFk INT,
UNIQUE(outFk),
INDEX(entryFk),
INDEX(travelFk)
);

View File

@ -1,6 +0,0 @@
CREATE TABLE IF NOT EXISTS stock.buyOutOrder (
outFk INT UNSIGNED,
orderFk INT,
UNIQUE(outFk),
INDEX(orderFk)
);

View File

@ -1,6 +0,0 @@
CREATE TABLE IF NOT EXISTS stock.buyOutSale (
outFk INT UNSIGNED,
ticketFk INT,
UNIQUE(outFk),
INDEX(ticketFk)
);