73 lines
1.8 KiB
SQL
73 lines
1.8 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sale_setProblemRoundingByBuy`(
|
|
vBuyFk INT
|
|
)
|
|
BEGIN
|
|
/**
|
|
* Update rounding problem for all sales related to a buy.
|
|
*
|
|
* @param vBuyFk Buy id
|
|
*/
|
|
DECLARE vItemFk INT;
|
|
DECLARE vWareHouseFk INT;
|
|
DECLARE vMaxDated DATE;
|
|
DECLARE vMinDated DATE;
|
|
DECLARE vLanding DATE;
|
|
DECLARE vLastBuy INT;
|
|
DECLARE vCurrentBuy INT;
|
|
DECLARE vGrouping INT;
|
|
|
|
SELECT b.itemFk, t.warehouseInFk
|
|
INTO vItemFk, vWareHouseFk
|
|
FROM buy b
|
|
JOIN entry e ON e.id = b.entryFk
|
|
JOIN travel t ON t.id = e.travelFk
|
|
WHERE b.id = vBuyFk;
|
|
|
|
SELECT DATE(MAX(t.shipped)) + INTERVAL 1 DAY, DATE(MIN(t.shipped))
|
|
INTO vMaxDated, vMinDated
|
|
FROM sale s
|
|
JOIN ticket t ON t.id = s.ticketFk
|
|
WHERE t.shipped >= util.VN_CURDATE()
|
|
AND s.itemFk = vItemFk
|
|
AND s.quantity > 0;
|
|
|
|
CALL buy_getUltimate(vItemFk, vWareHouseFk, vMinDated);
|
|
|
|
SELECT bu.buyFk, b.grouping INTO vLastBuy, vGrouping
|
|
FROM tmp.buyUltimate bu
|
|
JOIN buy b ON b.id = bu.buyFk;
|
|
|
|
DROP TEMPORARY TABLE tmp.buyUltimate;
|
|
|
|
SET vLanding = vMaxDated;
|
|
|
|
WHILE vCurrentBuy <> vLastBuy OR vLanding > vMinDated DO
|
|
SET vMaxDated = vLanding - INTERVAL 1 DAY;
|
|
|
|
CALL buy_getUltimate(vItemFk, vWareHouseFk, vMaxDated);
|
|
|
|
SELECT buyFk, landing
|
|
INTO vCurrentBuy, vLanding
|
|
FROM tmp.buyUltimate;
|
|
|
|
DROP TEMPORARY TABLE tmp.buyUltimate;
|
|
END WHILE;
|
|
|
|
CREATE OR REPLACE TEMPORARY TABLE tmp.sale
|
|
(INDEX(saleFk, isProblemCalcNeeded))
|
|
ENGINE = MEMORY
|
|
SELECT s.id saleFk,
|
|
MOD(s.quantity, vGrouping) hasProblem,
|
|
ticket_isProblemCalcNeeded(t.id) isProblemCalcNeeded
|
|
FROM sale s
|
|
JOIN ticket t ON t.id = s.ticketFk
|
|
WHERE s.itemFk = vItemFk
|
|
AND s.quantity > 0
|
|
AND t.shipped BETWEEN vMinDated AND util.dayEnd(vMaxDated);
|
|
|
|
CALL sale_setProblem('hasRounding');
|
|
|
|
DROP TEMPORARY TABLE tmp.sale;
|
|
END$$
|
|
DELIMITER ; |