|
|
|
@ -5,100 +5,139 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`collection_getAssigne
|
|
|
|
|
)
|
|
|
|
|
BEGIN
|
|
|
|
|
/**
|
|
|
|
|
* 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 y hace la reserva para la colección
|
|
|
|
|
* 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;
|
|
|
|
|
DECLARE vItemPackingTypeFk VARCHAR(1);
|
|
|
|
|
DECLARE vWarehouseFk INT;
|
|
|
|
|
DECLARE vLockName VARCHAR(215);
|
|
|
|
|
DECLARE vLockTime INT DEFAULT 30;
|
|
|
|
|
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;
|
|
|
|
|
|
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
|
|
|
-- Si hay colecciones sin terminar, sale del proceso
|
|
|
|
|
|
|
|
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
|
|
|
BEGIN
|
|
|
|
|
IF vLockName IS NOT NULL THEN
|
|
|
|
|
DO RELEASE_LOCK(vLockName);
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
ROLLBACK;
|
|
|
|
|
RESIGNAL;
|
|
|
|
|
END;
|
|
|
|
|
|
|
|
|
|
-- Si hay colecciones sin terminar, sale del proceso
|
|
|
|
|
CALL collection_get(vUserFk);
|
|
|
|
|
|
|
|
|
|
SELECT (pc.maxNotReadyCollections - COUNT(*)) <= 0,
|
|
|
|
|
pc.collection_assign_lockname
|
|
|
|
|
INTO vHasTooMuchCollections,
|
|
|
|
|
vLockName
|
|
|
|
|
FROM tmp.collection c
|
|
|
|
|
JOIN productionConfig pc;
|
|
|
|
|
SELECT (pc.maxNotReadyCollections - COUNT(*)) <= 0, pc.maxNotAssignedCollectionLifeTime
|
|
|
|
|
INTO vHasTooMuchCollections, vMaxNotAssignedCollectionLifeTime
|
|
|
|
|
FROM productionConfig pc
|
|
|
|
|
LEFT JOIN tmp.collection ON TRUE;
|
|
|
|
|
|
|
|
|
|
DROP TEMPORARY TABLE tmp.collection;
|
|
|
|
|
|
|
|
|
|
IF vHasTooMuchCollections THEN
|
|
|
|
|
CALL util.throw('There are pending collections');
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
SELECT warehouseFk, itemPackingTypeFk
|
|
|
|
|
INTO vWarehouseFk, vItemPackingTypeFk
|
|
|
|
|
FROM operator
|
|
|
|
|
WHERE workerFk = vUserFk;
|
|
|
|
|
|
|
|
|
|
SET vLockName = CONCAT_WS('/',
|
|
|
|
|
vLockName,
|
|
|
|
|
vWarehouseFk,
|
|
|
|
|
vItemPackingTypeFk
|
|
|
|
|
);
|
|
|
|
|
|
|
|
|
|
IF NOT GET_LOCK(vLockName, vLockTime) THEN
|
|
|
|
|
CALL util.throw(CONCAT('Cannot get lock: ', vLockName));
|
|
|
|
|
CALL util.throw('Hay colecciones pendientes');
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
-- Se eliminan las colecciones sin asignar que estan obsoletas
|
|
|
|
|
|
|
|
|
|
INSERT INTO ticketTracking(stateFk, ticketFk)
|
|
|
|
|
SELECT s.id, tc.ticketFk
|
|
|
|
|
FROM collection c
|
|
|
|
|
FROM `collection` c
|
|
|
|
|
JOIN ticketCollection tc ON tc.collectionFk = c.id
|
|
|
|
|
JOIN state s ON s.code = 'PRINTED_AUTO'
|
|
|
|
|
JOIN productionConfig pc
|
|
|
|
|
JOIN `state` s ON s.code = 'PRINTED_AUTO'
|
|
|
|
|
WHERE c.workerFk IS NULL
|
|
|
|
|
AND TIMEDIFF(util.VN_NOW(), c.created) > pc.maxNotAssignedCollectionLifeTime;
|
|
|
|
|
AND TIMEDIFF(util.VN_NOW(), c.created) > vMaxNotAssignedCollectionLifeTime;
|
|
|
|
|
|
|
|
|
|
DELETE c
|
|
|
|
|
FROM collection c
|
|
|
|
|
JOIN productionConfig pc
|
|
|
|
|
WHERE c.workerFk IS NULL
|
|
|
|
|
AND TIMEDIFF(util.VN_NOW(), c.created) > pc.maxNotAssignedCollectionLifeTime;
|
|
|
|
|
DELETE FROM `collection`
|
|
|
|
|
WHERE workerFk IS NULL
|
|
|
|
|
AND TIMEDIFF(util.VN_NOW(), created) > vMaxNotAssignedCollectionLifeTime;
|
|
|
|
|
|
|
|
|
|
-- Se añade registro al semillero
|
|
|
|
|
INSERT INTO collectionHotbed
|
|
|
|
|
SET userFk = vUserFk;
|
|
|
|
|
|
|
|
|
|
INSERT INTO collectionHotbed(userFk) VALUES(vUserFk);
|
|
|
|
|
|
|
|
|
|
-- Comprueba si hay colecciones disponibles que se ajustan a su configuracion
|
|
|
|
|
SELECT MIN(c.id) INTO vCollectionFk
|
|
|
|
|
FROM collection c
|
|
|
|
|
JOIN operator o ON (o.itemPackingTypeFk = c.itemPackingTypeFk
|
|
|
|
|
OR c.itemPackingTypeFk IS NULL)
|
|
|
|
|
AND o.numberOfWagons = c.wagons
|
|
|
|
|
AND o.trainFk = c.trainFk
|
|
|
|
|
AND o.warehouseFk = c.warehouseFk
|
|
|
|
|
AND c.workerFk IS NULL
|
|
|
|
|
WHERE o.workerFk = vUserFk;
|
|
|
|
|
|
|
|
|
|
IF vCollectionFk IS NULL THEN
|
|
|
|
|
CALL collection_new(vUserFk, vCollectionFk);
|
|
|
|
|
OPEN vCollections;
|
|
|
|
|
l: LOOP
|
|
|
|
|
SET vDone = FALSE;
|
|
|
|
|
FETCH vCollections INTO vCollectionFk;
|
|
|
|
|
|
|
|
|
|
IF vDone THEN
|
|
|
|
|
LEAVE l;
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
UPDATE collection
|
|
|
|
|
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;
|
|
|
|
|
|
|
|
|
|
CALL itemShelvingSale_addByCollection(vCollectionFk);
|
|
|
|
|
COMMIT;
|
|
|
|
|
LEAVE l;
|
|
|
|
|
END IF;
|
|
|
|
|
|
|
|
|
|
DO RELEASE_LOCK(vLockName);
|
|
|
|
|
ROLLBACK;
|
|
|
|
|
END;
|
|
|
|
|
END LOOP;
|
|
|
|
|
CLOSE vCollections;
|
|
|
|
|
|
|
|
|
|
IF vCollectionFk IS NULL THEN
|
|
|
|
|
CALL collection_new(vUserFk, vCollectionFk);
|
|
|
|
|
|
|
|
|
|
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;
|
|
|
|
|
END IF;
|
|
|
|
|
CALL itemShelvingSale_addByCollection(vCollectionFk);
|
|
|
|
|
END$$
|
|
|
|
|
DELIMITER ;
|