fix: collection_new
gitea/salix/pipeline/pr-master This commit looks good
Details
gitea/salix/pipeline/pr-master This commit looks good
Details
This commit is contained in:
parent
4f9b6030e8
commit
26a078504f
|
@ -12,30 +12,29 @@ BEGIN
|
|||
DECLARE vLinesLimit INT;
|
||||
DECLARE vTicketLines INT;
|
||||
DECLARE vVolumeLimit DECIMAL;
|
||||
DECLARE vTicketVolume DECIMAL;
|
||||
DECLARE vSizeLimit INT;
|
||||
DECLARE vTicketVolume DECIMAL;
|
||||
DECLARE vMaxTickets INT;
|
||||
DECLARE vStateFk VARCHAR(45);
|
||||
DECLARE vStateCode VARCHAR(45);
|
||||
DECLARE vFirstTicketFk INT;
|
||||
DECLARE vHour INT;
|
||||
DECLARE vMinute INT;
|
||||
DECLARE vWorkerCode VARCHAR(3);
|
||||
DECLARE vWagonCounter INT DEFAULT 0;
|
||||
DECLARE vWagonCounter INT DEFAULT 1;
|
||||
DECLARE vTicketFk INT;
|
||||
DECLARE vItemPackingTypeFk VARCHAR(1);
|
||||
DECLARE vHasAssignedTickets BOOLEAN;
|
||||
DECLARE vHasAssignedTickets BOOL;
|
||||
DECLARE vHasUniqueCollectionTime BOOL;
|
||||
DECLARE vDone INT DEFAULT FALSE;
|
||||
DECLARE vLockName VARCHAR(215);
|
||||
DECLARE vLockTime INT DEFAULT 30;
|
||||
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 vErrorNumber INT;
|
||||
DECLARE vErrorMsg TEXT;
|
||||
DECLARE vDone INT DEFAULT FALSE;
|
||||
|
||||
DECLARE c1 CURSOR FOR
|
||||
DECLARE vTickets CURSOR FOR
|
||||
SELECT ticketFk, `lines`, m3
|
||||
FROM tmp.productionBuffer
|
||||
WHERE ticketFk <> vFirstTicketFk
|
||||
ORDER BY HH,
|
||||
mm,
|
||||
productionOrder DESC,
|
||||
|
@ -48,26 +47,6 @@ BEGIN
|
|||
|
||||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
||||
|
||||
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||
BEGIN
|
||||
GET DIAGNOSTICS CONDITION 1
|
||||
vErrorNumber = MYSQL_ERRNO,
|
||||
vErrorMsg = MESSAGE_TEXT;
|
||||
|
||||
CALL util.debugAdd('collection_new', JSON_OBJECT(
|
||||
'errorNumber', vErrorNumber,
|
||||
'errorMsg', vErrorMsg,
|
||||
'lockName', vLockName,
|
||||
'userFk', vUserFk,
|
||||
'ticketFk', vTicketFk
|
||||
)); -- Tmp
|
||||
|
||||
IF vLockName IS NOT NULL THEN
|
||||
DO RELEASE_LOCK(vLockName);
|
||||
END IF;
|
||||
RESIGNAL;
|
||||
END;
|
||||
|
||||
SELECT pc.ticketTrolleyMax * o.numberOfWagons,
|
||||
pc.hasUniqueCollectionTime,
|
||||
w.code,
|
||||
|
@ -78,36 +57,26 @@ BEGIN
|
|||
o.trainFk,
|
||||
o.linesLimit,
|
||||
o.volumeLimit,
|
||||
o.sizeLimit,
|
||||
pc.collection_new_lockname
|
||||
o.sizeLimit
|
||||
INTO vMaxTickets,
|
||||
vHasUniqueCollectionTime,
|
||||
vWorkerCode,
|
||||
vWarehouseFk,
|
||||
vItemPackingTypeFk,
|
||||
vStateFk,
|
||||
vStateCode,
|
||||
vWagons,
|
||||
vTrainFk,
|
||||
vLinesLimit,
|
||||
vVolumeLimit,
|
||||
vSizeLimit,
|
||||
vLockName
|
||||
FROM productionConfig pc
|
||||
JOIN worker w ON w.id = vUserFk
|
||||
vSizeLimit
|
||||
FROM worker w
|
||||
JOIN operator o ON o.workerFk = w.id
|
||||
JOIN state st ON st.`code` = 'ON_PREPARATION'
|
||||
JOIN operator o ON o.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;
|
||||
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,
|
||||
|
@ -118,59 +87,58 @@ BEGIN
|
|||
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
|
||||
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;
|
||||
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.*
|
||||
|
||||
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
|
||||
-- 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;
|
||||
AND pb.workerCode = vWorkerCode
|
||||
) INTO vHasAssignedTickets;
|
||||
|
||||
-- Se dejan en la tabla tmp.productionBuffer sólo aquellos tickets adecuados
|
||||
|
||||
IF vHasAssignedTickets THEN
|
||||
DELETE pb.*
|
||||
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.*
|
||||
DELETE pb
|
||||
FROM tmp.productionBuffer pb
|
||||
JOIN state s ON s.id = pb.state
|
||||
JOIN agencyMode am ON am.id = pb.agencyModeFk
|
||||
|
@ -193,13 +161,21 @@ BEGIN
|
|||
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 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
|
||||
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;
|
||||
|
||||
SELECT ticketFk INTO vFirstTicketFk
|
||||
FROM tmp.productionBuffer
|
||||
ORDER BY HH,
|
||||
|
@ -212,45 +188,37 @@ BEGIN
|
|||
ticketFk
|
||||
LIMIT 1;
|
||||
|
||||
-- Hay que excluir aquellos que no tengan la misma hora de preparacion, si procede
|
||||
IF vHasUniqueCollectionTime THEN
|
||||
DELETE pb
|
||||
FROM tmp.productionBuffer pb
|
||||
JOIN tmp.productionBuffer pb2 ON pb2.ticketFk = vFirstTicketFk
|
||||
AND (pb.HH <> pb2.HH OR pb.mm <> pb2.mm);
|
||||
OPEN vTickets;
|
||||
l: LOOP
|
||||
SET vDone = FALSE;
|
||||
FETCH vTickets INTO vTicketFk, vTicketLines, vTicketVolume;
|
||||
|
||||
IF vDone THEN
|
||||
LEAVE l;
|
||||
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
|
||||
|
||||
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;
|
||||
|
||||
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
|
||||
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
|
||||
) sub
|
||||
SET pb.liters = sub.liters,
|
||||
pb.`lines` = sub.`lines`,
|
||||
pb.height = sub.height
|
||||
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
|
||||
|
@ -267,17 +235,13 @@ BEGIN
|
|||
tt.height
|
||||
LIMIT 1;
|
||||
|
||||
-- Si no le encuentra una balda adecuada, intentamos darle un carro entero si queda alguno libre
|
||||
-- Si no le encuentra una balda, intentamos darle un carro entero libre
|
||||
|
||||
IF NOT (SELECT COUNT(*) FROM tTrain WHERE ticketFk) THEN
|
||||
SELECT tt.wagon
|
||||
INTO vFreeWagonFk
|
||||
FROM tTrain tt
|
||||
LEFT JOIN (
|
||||
SELECT DISTINCT wagon
|
||||
SELECT wagon INTO vFreeWagonFk
|
||||
FROM tTrain
|
||||
WHERE ticketFk IS NOT NULL
|
||||
) nn ON nn.wagon = tt.wagon
|
||||
WHERE nn.wagon IS NULL
|
||||
GROUP BY wagon
|
||||
HAVING SUM(IFNULL(ticketFk, 0)) = 0
|
||||
ORDER BY wagon
|
||||
LIMIT 1;
|
||||
|
||||
|
@ -286,38 +250,35 @@ BEGIN
|
|||
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;
|
||||
-- Se anulan el resto de carros libres,
|
||||
-- máximo un carro con pedido excesivo
|
||||
|
||||
FETCH c1 INTO vTicketFk, vTicketLines, vTicketVolume;
|
||||
IF vDone OR NOT (SELECT COUNT(*) FROM tTrain WHERE ticketFk IS NULL) THEN
|
||||
LEAVE read_loop;
|
||||
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;
|
||||
ELSE
|
||||
FETCH c1 INTO vTicketFk, vTicketLines, vTicketVolume;
|
||||
IF vDone THEN
|
||||
LEAVE read_loop;
|
||||
END IF;
|
||||
END IF;
|
||||
END LOOP;
|
||||
CLOSE c1;
|
||||
CLOSE vTickets;
|
||||
|
||||
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;
|
||||
-- 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
|
||||
|
@ -325,15 +286,17 @@ BEGIN
|
|||
ORDER BY tt.wagon, tt.shelve;
|
||||
|
||||
-- Actualiza el estado de los tickets
|
||||
CALL collection_setState(vCollectionFk, vStateFk);
|
||||
|
||||
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 sales_mergeByCollection(vCollectionFk);
|
||||
CALL collection_mergeSales(vCollectionFk);
|
||||
|
||||
UPDATE `collection` c
|
||||
JOIN(
|
||||
|
@ -347,15 +310,10 @@ BEGIN
|
|||
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;
|
||||
|
|
|
@ -3,12 +3,19 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_mergeSales`(
|
|||
vSelf INT
|
||||
)
|
||||
BEGIN
|
||||
DECLARE vHasSalesToMerge BOOL;
|
||||
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||
BEGIN
|
||||
ROLLBACK;
|
||||
RESIGNAL;
|
||||
END;
|
||||
|
||||
START TRANSACTION;
|
||||
|
||||
SELECT id INTO vSelf
|
||||
FROM ticket
|
||||
WHERE id = vSelf FOR UPDATE;
|
||||
|
||||
CREATE OR REPLACE TEMPORARY TABLE tSalesToPreserve
|
||||
(PRIMARY KEY (id))
|
||||
ENGINE = MEMORY
|
||||
|
@ -18,26 +25,25 @@ BEGIN
|
|||
JOIN itemType it ON it.id = i.typeFk
|
||||
WHERE s.ticketFk = vSelf
|
||||
AND it.isMergeable
|
||||
GROUP BY s.itemFk, s.price, s.discount;
|
||||
GROUP BY s.itemFk, s.price, s.discount
|
||||
HAVING COUNT(*) > 1;
|
||||
|
||||
START TRANSACTION;
|
||||
SELECT COUNT(*) INTO vHasSalesToMerge
|
||||
FROM tSalesToPreserve;
|
||||
|
||||
IF vHasSalesToMerge THEN
|
||||
UPDATE sale s
|
||||
JOIN tSalesToPreserve stp ON stp.id = s.id
|
||||
SET s.quantity = newQuantity
|
||||
WHERE s.ticketFk = vSelf;
|
||||
SET s.quantity = newQuantity;
|
||||
|
||||
DELETE s.*
|
||||
DELETE s
|
||||
FROM sale s
|
||||
LEFT JOIN tSalesToPreserve stp ON stp.id = s.id
|
||||
JOIN item i ON i.id = s.itemFk
|
||||
JOIN itemType it ON it.id = i.typeFk
|
||||
JOIN tSalesToPreserve stp ON stp.itemFk = s.itemFk
|
||||
WHERE s.ticketFk = vSelf
|
||||
AND stp.id IS NULL
|
||||
AND it.isMergeable;
|
||||
AND s.id <> stp.id;
|
||||
END IF;
|
||||
|
||||
COMMIT;
|
||||
|
||||
DROP TEMPORARY TABLE tSalesToPreserve;
|
||||
END$$
|
||||
DELIMITER ;
|
||||
|
|
Loading…
Reference in New Issue