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

127 lines
2.5 KiB
MySQL
Raw Normal View History

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 tOldLot
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 tNewLot
ENGINE = MEMORY
SELECT
t.id travelFk,
t.landed,
t.landingHour,
t.warehouseInFk,
t.isReceived,
e.id entryFk,
e.isRaid,
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 t.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 tOldLot
EXCEPT
SELECT buyFk FROM tNewLot
);
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,
available
FROM tNewLot
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);
-- Update picks
CREATE OR REPLACE TEMPORARY TABLE tAliveBuys
ENGINE = MEMORY
SELECT b.id buyFk
FROM vn.buy b
JOIN vn.entry e ON e.id = b.entryFk
JOIN vn.travel t ON t.id = e.travelFk
WHERE t.isAlive
AND b.id IN (
SELECT buyFk FROM tOldLot
UNION
SELECT buyFk FROM tNewLot
);
UPDATE buyOut o
JOIN buyPick p
ON p.source = o.tableName AND p.outFk = o.tableId
JOIN tAliveBuys a
ON a.buyFk = p.buyFk
SET o.isSync = FALSE,
o.lack = o.lack + p.quantity;
DELETE p FROM buyPick p
JOIN tAliveBuys a USING(buyFk);
DROP TEMPORARY TABLE
tOldLot,
tNewLot,
tAliveBuys;
COMMIT;
CALL buyOut_refreshBuy(vTable, vId);
END$$
DELIMITER ;