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

132 lines
3.2 KiB
SQL
Raw Blame History

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`entry_splitByShelving`(vShelvingFk VARCHAR(3), vFromEntryFk INT, vToEntryFk INT)
BEGIN
/**
* Divide las compras entre dos entradas de acuerdo con lo ubicado en una matr<74>cula
*
* @param vShelvingFk Identificador de vn.shelving
* @param vFromEntryFk Entrada origen
* @param vToEntryFk Entrada destino
*/
DECLARE vBuyFk INT;
DECLARE vIshStickers INT;
DECLARE vBuyStickers INT;
DECLARE vDone BOOLEAN DEFAULT FALSE;
DECLARE cur CURSOR FOR
SELECT bb.id buyFk,
FLOOR(ish.visible / ish.packing) ishStickers,
bb.stickers buyStickers
FROM vn.itemShelving ish
JOIN (SELECT b.id, b.itemFk, b.stickers
FROM vn.buy b
WHERE b.entryFk = vFromEntryFk
ORDER BY b.stickers DESC
LIMIT 10000000000000000000) bb ON bb.itemFk = ish.itemFk
AND bb.stickers >= FLOOR(ish.visible / ish.packing)
WHERE shelvingFk = vShelvingFk COLLATE utf8_general_ci
GROUP BY ish.id;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
-- Cantidades de la matrícula que exceden la de las entradas
SELECT ish.itemFk,
i.longName,
FLOOR(ish.visible / ish.packing) AS etiEnMatricula,
bb.stickers etiEnEntrada
FROM vn.itemShelving ish
JOIN vn.item i ON i.id = ish.itemFk
LEFT JOIN (SELECT b.id, b.itemFk, b.stickers
FROM vn.buy b
WHERE b.entryFk = vFromEntryFk
ORDER BY b.stickers DESC
LIMIT 10000000000000000000) bb ON bb.itemFk = ish.itemFk
WHERE shelvingFk = vShelvingFk COLLATE utf8_general_ci
AND IFNULL(bb.stickers,0) < FLOOR(ish.visible / ish.packing)
GROUP BY ish.id;
OPEN cur;
read_loop: LOOP
SET vDone = FALSE;
FETCH cur INTO vBuyFk, vIshStickers, vBuyStickers;
IF vDone THEN
LEAVE read_loop;
END IF;
IF vIshStickers = vBuyStickers THEN
UPDATE vn.buy
SET entryFk = vToEntryFk
WHERE id = vBuyFk;
ELSE
UPDATE vn.buy
SET stickers = stickers - vIshStickers,
quantity = stickers * packing
WHERE id = vBuyFk;
INSERT INTO vn.buy(entryFk,
itemFk,
quantity,
buyingValue,
freightValue,
isIgnored,
stickers,
packing,
`grouping`,
groupingMode,
containerFk,
comissionValue,
packageValue,
location,
packagingFk,
price1,
price2,
price3,
minPrice,
workerFk,
isChecked,
isPickedOff,
ektFk,
weight,
deliveryFk,
itemOriginalFk)
SELECT
vToEntryFk,
itemFk,
vIshStickers * packing,
buyingValue,
freightValue,
isIgnored,
vIshStickers,
packing,
`grouping`,
groupingMode,
containerFk,
comissionValue,
packageValue,
location,
packagingFk,
price1,
price2,
price3,
minPrice,
workerFk,
isChecked,
isPickedOff,
ektFk,
weight,
deliveryFk,
itemOriginalFk
FROM vn.buy
WHERE id = vBuyFk;
UPDATE buy SET printedStickers = vIshStickers WHERE id = LAST_INSERT_ID();
END IF;
END LOOP;
CLOSE cur;
END$$
DELIMITER ;