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

57 lines
1.5 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`itemShelving_transfer`(
vItemShelvingFk INT,
vShelvingCode VARCHAR(10)
)
BEGIN
/**
* Transfiere producto de una ubicación a otra
* fusionando si coincide el packing y la fecha.
*
* @param vItemShelvingFk Identificador de itemShelving
* @param vShelvingCode Código de shelving
*/
DECLARE vNewItemShelvingFk INT;
DECLARE vShelvingFk INT;
SELECT id INTO vShelvingFk
FROM shelving
WHERE code COLLATE utf8_unicode_ci = vShelvingCode;
SELECT MAX(ish.id) INTO vNewItemShelvingFk
FROM itemShelving ish
JOIN (
SELECT itemFk,
packing,
created,
buyFk
FROM itemShelving
WHERE id = vItemShelvingFk
) ish2 ON ish2.itemFk = ish.itemFk
AND ish2.packing = ish.packing
AND DATE(ish2.created) = DATE(ish.created)
AND ish2.buyFk = ish.buyFk
WHERE ish.shelvingFk = vShelvingFk;
IF vNewItemShelvingFk THEN
UPDATE itemShelving ish
JOIN itemShelving ish2 ON ish2.id = vItemShelvingFk
SET ish.visible = ish.visible + ish2.visible,
ish.available = ish.available + ish2.available
WHERE ish.id = vNewItemShelvingFk;
DELETE FROM itemShelving
WHERE id = vItemShelvingFk;
ELSE
IF (SELECT EXISTS(SELECT id FROM shelving WHERE id = vShelvingFk)) THEN
UPDATE itemShelving
SET shelvingFk = vShelvingFk
WHERE id = vItemShelvingFk;
ELSE
CALL util.throw('The shelving not exists');
END IF;
END IF;
SELECT TRUE;
END$$
DELIMITER ;