DELIMITER $$ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`collection_new`( vUserFk INT, OUT vCollectionFk INT ) BEGIN /** * Genera colecciones de tickets sin asignar trabajador. * * @param vUserFk Identificador de account.user */ DECLARE vWarehouseFk INT; DECLARE vWagons INT; DECLARE vTrainFk INT; DECLARE vLinesLimit INT; DECLARE vTicketLines INT; DECLARE vVolumeLimit DECIMAL; DECLARE vSizeLimit INT; DECLARE vTicketVolume DECIMAL; DECLARE vMaxTickets INT; DECLARE vStateCode VARCHAR(45); DECLARE vFirstTicketFk INT; DECLARE vWorkerCode VARCHAR(3); DECLARE vWagonCounter INT DEFAULT 1; DECLARE vTicketFk INT; DECLARE vItemPackingTypeFk VARCHAR(1); DECLARE vHasAssignedTickets BOOL; DECLARE vHasUniqueCollectionTime BOOL; DECLARE vHeight INT; DECLARE vVolume INT; DECLARE vLiters INT; DECLARE vLines INT; DECLARE vTotalLines INT DEFAULT 0; DECLARE vTotalVolume INT DEFAULT 0; DECLARE vFreeWagonFk INT; DECLARE vDone INT DEFAULT FALSE; DECLARE vTickets CURSOR FOR SELECT ticketFk, `lines`, m3 FROM tmp.productionBuffer ORDER BY HH, mm, productionOrder DESC, m3 DESC, agency, zona, routeFk, ticketFk LIMIT vMaxTickets; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; SELECT pc.ticketTrolleyMax * o.numberOfWagons, pc.hasUniqueCollectionTime, w.code, o.warehouseFk, o.itemPackingTypeFk, st.code, o.numberOfWagons, o.trainFk, o.linesLimit, o.volumeLimit, o.sizeLimit INTO vMaxTickets, vHasUniqueCollectionTime, vWorkerCode, vWarehouseFk, vItemPackingTypeFk, vStateCode, vWagons, vTrainFk, vLinesLimit, vVolumeLimit, vSizeLimit FROM worker w JOIN operator o ON o.workerFk = w.id JOIN state st ON st.`code` = 'ON_PREPARATION' JOIN productionConfig pc WHERE w.id = vUserFk; -- Se prepara el tren, con tantos vagones como sea necesario. CREATE OR REPLACE TEMPORARY TABLE tTrain (wagon INT, shelve INT, liters INT, `lines`INT, height INT, ticketFk INT, PRIMARY KEY(wagon, shelve)) ENGINE = MEMORY; INSERT INTO tTrain (wagon, shelve, liters, `lines`, height) WITH RECURSIVE wagonSequence AS ( SELECT vWagonCounter wagon UNION ALL SELECT wagon + 1 wagon FROM wagonSequence WHERE wagon < vWagonCounter + vWagons -1 ) SELECT ws.wagon, cv.`level`, cv.liters, cv.`lines`, cv.height FROM wagonSequence ws JOIN vn.collectionVolumetry cv ON cv.trainFk = vTrainFk AND cv.itemPackingTypeFk = vItemPackingTypeFk; -- Esto desaparecerá cuando tengamos la table cache.ticket CALL productionControl(vWarehouseFk, 0); ALTER TABLE tmp.productionBuffer ADD COLUMN liters INT, ADD COLUMN height INT; -- Los tickets de recogida en Algemesí sólo se sacan si están asignados. -- Los pedidos con riesgo no se sacan aunque se asignen. DELETE pb FROM tmp.productionBuffer pb JOIN state s ON s.id = pb.state WHERE (pb.agency = 'REC_ALGEMESI' AND s.code <> 'PICKER_DESIGNED') OR pb.problem LIKE '%RIESGO%'; -- Si hay tickets asignados, nos centramos exclusivamente en esos tickets -- y los sacamos independientemente de problemas o tamaños SELECT EXISTS ( SELECT TRUE FROM tmp.productionBuffer pb JOIN state s ON s.id = pb.state WHERE s.code = 'PICKER_DESIGNED' AND pb.workerCode = vWorkerCode ) INTO vHasAssignedTickets; -- Se dejan en la tabla tmp.productionBuffer sólo aquellos tickets adecuados IF vHasAssignedTickets THEN DELETE pb FROM tmp.productionBuffer pb JOIN state s ON s.id = pb.state WHERE s.code <> 'PICKER_DESIGNED' OR pb.workerCode <> vWorkerCode; ELSE DELETE pb FROM tmp.productionBuffer pb JOIN state s ON s.id = pb.state JOIN agencyMode am ON am.id = pb.agencyModeFk JOIN agency a ON a.id = am.agencyFk LEFT JOIN ( SELECT pb.ticketFk, MAX(i.`size`) maxSize FROM tmp.productionBuffer pb JOIN ticket t ON t.id = pb.ticketfk JOIN sale s ON s.ticketFk = t.id JOIN item i ON i.id = s.itemFk GROUP BY pb.ticketFk ) sub ON sub.ticketFk = pb.ticketFk JOIN productionConfig pc WHERE pb.shipped <> util.VN_CURDATE() OR (pb.ubicacion IS NULL AND a.isOwn) OR (NOT s.isPreparable AND NOT s.isPrintable) OR pb.collectionH IS NOT NULL OR pb.collectionV IS NOT NULL OR pb.collectionN IS NOT NULL OR (NOT pb.H AND pb.V > 0 AND vItemPackingTypeFk = 'H') OR (NOT pb.V AND vItemPackingTypeFk = 'V') OR (pc.isPreviousPreparationRequired AND pb.previousWithoutParking) OR LENGTH(pb.problem) OR pb.lines > vLinesLimit OR pb.m3 > vVolumeLimit OR sub.maxSize > vSizeLimit OR pb.hasPlantTray; END IF; -- Hay que excluir aquellos que no tengan la misma hora de preparacion, si procede IF vHasUniqueCollectionTime THEN SELECT ticketFk INTO vFirstTicketFk FROM tmp.productionBuffer ORDER BY HH, mm, productionOrder DESC, m3 DESC, agency, zona, routeFk, ticketFk LIMIT 1; DELETE pb FROM tmp.productionBuffer pb JOIN tmp.productionBuffer pb2 ON pb2.ticketFk = vFirstTicketFk AND (pb.HH <> pb2.HH OR pb.mm <> pb2.mm); END IF; OPEN vTickets; l: LOOP SET vDone = FALSE; FETCH vTickets INTO vTicketFk, vTicketLines, vTicketVolume; IF vDone THEN LEAVE l; END IF; -- Buscamos un ticket que cumpla con los requisitos en el listado IF (vLinesLimit IS NULL OR (vTotalLines + vTicketLines) <= vLinesLimit) AND (vVolumeLimit IS NULL OR (vTotalVolume + vTicketVolume) <= vVolumeLimit) THEN CALL ticket_splitItemPackingType(vTicketFk, vItemPackingTypeFk); DROP TEMPORARY TABLE tmp.ticketIPT; SELECT COUNT(*), SUM(litros), MAX(i.`size`), SUM(sv.volume) INTO vLines, vLiters, vHeight, vVolume FROM saleVolume sv JOIN sale s ON s.id = sv.saleFk JOIN item i ON i.id = s.itemFk WHERE sv.ticketFk = vTicketFk; SET vTotalVolume = vTotalVolume + vVolume, vTotalLines = vTotalLines + vLines; UPDATE tmp.productionBuffer pb SET pb.liters = vLiters, pb.`lines` = vLines, pb.height = vHeight WHERE pb.ticketFk = vTicketFk; UPDATE tTrain tt JOIN tmp.productionBuffer pb ON pb.ticketFk = vTicketFk SET tt.ticketFk = pb.ticketFk WHERE tt.liters >= pb.liters AND tt.`lines` >= pb.`lines` AND (tt.height >= pb.height OR vItemPackingTypeFk <> 'V') AND tt.ticketFk IS NULL ORDER BY wagon, shelve, tt.liters, tt.`lines`, tt.height LIMIT 1; -- Si no le encuentra una balda, intentamos darle un carro entero libre IF NOT (SELECT COUNT(*) FROM tTrain WHERE ticketFk) THEN SELECT wagon INTO vFreeWagonFk FROM tTrain GROUP BY wagon HAVING SUM(IFNULL(ticketFk, 0)) = 0 ORDER BY wagon LIMIT 1; IF vFreeWagonFk THEN UPDATE tTrain SET ticketFk = vFirstTicketFk WHERE wagon = vFreeWagonFk; -- Se anulan el resto de carros libres, -- máximo un carro con pedido excesivo DELETE tt FROM tTrain tt JOIN (SELECT wagon FROM tTrain GROUP BY wagon HAVING SUM(IFNULL(ticketFk, 0)) = 0 ) sub ON sub.wagon = tt.wagon; END IF; END IF; END IF; END LOOP; CLOSE vTickets; IF (SELECT COUNT(*) FROM tTrain WHERE ticketFk) THEN -- Se obtiene nº de colección INSERT INTO collection SET itemPackingTypeFk = vItemPackingTypeFk, trainFk = vTrainFk, wagons = vWagons, warehouseFk = vWarehouseFk; SELECT LAST_INSERT_ID() INTO vCollectionFk; -- Asigna las bandejas INSERT IGNORE INTO ticketCollection(ticketFk, collectionFk, `level`, wagon, liters) SELECT tt.ticketFk, vCollectionFk, tt.shelve, tt.wagon, tt.liters FROM tTrain tt WHERE tt.ticketFk IS NOT NULL ORDER BY tt.wagon, tt.shelve; -- Actualiza el estado de los tickets CALL collection_setState(vCollectionFk, vStateCode); -- Aviso para la preparacion previa INSERT INTO ticketDown(ticketFk, collectionFk) SELECT tc.ticketFk, tc.collectionFk FROM ticketCollection tc WHERE tc.collectionFk = vCollectionFk; CALL collection_mergeSales(vCollectionFk); UPDATE `collection` c JOIN( SELECT COUNT(*) saleTotalCount, SUM(s.isPicked <> 0) salePickedCount FROM ticketCollection tc JOIN sale s ON s.ticketFk = tc.ticketFk WHERE tc.collectionFk = vCollectionFk AND s.quantity > 0 )sub SET c.saleTotalCount = sub.saleTotalCount, c.salePickedCount = sub.salePickedCount WHERE c.id = vCollectionFk; ELSE SET vCollectionFk = NULL; END IF; DROP TEMPORARY TABLE tTrain, tmp.productionBuffer; END$$ DELIMITER ;