55 lines
1.4 KiB
MySQL
55 lines
1.4 KiB
MySQL
|
DELIMITER $$
|
||
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`stockBought_calculate`()
|
||
|
BEGIN
|
||
|
/**
|
||
|
* Inserts the purchase volume per buyer
|
||
|
* into stockBought according to the date.
|
||
|
*
|
||
|
* @param vDated Purchase date
|
||
|
*/
|
||
|
DECLARE vDated DATE;
|
||
|
SET vDated = util.VN_CURDATE();
|
||
|
|
||
|
CREATE OR REPLACE TEMPORARY TABLE tStockBought
|
||
|
SELECT workerFk, reserve
|
||
|
FROM stockBought
|
||
|
WHERE dated = vDated
|
||
|
AND reserve;
|
||
|
|
||
|
DELETE FROM stockBought WHERE dated = vDated;
|
||
|
|
||
|
INSERT INTO stockBought (workerFk, bought, dated)
|
||
|
SELECT it.workerFk,
|
||
|
ROUND(SUM(
|
||
|
(ac.conversionCoefficient *
|
||
|
(b.quantity / b.packing) *
|
||
|
buy_getVolume(b.id)
|
||
|
) / (vc.trolleyM3 * 1000000)
|
||
|
), 1),
|
||
|
vDated
|
||
|
FROM entry e
|
||
|
JOIN travel t ON t.id = e.travelFk
|
||
|
JOIN warehouse w ON w.id = t.warehouseInFk
|
||
|
JOIN buy b ON b.entryFk = e.id
|
||
|
JOIN item i ON i.id = b.itemFk
|
||
|
JOIN itemType it ON it.id = i.typeFk
|
||
|
JOIN auctionConfig ac
|
||
|
JOIN volumeConfig vc
|
||
|
WHERE t.shipped = vDated
|
||
|
AND t.warehouseInFk = ac.warehouseFk
|
||
|
GROUP BY it.workerFk;
|
||
|
|
||
|
UPDATE stockBought s
|
||
|
JOIN tStockBought 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 tStockBought ts
|
||
|
WHERE ts.workerFk NOT IN (SELECT workerFk FROM stockBought WHERE dated = vDated);
|
||
|
|
||
|
DROP TEMPORARY TABLE tStockBought;
|
||
|
END$$
|
||
|
DELIMITER ;
|