345 lines
9.0 KiB
SQL
345 lines
9.0 KiB
SQL
DELIMITER $$
|
|
CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_new`(vUserFk INT, OUT vCollectionFk INT)
|
|
proc: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 DEFAULT NULL;
|
|
DECLARE vTicketLines INT;
|
|
DECLARE vVolumeLimit DECIMAL DEFAULT NULL;
|
|
DECLARE vTicketVolume DECIMAL;
|
|
DECLARE vMaxTickets INT;
|
|
DECLARE vStateFk VARCHAR(45);
|
|
DECLARE vFirstTicketFk INT;
|
|
DECLARE vHour INT;
|
|
DECLARE vMinute INT;
|
|
DECLARE vWorkerCode VARCHAR(3);
|
|
DECLARE vWagonCounter INT DEFAULT 0;
|
|
DECLARE vTicketFk INT;
|
|
DECLARE vItemPackingTypeFk VARCHAR(1);
|
|
DECLARE vHasAssignedTickets BOOLEAN;
|
|
DECLARE vHasUniqueCollectionTime BOOL;
|
|
DECLARE vDone INT DEFAULT FALSE;
|
|
DECLARE vLockName VARCHAR(215);
|
|
DECLARE vLockTime INT DEFAULT 15;
|
|
DECLARE vFreeWagonFk INT;
|
|
|
|
DECLARE c1 CURSOR FOR
|
|
SELECT ticketFk, `lines`, m3
|
|
FROM tmp.productionBuffer
|
|
WHERE ticketFk <> vFirstTicketFk
|
|
ORDER BY HH,
|
|
mm,
|
|
productionOrder DESC,
|
|
m3 DESC,
|
|
agency,
|
|
zona,
|
|
routeFk,
|
|
ticketFk
|
|
LIMIT vMaxTickets;
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
|
|
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
|
BEGIN
|
|
IF vLockName IS NOT NULL THEN
|
|
DO RELEASE_LOCK(vLockName);
|
|
END IF;
|
|
|
|
RESIGNAL;
|
|
END;
|
|
|
|
SELECT pc.ticketTrolleyMax * o.numberOfWagons,
|
|
pc.hasUniqueCollectionTime,
|
|
w.code,
|
|
o.warehouseFk,
|
|
o.itemPackingTypeFk,
|
|
st.code,
|
|
o.numberOfWagons,
|
|
o.trainFk,
|
|
o.linesLimit,
|
|
o.volumeLimit
|
|
INTO vMaxTickets,
|
|
vHasUniqueCollectionTime,
|
|
vWorkerCode,
|
|
vWarehouseFk,
|
|
vItemPackingTypeFk,
|
|
vStateFk,
|
|
vWagons,
|
|
vTrainFk,
|
|
vLinesLimit,
|
|
vVolumeLimit
|
|
FROM productionConfig pc
|
|
JOIN worker w ON w.id = vUserFk
|
|
JOIN state st ON st.`code` = 'ON_PREPARATION'
|
|
JOIN operator o ON o.workerFk = vUserFk;
|
|
|
|
SET vLockName = CONCAT_WS('/',
|
|
'collection_new',
|
|
vWarehouseFk,
|
|
vItemPackingTypeFk
|
|
);
|
|
|
|
IF NOT GET_LOCK(vLockName, vLockTime) THEN
|
|
LEAVE proc;
|
|
END IF;
|
|
|
|
-- 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;
|
|
|
|
WHILE vWagons > vWagonCounter DO
|
|
SET vWagonCounter = vWagonCounter + 1;
|
|
|
|
INSERT INTO tTrain(wagon, shelve, liters, `lines`, height)
|
|
SELECT vWagonCounter, cv.`level` , cv.liters , cv.`lines` , cv.height
|
|
FROM collectionVolumetry cv
|
|
WHERE cv.trainFk = vTrainFk
|
|
AND cv.itemPackingTypeFk = vItemPackingTypeFk;
|
|
END WHILE;
|
|
|
|
-- Esto desaparecerá cuando tengamos la table cache.ticket
|
|
CALL productionControl(vWarehouseFk, 0);
|
|
|
|
ALTER TABLE tmp.productionBuffer
|
|
ADD COLUMN liters INT,
|
|
ADD COLUMN height INT;
|
|
|
|
-- Se obtiene nº de colección.
|
|
INSERT INTO collection
|
|
SET itemPackingTypeFk = vItemPackingTypeFk,
|
|
trainFk = vTrainFk,
|
|
wagons = vWagons,
|
|
warehouseFk = vWarehouseFk;
|
|
|
|
SELECT LAST_INSERT_ID() INTO vCollectionFk;
|
|
|
|
-- 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%';
|
|
|
|
-- Comprobamos si hay tickets asignados. En ese caso, nos centramos
|
|
-- exclusivamente en esos tickets y los sacamos independientemente
|
|
-- de problemas o tamaños
|
|
SELECT COUNT(*) INTO vHasAssignedTickets
|
|
FROM tmp.productionBuffer pb
|
|
JOIN state s ON s.id = pb.state
|
|
WHERE s.code = 'PICKER_DESIGNED'
|
|
AND pb.workerCode = vWorkerCode;
|
|
|
|
-- 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
|
|
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) > 0
|
|
OR (pb.lines >= vLinesLimit AND vLinesLimit IS NOT NULL)
|
|
OR (pb.m3 >= vVolumeLimit AND vVolumeLimit IS NOT NULL);
|
|
END IF;
|
|
|
|
-- Es importante que el primer ticket se coja en todos los casos
|
|
SELECT ticketFk,
|
|
HH,
|
|
mm,
|
|
`lines`,
|
|
m3
|
|
INTO vFirstTicketFk,
|
|
vHour,
|
|
vMinute,
|
|
vTicketLines,
|
|
vTicketVolume
|
|
FROM tmp.productionBuffer
|
|
ORDER BY HH,
|
|
mm,
|
|
productionOrder DESC,
|
|
m3 DESC,
|
|
agency,
|
|
zona,
|
|
routeFk,
|
|
ticketFk
|
|
LIMIT 1;
|
|
|
|
-- Hay que excluir aquellos que no tengan la misma hora de preparacion, si procede
|
|
IF vHasUniqueCollectionTime THEN
|
|
DELETE FROM tmp.productionBuffer
|
|
WHERE HH <> vHour
|
|
OR mm <> vMinute;
|
|
END IF;
|
|
|
|
SET vTicketFk = vFirstTicketFk;
|
|
SET @lines = 0;
|
|
SET @volume = 0;
|
|
|
|
OPEN c1;
|
|
read_loop: LOOP
|
|
SET vDone = FALSE;
|
|
|
|
-- Buscamos un ticket que cumpla con los requisitos en el listado
|
|
IF ((vTicketLines + @lines) <= vLinesLimit OR vLinesLimit IS NULL)
|
|
AND ((vTicketVolume + @volume) <= vVolumeLimit OR vVolumeLimit IS NULL) THEN
|
|
|
|
CALL ticket_splitItemPackingType(vTicketFk, vItemPackingTypeFk);
|
|
DROP TEMPORARY TABLE tmp.ticketIPT;
|
|
|
|
UPDATE tmp.productionBuffer pb
|
|
JOIN (
|
|
SELECT SUM(litros) liters,
|
|
@lines:= COUNT(*) + @lines,
|
|
COUNT(*) `lines`,
|
|
MAX(i.`size`) height,
|
|
@volume := SUM(sv.volume) + @volume,
|
|
SUM(sv.volume) volume
|
|
FROM saleVolume sv
|
|
JOIN sale s ON s.id = sv.saleFk
|
|
JOIN item i ON i.id = s.itemFk
|
|
WHERE sv.ticketFk = vTicketFk
|
|
) sub
|
|
SET pb.liters = sub.liters,
|
|
pb.`lines` = sub.`lines`,
|
|
pb.height = sub.height
|
|
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 adecuada, intentamos darle un carro entero si queda alguno libre
|
|
IF NOT (SELECT COUNT(*) FROM tTrain WHERE ticketFk) THEN
|
|
SELECT tt.wagon
|
|
INTO vFreeWagonFk
|
|
FROM tTrain tt
|
|
LEFT JOIN (
|
|
SELECT DISTINCT wagon
|
|
FROM tTrain
|
|
WHERE ticketFk IS NOT NULL
|
|
) nn ON nn.wagon = tt.wagon
|
|
WHERE nn.wagon IS NULL
|
|
ORDER BY wagon
|
|
LIMIT 1;
|
|
|
|
IF vFreeWagonFk THEN
|
|
UPDATE tTrain
|
|
SET ticketFk = vFirstTicketFk
|
|
WHERE wagon = vFreeWagonFk;
|
|
|
|
-- Se anulan el resto de carros libres para que sólo uno lleve un pedido excesivo
|
|
DELETE tt.*
|
|
FROM tTrain tt
|
|
LEFT JOIN (
|
|
SELECT DISTINCT wagon
|
|
FROM tTrain
|
|
WHERE ticketFk IS NOT NULL
|
|
) nn ON nn.wagon = tt.wagon
|
|
WHERE nn.wagon IS NULL;
|
|
END IF;
|
|
END IF;
|
|
|
|
FETCH c1 INTO vTicketFk, vTicketLines, vTicketVolume;
|
|
IF vDone OR NOT (SELECT COUNT(*) FROM tTrain WHERE ticketFk IS NULL) THEN
|
|
LEAVE read_loop;
|
|
END IF;
|
|
ELSE
|
|
FETCH c1 INTO vTicketFk, vTicketLines, vTicketVolume;
|
|
IF vDone THEN
|
|
LEAVE read_loop;
|
|
END IF;
|
|
END IF;
|
|
END LOOP;
|
|
CLOSE c1;
|
|
|
|
IF (SELECT COUNT(*) FROM tTrain WHERE ticketFk) THEN
|
|
UPDATE collection c
|
|
JOIN state st ON st.code = 'ON_PREPARATION'
|
|
SET c.stateFk = st.id
|
|
WHERE c.id = 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, vStateFk);
|
|
|
|
-- Aviso para la preparacion previa
|
|
INSERT INTO ticketDown(ticketFk, collectionFk)
|
|
SELECT tc.ticketFk, tc.collectionFk
|
|
FROM ticketCollection tc
|
|
WHERE tc.collectionFk = vCollectionFk;
|
|
|
|
CALL sales_mergeByCollection(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
|
|
DELETE FROM `collection`
|
|
WHERE id = vCollectionFk;
|
|
SET vCollectionFk = NULL;
|
|
END IF;
|
|
|
|
DO RELEASE_LOCK(vLockName);
|
|
|
|
DROP TEMPORARY TABLE
|
|
tTrain,
|
|
tmp.productionBuffer;
|
|
END$$
|
|
DELIMITER ;
|