salix/db/routines/stock/procedures/buyLot_refresh.sql

124 lines
2.4 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `stock`.`buyLot_refresh`(
`vTable` ENUM('buy', 'entry', 'travel'),
`vId` INT)
BEGIN
START TRANSACTION;
-- Update cache
CREATE OR REPLACE TEMPORARY TABLE tLotOld
ENGINE = MEMORY
SELECT buyFk
FROM buyLot
WHERE
(vTable = 'travel' AND travelFk = vId)
OR (vTable = 'entry' AND entryFk = vId)
OR (vTable = 'buy' AND buyFk = vId);
CREATE OR REPLACE TEMPORARY TABLE tLotNew
ENGINE = MEMORY
SELECT
t.id travelFk,
t.landed,
t.landingHour,
t.warehouseInFk,
t.isReceived,
t.isRaid,
e.id entryFk,
b.id buyFk,
b.itemFk,
b.life,
b.quantity,
b.available
FROM vn.buy b
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 = 'travel' AND t.id = vId)
OR (vTable = 'entry' AND e.id = vId)
OR (vTable = 'buy' AND b.id = vId)
);
DELETE FROM buyLot
WHERE buyFk IN (
SELECT buyFk FROM tLotOld
EXCEPT
SELECT buyFk FROM tLotNew
);
INSERT INTO buyLot (
buyFk,
entryFk,
travelFk,
isSync,
isPicked,
warehouseFk,
itemFk,
dated,
expired,
quantity,
available
)
SELECT
buyFk,
entryFk,
travelFk,
FALSE,
isReceived,
warehouseInFk,
itemFk,
@dated := ADDTIME(landed, IFNULL(landingHour, '00:00:00')),
@dated + INTERVAL life DAY,
quantity,
NULL
FROM tLotNew
ON DUPLICATE KEY UPDATE
entryFk = VALUES(entryFk),
travelFk = VALUES(travelFk),
isSync = VALUES(isSync),
isPicked = VALUES(isPicked),
warehouseFk = VALUES(warehouseFk),
itemFk = VALUES(itemFk),
dated = VALUES(dated),
expired = VALUES(expired),
quantity = VALUES(quantity),
available = VALUES(available);
-- Remove picks from updated and removed lots
CREATE OR REPLACE TEMPORARY TABLE tLotPrune
ENGINE = MEMORY
SELECT buyFk FROM tLotNew
UNION
SELECT buyFk FROM tLotOld o
LEFT JOIN vn.buy b ON b.id = o.buyFk
WHERE b.id IS NULL;
UPDATE buyOut o
JOIN buyPick p
ON p.tableName = o.tableName AND p.tableId = o.tableId
JOIN tLotPrune pl
ON pl.buyFk = p.buyFk
SET o.isSync = FALSE,
o.lack = o.lack + p.quantity;
DELETE p FROM buyPick p
JOIN tLotPrune pl USING(buyFk);
DROP TEMPORARY TABLE
tLotOld,
tLotNew,
tLotPrune;
COMMIT;
-- Refresh outs
CALL buyOut_refreshBuy(vTable, vId);
END$$
DELIMITER ;