DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`collection_assign`(
	vUserFk INT,
	OUT vCollectionFk INT
)
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 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
		ROLLBACK;
		RESIGNAL;
	END;

	CALL collection_get(vUserFk);

	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('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
				JOIN ticketCollection tc ON tc.collectionFk = c.id
				JOIN `state` s ON s.code = 'PRINTED_AUTO'
			WHERE c.workerFk IS NULL 
				AND TIMEDIFF(util.VN_NOW(), c.created) > vMaxNotAssignedCollectionLifeTime;

	DELETE FROM `collection` 
		WHERE workerFk IS NULL 
			AND TIMEDIFF(util.VN_NOW(), created) > vMaxNotAssignedCollectionLifeTime;

	-- Se añade registro al semillero

	INSERT INTO collectionHotbed(userFk) VALUES(vUserFk);

	-- Comprueba si hay colecciones disponibles que se ajustan a su configuracion

	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;

	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;
END$$
DELIMITER ;