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

352 lines
7.4 KiB
MySQL
Raw Normal View History

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_devalueA2`(
vShelvingFK VARCHAR(10),
vItemFk INT,
vBuyingValue DECIMAL(10,4),
vQuantity INT
)
BEGIN
/**
* Devalua un item modificando su calidad de A1 a A2.
* Si no existe el item A2 lo crea y genera los movimientos de las entradas
* de almacén y shelvings correspondientes
*
* @param vShelvingFK Ubicación actual del artículo
* @param vItemFk Id de artículo a devaluar
* @param vBuyingValue Nuevo precio de coste
*/
DECLARE vItemA2Fk INT;
DECLARE vLastBuyFk BIGINT;
DECLARE vA1BuyFk INT;
DECLARE vA2BuyFk INT;
DECLARE vTargetEntryFk INT;
DECLARE vTargetEntryDate DATE;
DECLARE vTargetItemShelvingFk BIGINT;
DECLARE vWarehouseFk INT;
DECLARE vCacheFk INT;
DECLARE vLastEntryFk INT;
DECLARE vCurrentVisible INT;
DECLARE vInventoryTravelFk INT;
DECLARE vCurdate DATE;
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
RESIGNAL;
END;
IF (SELECT TRUE FROM item WHERE id = vItemFk AND (category <> 'A1' OR category IS NULL)) THEN
CALL util.throw('Item has not category A1');
END IF;
SELECT warehouseFk INTO vWarehouseFk
FROM userConfig
WHERE userFk = account.myUser_getId();
IF NOT vWarehouseFk OR vWarehouseFk IS NULL THEN
CALL util.throw ('Operator has not a valid warehouse');
END IF;
SELECT util.VN_CURDATE() INTO vCurdate;
SELECT t.id INTO vInventoryTravelFk
FROM travel t
JOIN travelConfig tc
WHERE t.shipped = vCurdate
AND t.landed = vCurdate
AND t.warehouseInFk = vWarehouseFk
AND t.warehouseOutFk = tc.devalueWarehouseOutFk
AND t.agencyModeFk = tc.devalueAgencyModeFk
LIMIT 1;
IF NOT vInventoryTravelFk OR vInventoryTravelFk IS NULL THEN
INSERT INTO travel (
shipped,
landed,
warehouseInFk,
warehouseOutFk,
`ref`,
isReceived,
agencyModeFk)
SELECT vCurdate,
vCurdate,
vWarehouseFk,
tc.devalueWarehouseOutFk,
tc.devalueRef,
TRUE,
tc.devalueAgencyModeFk
FROM travelConfig tc;
SET vInventoryTravelFk = LAST_INSERT_ID();
END IF;
SELECT id, dated INTO vTargetEntryFk, vTargetEntryDate
FROM `entry` e
WHERE created = vCurdate
AND typeFk ='devaluation'
AND travelFk = vInventoryTravelFk
ORDER BY created DESC
LIMIT 1;
CALL buyUltimate(vWarehouseFk, vCurdate);
SELECT b.entryFk, bu.buyFk INTO vLastEntryFk,vLastBuyFk
FROM tmp.buyUltimate bu
JOIN vn.buy b ON b.id =bu.buyFk
WHERE bu.itemFk = vItemFk
AND bu.warehouseFk = vWarehouseFk;
SELECT id,visible INTO vTargetItemShelvingFk,vCurrentVisible
FROM itemShelving
WHERE shelvingFk = vShelvingFK COLLATE utf8mb3_general_ci
AND itemFk = vItemFk
LIMIT 1;
IF vQuantity >= vCurrentVisible THEN
CALL util.throw('Quantity is greater than visible');
END IF;
START TRANSACTION;
IF NOT vTargetEntryFk OR vTargetEntryFk IS NULL
OR NOT vTargetEntryDate <=> vCurdate THEN
INSERT INTO entry(
travelFk,
supplierFk,
dated,
commission,
currencyFk,
companyFk,
clonedFrom,
typeFk
)
SELECT vInventoryTravelFk,
supplierFk,
vCurdate,
commission,
currencyFk,
companyFk,
vLastEntryFk,
'devaluation'
FROM entry
WHERE id = vLastEntryFk;
SET vTargetEntryFk = LAST_INSERT_ID();
END IF;
SELECT i.id INTO vItemA2Fk
FROM item i
JOIN (
SELECT i.id,
i.name,
i.subname,
i.value5,
i.value6,
i.value7,
i.value8,
i.value9,
i.value10,
i.NumberOfItemsPerCask,
i.EmbalageCode,
i.quality
FROM item i
WHERE i.id = vItemFk
)i2 ON i2.name <=> i.name
AND i2.subname <=> i.subname
AND i2.value5 <=> i.value5
AND i2.value6 <=> i.value6
AND i2.value8 <=> i.value8
AND i2.value9 <=> i.value9
AND i2.value10 <=> i.value10
AND i2.NumberOfItemsPerCask <=> i.NumberOfItemsPerCask
AND i2.EmbalageCode <=> i.EmbalageCode
AND i2.quality <=> i.quality
WHERE i.id <> i2.id
AND i.category = 'A2'
LIMIT 1;
IF vItemA2Fk IS NULL THEN
INSERT INTO item (
equivalent,
name,
`size`,
stems,
minPrice,
isToPrint,
family,
box,
category,
originFk,
doPhoto,
image,
inkFk,
intrastatFk,
hasMinPrice,
created,
comment,
typeFk,
generic,
producerFk,
description,
density,
relevancy,
expenseFk,
isActive,
longName,
subName,
tag5,
value5,
tag6,
value6,
tag7,
value7,
tag8,
value8,
tag9,
value9,
tag10,
value10,
minimum,
upToDown,
supplyResponseFk,
hasKgPrice,
isFloramondo,
isFragile,
numberOfItemsPerCask,
embalageCode,
quality,
stemMultiplier,
itemPackingTypeFk,
packingOut,
genericFk,
isLaid,
lastUsed,
weightByPiece,
editorFk,
recycledPlastic,
nonRecycledPlastic)
SELECT equivalent,
name,
`size`,
stems,
minPrice,
isToPrint,
family,
box,
'A2',
originFk,
doPhoto,
image,
inkFk,
intrastatFk,
hasMinPrice,
created,
comment,
typeFk,
generic,
producerFk,
description,
density,
relevancy,
expenseFk,
isActive,
longName,
subName,
tag5,
value5,
tag6,
value6,
tag7,
value7,
tag8,
value8,
tag9,
value9,
tag10,
value10,
minimum,
upToDown,
supplyResponseFk,
hasKgPrice,
isFloramondo,
isFragile,
numberOfItemsPerCask,
embalageCode,
quality,
stemMultiplier,
itemPackingTypeFk,
packingOut,
genericFk,
isLaid,
lastUsed,
weightByPiece,
editorFk,
recycledPlastic,
nonRecycledPlastic
FROM item
WHERE id = vItemFk;
SET vItemA2Fk = LAST_INSERT_ID();
UPDATE itemTaxCountry itc
JOIN itemTaxCountry itc2 ON itc2.itemFk = vItemFk
AND itc2.countryFk = itc.countryFk
SET itc2.taxClassFk = itc.taxClassFk
WHERE itc.id = vItemA2Fk;
INSERT INTO itemBotanical (itemFk, genusFk, specieFk)
SELECT vItemA2Fk, genusFk, specieFk
FROM itemBotanical
WHERE itemFk = vItemFk;
END IF;
IF vQuantity = vCurrentVisible THEN
DELETE FROM itemShelving
WHERE id = vTargetItemShelvingFk;
ELSE
UPDATE itemShelving
SET visible = vCurrentVisible - vQuantity
WHERE id = vTargetItemShelvingFk;
END IF;
CALL buy_cloneByBuy(vA1BuyFk, vLastBuyFk, vTargetEntryFk);
UPDATE buy
SET quantity = - LEAST(vQuantity,vCurrentVisible),
isIgnored = TRUE,
buyingValue = vBuyingValue
WHERE id = vA1BuyFk;
CALL buy_cloneByBuy(vA2BuyFk, vLastBuyFk, vTargetEntryFk);
UPDATE buy
SET quantity = vQuantity,
isIgnored = TRUE,
buyingValue = vBuyingValue,
itemFk = vItemA2Fk
WHERE id = vA2BuyFk;
INSERT INTO itemShelving (
itemFk,
shelvingFk,
visible,
`grouping`,
packing,
packagingFk,
userFk,
isChecked)
SELECT vItemA2Fk,
shelvingFk,
vQuantity,
`grouping`,
packing,
packagingFk,
account.myUser_getId(),
isChecked
FROM itemShelving
WHERE itemFK = vItemFk
AND shelvingFk = vShelvingFK COLLATE utf8mb3_general_ci;
COMMIT;
CALL cache.visible_refresh(vCacheFk, TRUE, vWarehouseFk);
CALL cache.available_refresh(vCacheFk, TRUE, vWarehouseFk, vCurdate);
CALL buy_recalcPricesByBuy(vA2BuyFk);
END$$
DELIMITER ;