96 lines
2.7 KiB
SQL
96 lines
2.7 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_assign`(
|
|
vUserFk INT,
|
|
OUT vCollectionFk INT
|
|
)
|
|
proc: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.
|
|
*
|
|
* @param vUserFk Id de usuario
|
|
* @param vCollectionFk Id de colección
|
|
*/
|
|
DECLARE vHasTooMuchCollections BOOL;
|
|
DECLARE vLockTime INT DEFAULT 15;
|
|
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
BEGIN
|
|
DO RELEASE_LOCK('collection_assign');
|
|
|
|
RESIGNAL;
|
|
END;
|
|
|
|
-- Si hay colecciones sin terminar, sale del proceso
|
|
CALL collection_get(vUserFk);
|
|
|
|
SELECT (pc.maxNotReadyCollections - COUNT(*)) <= 0
|
|
INTO vHasTooMuchCollections
|
|
FROM tCollection
|
|
JOIN productionConfig pc ;
|
|
|
|
DROP TEMPORARY TABLE tCollection;
|
|
|
|
IF vHasTooMuchCollections THEN
|
|
CALL util.throw('Hay colecciones pendientes');
|
|
LEAVE proc;
|
|
END IF;
|
|
|
|
IF NOT GET_LOCK('collection_assign',vLockTime) THEN
|
|
LEAVE proc;
|
|
END IF;
|
|
|
|
-- Se eliminan las colecciones sin asignar que estan obsoletas
|
|
INSERT INTO ticketTracking(stateFk, ticketFk)
|
|
SELECT s.id, tc.ticketFk
|
|
FROM `collection` c
|
|
JOIN ticketCollection tc ON tc.collectionFk = c.id
|
|
JOIN `state` s ON s.code = 'PRINTED_AUTO'
|
|
JOIN productionConfig pc
|
|
WHERE c.workerFk IS NULL
|
|
AND TIMEDIFF(util.VN_NOW(), c.created) > pc.maxNotAssignedCollectionLifeTime;
|
|
|
|
DELETE c.*
|
|
FROM `collection` c
|
|
JOIN productionConfig pc
|
|
WHERE c.workerFk IS NULL
|
|
AND TIMEDIFF(util.VN_NOW(), c.created) > pc.maxNotAssignedCollectionLifeTime;
|
|
|
|
-- Se añade registro al semillero
|
|
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
|
|
AND (c.saleTotalCount <= o.linesLimit OR o.linesLimit IS NULL)
|
|
JOIN (
|
|
SELECT tc.collectionFk, SUM(sv.volume) volume
|
|
FROM ticketCollection tc
|
|
JOIN saleVolume sv ON sv.ticketFk = tc.ticketFk
|
|
WHERE sv.shipped >= util.VN_CURDATE()
|
|
GROUP BY tc.collectionFk
|
|
) sub ON sub.collectionFk = c.id
|
|
AND (volume <= o.volumeLimit OR o.volumeLimit IS NULL)
|
|
WHERE o.workerFk = vUserFk;
|
|
|
|
IF vCollectionFk IS NULL THEN
|
|
CALL collection_new(vUserFk, vCollectionFk);
|
|
END IF;
|
|
|
|
UPDATE `collection`
|
|
SET workerFk = vUserFk
|
|
WHERE id = vCollectionFk;
|
|
|
|
DO RELEASE_LOCK('collection_assign');
|
|
END$$
|
|
DELIMITER ;
|