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

82 lines
1.9 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`buy_afterUpsert`(vSelf INT)
BEGIN
/**
* Triggered actions when a buy is updated or inserted.
*
* @param vSelf The buy reference
*/
DECLARE vEntryFk INT;
DECLARE vItemFk INT;
DECLARE vPackingOut DECIMAL(10,2);
DECLARE vWarehouse INT;
DECLARE vStandardFlowerBox INT;
DECLARE vWarehouseOut INT;
DECLARE vIsMerchandise BOOL;
DECLARE vIsFeedStock BOOL;
DECLARE vWeight DECIMAL(10,2);
DECLARE vPacking INT;
SELECT b.entryFk,
b.itemFk,
i.packingOut,
ic.merchandise,
vc.standardFlowerBox,
b.weight,
b.packing
INTO
vEntryFk,
vItemFk,
vPackingOut,
vIsMerchandise,
vStandardFlowerBox,
vWeight,
vPacking
FROM buy b
LEFT JOIN item i ON i.id = b.itemFk
LEFT JOIN itemType it ON it.id = i.typeFk
LEFT JOIN itemCategory ic ON ic.id = it.categoryFk
LEFT JOIN packaging p ON p.id = b.packagingFk AND NOT p.isBox
JOIN volumeConfig vc ON TRUE
WHERE b.id = vSelf;
SELECT t.warehouseInFk, t.warehouseOutFk
INTO vWarehouse, vWarehouseOut
FROM entry e
JOIN travel t ON t.id = e.travelFk
WHERE e.id = vEntryFk;
IF vIsMerchandise THEN
REPLACE itemCost SET
itemFk = vItemFk,
warehouseFk = vWarehouse,
cm3 = buy_getUnitVolume(vSelf),
cm3Delivery = IFNULL((vStandardFlowerBox * 1000) / vPackingOut, buy_getUnitVolume(vSelf));
IF vWeight AND vPacking THEN
UPDATE itemCost SET
grams = vWeight * 1000 / vPacking
WHERE itemFk = vItemFk
AND warehouseFk = vWarehouse;
END IF;
END IF;
SELECT isFeedStock INTO vIsFeedStock
FROM warehouse WHERE id = vWarehouseOut;
IF vIsFeedStock THEN
INSERT IGNORE INTO producer(`name`)
SELECT es.company_name
FROM buy b
JOIN edi.ekt be ON be.id = b.ektFk
JOIN edi.supplier es ON es.supplier_id = be.pro
WHERE b.id = vSelf;
END IF;
CREATE OR REPLACE TEMPORARY TABLE tmp.buysToCheck
SELECT vSelf id;
CALL buy_checkItem();
END$$
DELIMITER ;