Actualizar db/routines/vn/procedures/itemShelvingSale_addBySale.sql
gitea/salix/pipeline/pr-test There was a failure building this commit Details
gitea/salix/pipeline/head There was a failure building this commit Details

This commit is contained in:
Carlos Andrés 2024-07-12 08:27:24 +00:00
parent b883d0ee2b
commit b93601d6d8
1 changed files with 113 additions and 101 deletions

View File

@ -1,102 +1,114 @@
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_addBySale`(
vSaleFk INT
)
proc: BEGIN
/**
* Reserva una línea de venta en la ubicación más óptima
*
* @param vSaleFk Id de sale
* @param vItemShelvingSaleFk Id de reserva
*/
DECLARE vLastPickingOrder INT;
DECLARE vDone INT DEFAULT FALSE;
DECLARE vItemShelvingFk INT;
DECLARE vAvailable INT;
DECLARE vReservedQuantity INT;
DECLARE vOutStanding INT;
DECLARE vUserFk INT;
DECLARE vItemShelvingAvailable CURSOR FOR
SELECT ish.id itemShelvingFk,
ish.available
FROM sale s
JOIN itemShelving ish ON ish.itemFk = s.itemFk
JOIN shelving sh ON sh.code = ish.shelvingFk
JOIN parking p ON p.id = sh.parkingFk
JOIN sector sc ON sc.id = p.sectorFk
JOIN productionConfig pc
WHERE s.id = vSaleFk
AND NOT sc.isHideForPickers
ORDER BY s.id,
p.pickingOrder >= vLastPickingOrder,
sh.priority DESC,
ish.available >= s.quantity DESC,
s.quantity MOD ish.grouping = 0 DESC,
ish.grouping DESC,
IF(pc.orderMode = 'Location', p.pickingOrder, ish.created);
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
DECLARE EXIT HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
RESIGNAL;
END;
SELECT MAX(p.pickingOrder), s.quantity - SUM(IFNULL(iss.quantity, 0))
INTO vLastPickingOrder, vOutStanding
FROM sale s
LEFT JOIN itemShelvingSale iss ON iss.saleFk = s.id
LEFT JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
LEFT JOIN shelving sh ON sh.code = ish.shelvingFk
LEFT JOIN parking p ON p.id = sh.parkingFk
WHERE s.id = vSaleFk;
IF vOutStanding <= 0 THEN
LEAVE proc;
END IF;
SELECT getUser() INTO vUserFk;
OPEN vItemShelvingAvailable;
l: LOOP
SET vDone = FALSE;
FETCH vItemShelvingAvailable INTO vItemShelvingFk, vAvailable;
IF vOutStanding <= 0 OR vDone THEN
LEAVE l;
END IF;
START TRANSACTION;
SELECT id INTO vItemShelvingFk
FROM itemShelving
WHERE id = vItemShelvingFk
FOR UPDATE;
SELECT LEAST(vOutStanding, vAvailable) INTO vReservedQuantity;
SET vOutStanding = vOutStanding - vReservedQuantity;
IF vReservedQuantity > 0 THEN
INSERT INTO itemShelvingSale(
itemShelvingFk,
saleFk,
quantity,
userFk)
SELECT vItemShelvingFk,
vSaleFk,
vReservedQuantity,
vUserFk;
UPDATE itemShelving
SET available = available - vReservedQuantity
WHERE id = vItemShelvingFk;
END IF;
COMMIT;
END LOOP;
CLOSE vItemShelvingAvailable;
END$$
DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_addBySale`(
vSaleFk INT
)
proc: BEGIN
/**
* Reserva una línea de venta en la ubicación más óptima
*
* @param vSaleFk Id de sale
* @param vItemShelvingSaleFk Id de reserva
*/
DECLARE vLastPickingOrder INT;
DECLARE vDone INT DEFAULT FALSE;
DECLARE vItemShelvingFk INT;
DECLARE vAvailable INT;
DECLARE vReservedQuantity INT;
DECLARE vOutStanding INT;
DECLARE vUserFk INT;
DECLARE vTotalReservedQuantity INT;
DECLARE vSaleQuantity INT;
DECLARE vItemShelvingAvailable CURSOR FOR
SELECT ish.id itemShelvingFk,
ish.available
FROM sale s
JOIN itemShelving ish ON ish.itemFk = s.itemFk
JOIN shelving sh ON sh.code = ish.shelvingFk
JOIN parking p ON p.id = sh.parkingFk
JOIN sector sc ON sc.id = p.sectorFk
JOIN productionConfig pc
WHERE s.id = vSaleFk
AND NOT sc.isHideForPickers
ORDER BY s.id,
p.pickingOrder >= vLastPickingOrder,
sh.priority DESC,
ish.available >= s.quantity DESC,
s.quantity MOD ish.grouping = 0 DESC,
ish.grouping DESC,
IF(pc.orderMode = 'Location', p.pickingOrder, ish.created);
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
DECLARE EXIT HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
RESIGNAL;
END;
SELECT MAX(p.pickingOrder), s.quantity - SUM(IFNULL(iss.quantity, 0)), s.quantity
INTO vLastPickingOrder, vOutStanding, vSaleQuantity
FROM sale s
LEFT JOIN itemShelvingSale iss ON iss.saleFk = s.id
LEFT JOIN itemShelving ish ON ish.id = iss.itemShelvingFk
LEFT JOIN shelving sh ON sh.code = ish.shelvingFk
LEFT JOIN parking p ON p.id = sh.parkingFk
WHERE s.id = vSaleFk;
IF vOutStanding <= 0 THEN
LEAVE proc;
END IF;
SELECT getUser() INTO vUserFk;
OPEN vItemShelvingAvailable;
l: LOOP
SET vDone = FALSE;
FETCH vItemShelvingAvailable INTO vItemShelvingFk, vAvailable;
IF vOutStanding <= 0 OR vDone THEN
SELECT SUM(IFNULL(quantity, 0))
INTO vTotalReservedQuantity
FROM itemShelvingSale
WHERE saleFk = vSaleFk;
IF vTotalReservedQuantity <> vSaleQuantity THEN
UPDATE sale
SET quantity = vTotalReservedQuantity
WHERE id = vSaleFk;
END IF
LEAVE l;
END IF;
START TRANSACTION;
SELECT id INTO vItemShelvingFk
FROM itemShelving
WHERE id = vItemShelvingFk
FOR UPDATE;
SELECT LEAST(vOutStanding, vAvailable) INTO vReservedQuantity;
SET vOutStanding = vOutStanding - vReservedQuantity;
IF vReservedQuantity > 0 THEN
INSERT INTO itemShelvingSale(
itemShelvingFk,
saleFk,
quantity,
userFk)
SELECT vItemShelvingFk,
vSaleFk,
vReservedQuantity,
vUserFk;
UPDATE itemShelving
SET available = available - vReservedQuantity
WHERE id = vItemShelvingFk;
END IF;
COMMIT;
END LOOP;
CLOSE vItemShelvingAvailable;
END$$
DELIMITER ;