salix/db/routines/vn/procedures/itemShelvingSale_setQuantit...

94 lines
2.7 KiB
SQL

DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_setQuantity`(
vItemShelvingSaleFk INT(10),
vQuantity DECIMAL(10,0),
vIsItemShelvingSaleEmpty BOOLEAN
)
BEGIN
/**
* Gestiona la reserva de un itemShelvingFk, actualizando isPicked y quantity
* en itemShelvingSale y sale.isPicked en caso necesario.
* Si la reserva de la ubicación es fallida, se regulariza la situación
*
* @param vItemShelvingSaleFk Id itemShelvingSaleFK
* @param vQuantity Cantidad real que se ha cogido de la ubicación
* @param vIsItemShelvingSaleEmpty determina si la ubicación itemShelvingSale se ha
* quedado vacio tras el movimiento
*/
DECLARE vSaleFk INT;
DECLARE vItemShelvingFk INT;
DECLARE vReservedQuantity INT;
DECLARE vRemainingQuantity INT;
DECLARE vItemFk INT;
DECLARE vTotalQuantity INT;
DECLARE EXIT HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
RESIGNAL;
END;
IF (SELECT isPicked FROM itemShelvingSale WHERE id = vItemShelvingSaleFk) THEN
CALL util.throw('Reservation completed');
END IF;
SELECT s.itemFk, iss.saleFk, iss.itemShelvingFk, SUM(IFNULL(iss.quantity,0))
INTO vItemFk, vSaleFk, vItemShelvingFk, vReservedQuantity
FROM itemShelvingSale iss
JOIN sale s ON s.id = iss.saleFk
WHERE iss.id = vItemShelvingSaleFk
AND NOT iss.isPicked;
IF vQuantity > vReservedQuantity
OR (vQuantity < vReservedQuantity AND
(NOT vIsItemShelvingSaleEmpty OR vIsItemShelvingSaleEmpty IS NULL))
OR (vIsItemShelvingSaleEmpty IS NOT NULL AND vQuantity = vReservedQuantity) THEN
CALL util.throw('The quantity cannot be different from the reserved');
END IF;
START TRANSACTION;
UPDATE itemShelvingSale
SET isPicked = TRUE,
quantity = vQuantity
WHERE id = vItemShelvingSaleFk;
SELECT id INTO vItemShelvingFk
FROM itemShelving
WHERE id = vItemShelvingFk
FOR UPDATE;
UPDATE itemShelving
SET visible = GREATEST(0, visible - vQuantity)
WHERE id = vItemShelvingFk;
SELECT SUM(IF(isPicked, 0, quantity)), SUM(quantity)
INTO vRemainingQuantity, vTotalQuantity
FROM itemShelvingSale
WHERE saleFk = vSaleFk;
IF vRemainingQuantity = 0 AND NOT vIsItemShelvingSaleEmpty THEN
CALL saleTracking_new(
vSaleFk,
TRUE,
vTotalQuantity,
`account`.`myUser_getId`(),
NULL,
'PREPARED',
TRUE);
UPDATE sale s
SET s.quantity = vTotalQuantity,
isPicked = TRUE
WHERE s.id = vSaleFk;
END IF;
COMMIT;
IF vIsItemShelvingSaleEmpty AND vQuantity <> vReservedQuantity THEN
INSERT INTO itemShelvingSaleReserve (saleFk)
SELECT vSaleFk;
CALL itemShelvingSale_reallocate(vItemShelvingFk, vItemFk);
END IF;
END$$
DELIMITER ;