72 lines
1.5 KiB
SQL
72 lines
1.5 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `srt`.`moving_clean`()
|
|
BEGIN
|
|
/**
|
|
* Elimina movimientos por inactividad
|
|
*/
|
|
DECLARE vExpeditionFk INT;
|
|
DECLARE vBufferFromFk INT;
|
|
DECLARE vStateOutFk INT
|
|
DEFAULT (SELECT id FROM expeditionState WHERE `description` = 'OUT');
|
|
DECLARE vDone BOOL;
|
|
DECLARE vSorter CURSOR FOR
|
|
SELECT m.expeditionFk, m.bufferFromFk
|
|
FROM moving m
|
|
JOIN (
|
|
SELECT bufferFk, SUM(isActive) hasBox
|
|
FROM photocell
|
|
GROUP BY bufferFk
|
|
) sub ON sub.bufferFk = m.bufferFromFk
|
|
WHERE m.created < (util.VN_NOW() - INTERVAL (SELECT movingMaxLife FROM config) MINUTE)
|
|
AND NOT sub.hasBox;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
BEGIN
|
|
ROLLBACK;
|
|
RESIGNAL;
|
|
END;
|
|
|
|
OPEN vSorter;
|
|
l: LOOP
|
|
SET vDone = FALSE;
|
|
FETCH vSorter INTO vExpeditionFk, vBufferFromFk;
|
|
|
|
IF vDone THEN
|
|
LEAVE l;
|
|
END IF;
|
|
|
|
START TRANSACTION;
|
|
|
|
SELECT id
|
|
FROM moving
|
|
WHERE expeditionFk = vExpeditionFk
|
|
FOR UPDATE;
|
|
|
|
DELETE FROM moving
|
|
WHERE expeditionFk = vExpeditionFk;
|
|
|
|
SELECT id
|
|
FROM expedition
|
|
WHERE id = vExpeditionFk
|
|
OR (bufferFk = vBufferFromFk AND `position` > 0)
|
|
FOR UPDATE;
|
|
|
|
UPDATE expedition
|
|
SET bufferFk = NULL,
|
|
`position` = NULL,
|
|
stateFk = vStateOutFk
|
|
WHERE id = vExpeditionFk;
|
|
|
|
UPDATE expedition
|
|
SET `position` = `position` - 1
|
|
WHERE bufferFk = vBufferFromFk
|
|
AND `position` > 0;
|
|
|
|
COMMIT;
|
|
END LOOP l;
|
|
CLOSE vSorter;
|
|
END$$
|
|
DELIMITER ;
|