salix/db/routines/vn/procedures/collection_assign.sql

136 lines
3.5 KiB
MySQL
Raw Normal View History

2024-04-01 12:20:25 +00:00
DELIMITER $$
2024-08-20 08:06:10 +00:00
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`collection_assign`(
2024-01-25 16:33:54 +00:00
vUserFk INT,
OUT vCollectionFk INT
2024-04-01 12:20:25 +00:00
)
BEGIN
2024-01-25 16:33:54 +00:00
/**
* Comprueba si existen colecciones libres que se ajustan
* al perfil del usuario y le asigna la más antigua.
* Añade un registro al semillero de colecciones.
*
* @param vUserFk Id de usuario
* @param vCollectionFk Id de colección
*/
DECLARE vHasTooMuchCollections BOOL;
2024-08-27 08:47:09 +00:00
DECLARE vDone BOOL DEFAULT FALSE;
DECLARE vCollectionWorker INT;
DECLARE vMaxNotAssignedCollectionLifeTime TIME;
DECLARE vCollections CURSOR FOR
WITH collections AS (
SELECT tc.collectionFk,
SUM(sv.volume) volume,
c.saleTotalCount,
c.itemPackingTypeFk,
c.trainFk,
c.warehouseFk,
c.wagons
FROM vn.ticketCollection tc
JOIN vn.collection c ON c.id = tc.collectionFk
JOIN vn.saleVolume sv ON sv.ticketFk = tc.ticketFk
WHERE c.workerFk IS NULL
AND sv.shipped >= util.VN_CURDATE()
GROUP BY tc.collectionFk
) SELECT c.collectionFk
FROM collections c
JOIN vn.operator o
WHERE o.workerFk = vUserFk
AND (c.saleTotalCount <= o.linesLimit OR o.linesLimit IS NULL)
AND (c.itemPackingTypeFk = o.itemPackingTypeFk OR o.itemPackingTypeFk IS NULL)
AND o.numberOfWagons = c.wagons
AND o.trainFk = c.trainFk
AND o.warehouseFk = c.warehouseFk;
2024-04-01 12:20:25 +00:00
2024-08-27 08:47:09 +00:00
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
2024-01-25 16:33:54 +00:00
-- Si hay colecciones sin terminar, sale del proceso
2024-08-27 08:47:09 +00:00
2024-01-25 16:33:54 +00:00
CALL collection_get(vUserFk);
2024-08-27 08:47:09 +00:00
SELECT (pc.maxNotReadyCollections - COUNT(*)) <= 0, pc.maxNotAssignedCollectionLifeTime
INTO vHasTooMuchCollections, vMaxNotAssignedCollectionLifeTime
2024-04-29 12:54:15 +00:00
FROM productionConfig pc
2024-07-04 05:34:41 +00:00
LEFT JOIN tmp.collection ON TRUE;
2024-01-25 16:33:54 +00:00
2024-07-04 05:34:41 +00:00
DROP TEMPORARY TABLE tmp.collection;
2024-01-25 16:33:54 +00:00
IF vHasTooMuchCollections THEN
CALL util.throw('Hay colecciones pendientes');
END IF;
-- Se eliminan las colecciones sin asignar que estan obsoletas
2024-08-27 08:47:09 +00:00
2024-01-25 16:33:54 +00:00
INSERT INTO ticketTracking(stateFk, ticketFk)
2024-08-27 08:47:09 +00:00
SELECT s.id, tc.ticketFk
FROM `collection` c
JOIN ticketCollection tc ON tc.collectionFk = c.id
JOIN `state` s ON s.code = 'PRINTED_AUTO'
2024-06-25 12:00:46 +00:00
WHERE c.workerFk IS NULL
2024-08-27 08:47:09 +00:00
AND TIMEDIFF(util.VN_NOW(), c.created) > vMaxNotAssignedCollectionLifeTime;
2024-01-25 16:33:54 +00:00
2024-08-27 08:47:09 +00:00
DELETE FROM `collection`
WHERE workerFk IS NULL
AND TIMEDIFF(util.VN_NOW(), created) > vMaxNotAssignedCollectionLifeTime;
2024-01-25 16:33:54 +00:00
-- Se añade registro al semillero
2024-08-27 08:47:09 +00:00
INSERT INTO collectionHotbed(userFk) VALUES(vUserFk);
2024-01-25 16:33:54 +00:00
-- Comprueba si hay colecciones disponibles que se ajustan a su configuracion
2024-08-27 08:47:09 +00:00
OPEN vCollections;
l: LOOP
SET vDone = FALSE;
FETCH vCollections INTO vCollectionFk;
IF vDone THEN
LEAVE l;
END IF;
BEGIN
DECLARE EXIT HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
SET vCollectionFk = NULL;
RESIGNAL;
END;
START TRANSACTION;
SELECT workerFk INTO vCollectionWorker
FROM `collection`
WHERE id = vCollectionFk FOR UPDATE;
IF vCollectionWorker IS NULL THEN
UPDATE `collection`
SET workerFk = vUserFk
WHERE id = vCollectionFk;
COMMIT;
LEAVE l;
END IF;
ROLLBACK;
END;
END LOOP;
CLOSE vCollections;
2024-01-25 16:33:54 +00:00
IF vCollectionFk IS NULL THEN
CALL collection_new(vUserFk, vCollectionFk);
2024-06-25 12:00:46 +00:00
2024-10-06 07:07:48 +00:00
START TRANSACTION;
SELECT workerFk INTO vCollectionWorker
FROM `collection`
WHERE id = vCollectionFk FOR UPDATE;
IF vCollectionWorker IS NULL THEN
UPDATE `collection`
SET workerFk = vUserFk
WHERE id = vCollectionFk;
END IF;
COMMIT;
2024-08-27 08:47:09 +00:00
END IF;
2024-04-01 12:20:25 +00:00
END$$
2024-08-27 08:47:09 +00:00
DELIMITER ;