salix/db/routines/vn/procedures/stockBought_calculate.sql

89 lines
2.5 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`stockBought_calculate`(
vDated DATE
)
proc: BEGIN
/**
* Calculate the stock of the auction warehouse from the inventory date to vDated
* without taking into account the outputs of the same day vDated
*
* @param vDated Date to calculate the stock
*/
IF vDated < util.VN_CURDATE() THEN
LEAVE proc;
END IF;
CREATE OR REPLACE TEMPORARY TABLE tCurrentData
SELECT workerFk, reserve
FROM stockBought
WHERE dated = vDated
AND reserve;
DELETE FROM stockBought WHERE dated = vDated;
CREATE OR REPLACE TEMPORARY TABLE tStockSold
SELECT it.workerFk,
SUM(ic.cm3 * ito.quantity / vc.palletM3 / 1000000) sold
FROM itemTicketOut ito
JOIN item i ON i.id = ito.itemFk
JOIN itemType it ON it.id = i.typeFk
JOIN ticket t ON t.id = ito.ticketFk
JOIN warehouse wh ON wh.id = t.warehouseFk
JOIN itemCost ic ON ic.itemFk = ito.itemFk
AND ic.warehouseFk = t.warehouseFk
JOIN volumeConfig vc
WHERE ito.shipped BETWEEN vDated AND util.dayEnd(vDated)
AND wh.code = 'VNH'
GROUP BY it.workerFk;
CALL item_calculateStock(vDated);
CREATE OR REPLACE TEMPORARY TABLE tStockBought
SELECT it.workerFk,
SUM((ti.quantity / b.packing) *
buy_getVolume(b.id)
) / vc.palletM3 / 1000000 bought
FROM itemType it
JOIN item i ON i.typeFk = it.id
LEFT JOIN tmp.item ti ON ti.itemFk = i.id
JOIN itemCategory ic ON ic.id = it.categoryFk
JOIN warehouse wh ON wh.code = 'VNH'
JOIN tmp.buyUltimate bu ON bu.itemFk = i.id
AND bu.warehouseFk = wh.id
JOIN buy b ON b.id = bu.buyFk
JOIN volumeConfig vc
WHERE ic.display
GROUP BY it.workerFk
HAVING bought;
INSERT INTO stockBought(workerFk, bought, dated)
SELECT tb.workerFk,
ROUND(GREATEST(tb.bought - IFNULL(ts.sold, 0), 0), 2),
vDated
FROM tStockBought tb
LEFT JOIN tStockSold ts ON ts.workerFk = tb.workerFk;
UPDATE stockBought s
JOIN tCurrentData ts ON ts.workerFk = s.workerFk
SET s.reserve = ts.reserve
WHERE s.dated = vDated;
INSERT INTO stockBought (workerFk, reserve, dated)
SELECT ts.workerFk, ts.reserve, vDated
FROM tCurrentData ts
WHERE ts.workerFk NOT IN (
SELECT workerFk
FROM stockBought
WHERE dated = vDated
);
UPDATE stockBought s
JOIN tStockSold ts ON ts.workerFk = s.workerFk
SET s.bought = IF(s.bought < ABS(ts.sold), 0, ROUND(s.bought - ABS(ts.sold), 1))
WHERE s.dated = vDated;
DROP TEMPORARY TABLE tCurrentData, tmp.item, tmp.buyUltimate, tStockSold;
END$$
DELIMITER ;