51 lines
1.4 KiB
SQL
51 lines
1.4 KiB
SQL
|
|
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`itemShelvingSale_addByCollection`(
|
|
vCollectionFk INT(11)
|
|
)
|
|
BEGIN
|
|
/**
|
|
* Reserva cantidades con ubicaciones para el contenido de una colección
|
|
*
|
|
* @param vCollectionFk Identificador de collection
|
|
*/
|
|
DECLARE vDone BOOL DEFAULT FALSE;
|
|
DECLARE vSaleFk INT;
|
|
DECLARE vSales CURSOR FOR
|
|
WITH sales AS (
|
|
SELECT s.id saleFk, s.quantity, SUM(IFNULL(iss.quantity, 0)) quantityReserved
|
|
FROM vn.ticketCollection tc
|
|
JOIN vn.sale s ON s.ticketFk = tc.ticketFk
|
|
LEFT JOIN vn.itemShelvingSale iss ON iss.saleFk = s.id
|
|
WHERE tc.collectionFk = vCollectionFk
|
|
GROUP BY s.id
|
|
HAVING quantity <> quantityReserved
|
|
), trackedSales AS (
|
|
SELECT sa.saleFk
|
|
FROM sales sa
|
|
JOIN vn.saleTracking st ON st.saleFk = sa.saleFk
|
|
JOIN vn.`state` s ON s.id = st.stateFk
|
|
WHERE st.isChecked
|
|
AND s.`code` IN ('PREVIOUS_PREPARATION', 'OK PREVIOUS', 'OK STOWAWAY')
|
|
GROUP BY sa.saleFk
|
|
) SELECT s.saleFk
|
|
FROM sales s
|
|
LEFT JOIN trackedSales ts ON ts.saleFk = s.saleFk
|
|
WHERE ts.saleFk IS NULL;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
|
|
OPEN vSales;
|
|
l: LOOP
|
|
SET vDone = FALSE;
|
|
FETCH vSales INTO vSaleFk;
|
|
|
|
IF vDone THEN
|
|
LEAVE l;
|
|
END IF;
|
|
|
|
CALL itemShelvingSale_addBySale(vSaleFk, NULL);
|
|
END LOOP;
|
|
CLOSE vSales;
|
|
END$$
|
|
DELIMITER ; |