92 lines
1.8 KiB
SQL
92 lines
1.8 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `stock`.`buyLot_refresh`(
|
|
`vTable` ENUM('lot', 'entry', 'travel'),
|
|
`vId` INT)
|
|
BEGIN
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
BEGIN
|
|
ROLLBACK;
|
|
RESIGNAL;
|
|
END;
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tBuyAlive
|
|
ENGINE = MEMORY
|
|
SELECT
|
|
t.id travelFk,
|
|
t.landed,
|
|
t.landingHour,
|
|
t.warehouseInFk,
|
|
t.isReceived,
|
|
t.isRaid,
|
|
e.id entryFk,
|
|
b.lotFk,
|
|
b.itemFk,
|
|
b.life,
|
|
b.quantity
|
|
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 oo.isIncluded;
|
|
|
|
START TRANSACTION;
|
|
|
|
-- Delete excluded/deleted/dead lots
|
|
|
|
DELETE l FROM buyLot l
|
|
JOIN tLotStatus oo USING(lotFk)
|
|
WHERE NOT oo.isIncluded;
|
|
|
|
-- 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.isIncluded;
|
|
|
|
DELETE p FROM buyPick p
|
|
JOIN tLotStatus oo USING(lotFk)
|
|
WHERE oo.isExcluded OR oo.isIncluded;
|
|
|
|
-- Update alive outs
|
|
|
|
INSERT INTO buyLot (
|
|
lotFk,
|
|
isSync,
|
|
isPicked,
|
|
warehouseFk,
|
|
itemFk,
|
|
dated,
|
|
expired,
|
|
quantity,
|
|
available
|
|
)
|
|
SELECT
|
|
lotFk,
|
|
FALSE,
|
|
isReceived,
|
|
warehouseInFk,
|
|
itemFk,
|
|
@dated := ADDTIME(landed, IFNULL(landingHour, '00:00:00')),
|
|
@dated + INTERVAL life DAY,
|
|
quantity,
|
|
NULL
|
|
FROM tBuyAlive
|
|
ON DUPLICATE KEY UPDATE
|
|
isSync = VALUES(isSync),
|
|
isPicked = VALUES(isPicked),
|
|
warehouseFk = VALUES(warehouseFk),
|
|
itemFk = VALUES(itemFk),
|
|
dated = VALUES(dated),
|
|
expired = VALUES(expired),
|
|
quantity = VALUES(quantity),
|
|
available = VALUES(available);
|
|
|
|
COMMIT;
|
|
|
|
DROP TEMPORARY TABLE tBuyAlive;
|
|
END$$
|
|
DELIMITER ;
|