129 lines
3.5 KiB
SQL
129 lines
3.5 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`itemShelvingSale_addBySale`(
|
|
vSaleFk INT,
|
|
vSectorFk 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
|
|
* @param vSectorFk Id del sector del operator
|
|
*/
|
|
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 vIsRequiredTx BOOL DEFAULT NOT @@in_transaction;
|
|
|
|
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.id = 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
|
|
AND (sc.id = vSectorFk OR vSectorFk IS NULL)
|
|
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
|
|
CALL util.tx_rollback(vIsRequiredTx);
|
|
RESIGNAL;
|
|
END;
|
|
|
|
CALL util.tx_start(vIsRequiredTx);
|
|
|
|
SELECT id INTO vSaleFk
|
|
FROM sale
|
|
WHERE id = vSaleFk
|
|
FOR UPDATE;
|
|
|
|
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.id = ish.shelvingFk
|
|
LEFT JOIN parking p ON p.id = sh.parkingFk
|
|
WHERE s.id = vSaleFk;
|
|
|
|
IF vOutStanding <= 0 THEN
|
|
CALL util.tx_commit(vIsRequiredTx);
|
|
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
|
|
CALL util.debugAdd('itemShelvingSale_addBySale',
|
|
CONCAT(vSaleFk, ' - ', vSaleQuantity,' - ', vTotalReservedQuantity,'-', vOutStanding,'-', account.myUser_getId()));
|
|
|
|
UPDATE sale
|
|
SET quantity = vTotalReservedQuantity
|
|
WHERE id = vSaleFk;
|
|
END IF;
|
|
LEAVE l;
|
|
END IF;
|
|
|
|
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
|
|
CALL util.debugAdd('itemShelvingSale_addBySale_reservedQuantity',
|
|
CONCAT(vSaleFk, ' - ', vReservedQuantity, ' - ', vOutStanding, account.myUser_getId()));
|
|
INSERT INTO itemShelvingSale(
|
|
itemShelvingFk,
|
|
saleFk,
|
|
quantity,
|
|
userFk,
|
|
isPicked)
|
|
SELECT vItemShelvingFk,
|
|
vSaleFk,
|
|
vReservedQuantity,
|
|
vUserFk,
|
|
FALSE;
|
|
|
|
UPDATE itemShelving
|
|
SET available = available - vReservedQuantity
|
|
WHERE id = vItemShelvingFk;
|
|
|
|
END IF;
|
|
END LOOP;
|
|
CLOSE vItemShelvingAvailable;
|
|
CALL util.tx_commit(vIsRequiredTx);
|
|
END$$
|
|
DELIMITER ; |