DELIMITER $$
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_getAssigned`(
	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 y hace la reserva para la colección
 * 
 * @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 EXIT HANDLER FOR SQLEXCEPTION
	BEGIN
		IF vLockName IS NOT NULL THEN
			DO RELEASE_LOCK(vLockName);
		END IF;
		
		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;

	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));
	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
		SET userFk = 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);
	END IF;

	UPDATE collection
		SET workerFk = vUserFk
		WHERE id = vCollectionFk;

	CALL itemShelvingSale_addByCollection(vCollectionFk);
	
	DO RELEASE_LOCK(vLockName);
END$$
DELIMITER ;