Merge pull request 'solve_merge_problems' (!2986) from solve_merge_problems into master
gitea/salix/pipeline/head This commit looks good
Details
gitea/salix/pipeline/head This commit looks good
Details
Reviewed-on: #2986 Reviewed-by: Guillermo Bonet <guillermo@verdnatura.es>
This commit is contained in:
commit
cd5efc095f
|
@ -12,30 +12,29 @@ BEGIN
|
||||||
DECLARE vLinesLimit INT;
|
DECLARE vLinesLimit INT;
|
||||||
DECLARE vTicketLines INT;
|
DECLARE vTicketLines INT;
|
||||||
DECLARE vVolumeLimit DECIMAL;
|
DECLARE vVolumeLimit DECIMAL;
|
||||||
DECLARE vTicketVolume DECIMAL;
|
|
||||||
DECLARE vSizeLimit INT;
|
DECLARE vSizeLimit INT;
|
||||||
|
DECLARE vTicketVolume DECIMAL;
|
||||||
DECLARE vMaxTickets INT;
|
DECLARE vMaxTickets INT;
|
||||||
DECLARE vStateFk VARCHAR(45);
|
DECLARE vStateCode VARCHAR(45);
|
||||||
DECLARE vFirstTicketFk INT;
|
DECLARE vFirstTicketFk INT;
|
||||||
DECLARE vHour INT;
|
|
||||||
DECLARE vMinute INT;
|
|
||||||
DECLARE vWorkerCode VARCHAR(3);
|
DECLARE vWorkerCode VARCHAR(3);
|
||||||
DECLARE vWagonCounter INT DEFAULT 0;
|
DECLARE vWagonCounter INT DEFAULT 1;
|
||||||
DECLARE vTicketFk INT;
|
DECLARE vTicketFk INT;
|
||||||
DECLARE vItemPackingTypeFk VARCHAR(1);
|
DECLARE vItemPackingTypeFk VARCHAR(1);
|
||||||
DECLARE vHasAssignedTickets BOOLEAN;
|
DECLARE vHasAssignedTickets BOOL;
|
||||||
DECLARE vHasUniqueCollectionTime BOOL;
|
DECLARE vHasUniqueCollectionTime BOOL;
|
||||||
DECLARE vDone INT DEFAULT FALSE;
|
DECLARE vHeight INT;
|
||||||
DECLARE vLockName VARCHAR(215);
|
DECLARE vVolume INT;
|
||||||
DECLARE vLockTime INT DEFAULT 30;
|
DECLARE vLiters INT;
|
||||||
|
DECLARE vLines INT;
|
||||||
|
DECLARE vTotalLines INT DEFAULT 0;
|
||||||
|
DECLARE vTotalVolume INT DEFAULT 0;
|
||||||
DECLARE vFreeWagonFk INT;
|
DECLARE vFreeWagonFk INT;
|
||||||
DECLARE vErrorNumber INT;
|
DECLARE vDone INT DEFAULT FALSE;
|
||||||
DECLARE vErrorMsg TEXT;
|
|
||||||
|
|
||||||
DECLARE c1 CURSOR FOR
|
DECLARE vTickets CURSOR FOR
|
||||||
SELECT ticketFk, `lines`, m3
|
SELECT ticketFk, `lines`, m3
|
||||||
FROM tmp.productionBuffer
|
FROM tmp.productionBuffer
|
||||||
WHERE ticketFk <> vFirstTicketFk
|
|
||||||
ORDER BY HH,
|
ORDER BY HH,
|
||||||
mm,
|
mm,
|
||||||
productionOrder DESC,
|
productionOrder DESC,
|
||||||
|
@ -48,26 +47,6 @@ BEGIN
|
||||||
|
|
||||||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
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,
|
SELECT pc.ticketTrolleyMax * o.numberOfWagons,
|
||||||
pc.hasUniqueCollectionTime,
|
pc.hasUniqueCollectionTime,
|
||||||
w.code,
|
w.code,
|
||||||
|
@ -78,36 +57,26 @@ BEGIN
|
||||||
o.trainFk,
|
o.trainFk,
|
||||||
o.linesLimit,
|
o.linesLimit,
|
||||||
o.volumeLimit,
|
o.volumeLimit,
|
||||||
o.sizeLimit,
|
o.sizeLimit
|
||||||
pc.collection_new_lockname
|
|
||||||
INTO vMaxTickets,
|
INTO vMaxTickets,
|
||||||
vHasUniqueCollectionTime,
|
vHasUniqueCollectionTime,
|
||||||
vWorkerCode,
|
vWorkerCode,
|
||||||
vWarehouseFk,
|
vWarehouseFk,
|
||||||
vItemPackingTypeFk,
|
vItemPackingTypeFk,
|
||||||
vStateFk,
|
vStateCode,
|
||||||
vWagons,
|
vWagons,
|
||||||
vTrainFk,
|
vTrainFk,
|
||||||
vLinesLimit,
|
vLinesLimit,
|
||||||
vVolumeLimit,
|
vVolumeLimit,
|
||||||
vSizeLimit,
|
vSizeLimit
|
||||||
vLockName
|
FROM worker w
|
||||||
FROM productionConfig pc
|
JOIN operator o ON o.workerFk = w.id
|
||||||
JOIN worker w ON w.id = vUserFk
|
|
||||||
JOIN state st ON st.`code` = 'ON_PREPARATION'
|
JOIN state st ON st.`code` = 'ON_PREPARATION'
|
||||||
JOIN operator o ON o.workerFk = vUserFk;
|
JOIN productionConfig pc
|
||||||
|
WHERE w.id = 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 prepara el tren, con tantos vagones como sea necesario.
|
-- Se prepara el tren, con tantos vagones como sea necesario.
|
||||||
|
|
||||||
CREATE OR REPLACE TEMPORARY TABLE tTrain
|
CREATE OR REPLACE TEMPORARY TABLE tTrain
|
||||||
(wagon INT,
|
(wagon INT,
|
||||||
shelve INT,
|
shelve INT,
|
||||||
|
@ -118,59 +87,58 @@ BEGIN
|
||||||
PRIMARY KEY(wagon, shelve))
|
PRIMARY KEY(wagon, shelve))
|
||||||
ENGINE = MEMORY;
|
ENGINE = MEMORY;
|
||||||
|
|
||||||
WHILE vWagons > vWagonCounter DO
|
|
||||||
SET vWagonCounter = vWagonCounter + 1;
|
|
||||||
|
|
||||||
INSERT INTO tTrain (wagon, shelve, liters, `lines`, height)
|
INSERT INTO tTrain (wagon, shelve, liters, `lines`, height)
|
||||||
SELECT vWagonCounter, cv.`level` , cv.liters , cv.`lines` , cv.height
|
WITH RECURSIVE wagonSequence AS (
|
||||||
FROM collectionVolumetry cv
|
SELECT vWagonCounter wagon
|
||||||
WHERE cv.trainFk = vTrainFk
|
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;
|
AND cv.itemPackingTypeFk = vItemPackingTypeFk;
|
||||||
END WHILE;
|
|
||||||
|
|
||||||
-- Esto desaparecerá cuando tengamos la table cache.ticket
|
-- Esto desaparecerá cuando tengamos la table cache.ticket
|
||||||
|
|
||||||
CALL productionControl(vWarehouseFk, 0);
|
CALL productionControl(vWarehouseFk, 0);
|
||||||
|
|
||||||
ALTER TABLE tmp.productionBuffer
|
ALTER TABLE tmp.productionBuffer
|
||||||
ADD COLUMN liters INT,
|
ADD COLUMN liters INT,
|
||||||
ADD COLUMN height 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 tickets de recogida en Algemesí sólo se sacan si están asignados.
|
||||||
-- Los pedidos con riesgo no se sacan aunque se asignen.
|
-- Los pedidos con riesgo no se sacan aunque se asignen.
|
||||||
DELETE pb.*
|
|
||||||
|
DELETE pb
|
||||||
FROM tmp.productionBuffer pb
|
FROM tmp.productionBuffer pb
|
||||||
JOIN state s ON s.id = pb.state
|
JOIN state s ON s.id = pb.state
|
||||||
WHERE (pb.agency = 'REC_ALGEMESI'
|
WHERE (pb.agency = 'REC_ALGEMESI'
|
||||||
AND s.code <> 'PICKER_DESIGNED')
|
AND s.code <> 'PICKER_DESIGNED')
|
||||||
OR pb.problem LIKE '%RIESGO%';
|
OR pb.problem LIKE '%RIESGO%';
|
||||||
|
|
||||||
-- Comprobamos si hay tickets asignados. En ese caso, nos centramos
|
-- Si hay tickets asignados, nos centramos exclusivamente en esos tickets
|
||||||
-- exclusivamente en esos tickets y los sacamos independientemente
|
-- y los sacamos independientemente de problemas o tamaños
|
||||||
-- de problemas o tamaños
|
|
||||||
SELECT COUNT(*) INTO vHasAssignedTickets
|
SELECT EXISTS (
|
||||||
|
SELECT TRUE
|
||||||
FROM tmp.productionBuffer pb
|
FROM tmp.productionBuffer pb
|
||||||
JOIN state s ON s.id = pb.state
|
JOIN state s ON s.id = pb.state
|
||||||
WHERE s.code = 'PICKER_DESIGNED'
|
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
|
-- Se dejan en la tabla tmp.productionBuffer sólo aquellos tickets adecuados
|
||||||
|
|
||||||
IF vHasAssignedTickets THEN
|
IF vHasAssignedTickets THEN
|
||||||
DELETE pb.*
|
DELETE pb
|
||||||
FROM tmp.productionBuffer pb
|
FROM tmp.productionBuffer pb
|
||||||
JOIN state s ON s.id = pb.state
|
JOIN state s ON s.id = pb.state
|
||||||
WHERE s.code <> 'PICKER_DESIGNED'
|
WHERE s.code <> 'PICKER_DESIGNED'
|
||||||
OR pb.workerCode <> vWorkerCode;
|
OR pb.workerCode <> vWorkerCode;
|
||||||
ELSE
|
ELSE
|
||||||
DELETE pb.*
|
DELETE pb
|
||||||
FROM tmp.productionBuffer pb
|
FROM tmp.productionBuffer pb
|
||||||
JOIN state s ON s.id = pb.state
|
JOIN state s ON s.id = pb.state
|
||||||
JOIN agencyMode am ON am.id = pb.agencyModeFk
|
JOIN agencyMode am ON am.id = pb.agencyModeFk
|
||||||
|
@ -193,24 +161,22 @@ BEGIN
|
||||||
OR (NOT pb.H AND pb.V > 0 AND vItemPackingTypeFk = 'H')
|
OR (NOT pb.H AND pb.V > 0 AND vItemPackingTypeFk = 'H')
|
||||||
OR (NOT pb.V AND vItemPackingTypeFk = 'V')
|
OR (NOT pb.V AND vItemPackingTypeFk = 'V')
|
||||||
OR (pc.isPreviousPreparationRequired AND pb.previousWithoutParking)
|
OR (pc.isPreviousPreparationRequired AND pb.previousWithoutParking)
|
||||||
OR LENGTH(pb.problem) > 0
|
OR LENGTH(pb.problem)
|
||||||
OR pb.lines > vLinesLimit
|
OR pb.lines > vLinesLimit
|
||||||
OR pb.m3 > vVolumeLimit
|
OR pb.m3 > vVolumeLimit
|
||||||
OR sub.maxSize > vSizeLimit
|
OR sub.maxSize > vSizeLimit
|
||||||
OR pb.hasPlantTray;
|
OR pb.hasPlantTray;
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
-- Es importante que el primer ticket se coja en todos los casos
|
-- Hay que excluir aquellos que no tengan la misma hora de preparacion, si procede
|
||||||
SELECT ticketFk,
|
IF vHasUniqueCollectionTime THEN
|
||||||
HH,
|
DELETE pb
|
||||||
mm,
|
FROM tmp.productionBuffer pb
|
||||||
`lines`,
|
JOIN tmp.productionBuffer pb2 ON pb2.ticketFk = vFirstTicketFk
|
||||||
m3
|
AND (pb.HH <> pb2.HH OR pb.mm <> pb2.mm);
|
||||||
INTO vFirstTicketFk,
|
END IF;
|
||||||
vHour,
|
|
||||||
vMinute,
|
SELECT ticketFk INTO vFirstTicketFk
|
||||||
vTicketLines,
|
|
||||||
vTicketVolume
|
|
||||||
FROM tmp.productionBuffer
|
FROM tmp.productionBuffer
|
||||||
ORDER BY HH,
|
ORDER BY HH,
|
||||||
mm,
|
mm,
|
||||||
|
@ -222,44 +188,37 @@ BEGIN
|
||||||
ticketFk
|
ticketFk
|
||||||
LIMIT 1;
|
LIMIT 1;
|
||||||
|
|
||||||
-- Hay que excluir aquellos que no tengan la misma hora de preparacion, si procede
|
OPEN vTickets;
|
||||||
IF vHasUniqueCollectionTime THEN
|
l: LOOP
|
||||||
DELETE FROM tmp.productionBuffer
|
SET vDone = FALSE;
|
||||||
WHERE HH <> vHour
|
FETCH vTickets INTO vTicketFk, vTicketLines, vTicketVolume;
|
||||||
OR mm <> vMinute;
|
|
||||||
|
IF vDone THEN
|
||||||
|
LEAVE l;
|
||||||
END IF;
|
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
|
-- 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);
|
CALL ticket_splitItemPackingType(vTicketFk, vItemPackingTypeFk);
|
||||||
DROP TEMPORARY TABLE tmp.ticketIPT;
|
DROP TEMPORARY TABLE tmp.ticketIPT;
|
||||||
|
|
||||||
UPDATE tmp.productionBuffer pb
|
SELECT COUNT(*), SUM(litros), MAX(i.`size`), SUM(sv.volume)
|
||||||
JOIN (
|
INTO vLines, vLiters, vHeight, vVolume
|
||||||
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
|
FROM saleVolume sv
|
||||||
JOIN sale s ON s.id = sv.saleFk
|
JOIN sale s ON s.id = sv.saleFk
|
||||||
JOIN item i ON i.id = s.itemFk
|
JOIN item i ON i.id = s.itemFk
|
||||||
WHERE sv.ticketFk = vTicketFk
|
WHERE sv.ticketFk = vTicketFk;
|
||||||
) sub
|
|
||||||
SET pb.liters = sub.liters,
|
SET vTotalVolume = vTotalVolume + vVolume,
|
||||||
pb.`lines` = sub.`lines`,
|
vTotalLines = vTotalLines + vLines;
|
||||||
pb.height = sub.height
|
|
||||||
|
UPDATE tmp.productionBuffer pb
|
||||||
|
SET pb.liters = vLiters,
|
||||||
|
pb.`lines` = vLines,
|
||||||
|
pb.height = vHeight
|
||||||
WHERE pb.ticketFk = vTicketFk;
|
WHERE pb.ticketFk = vTicketFk;
|
||||||
|
|
||||||
UPDATE tTrain tt
|
UPDATE tTrain tt
|
||||||
|
@ -276,17 +235,13 @@ BEGIN
|
||||||
tt.height
|
tt.height
|
||||||
LIMIT 1;
|
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
|
IF NOT (SELECT COUNT(*) FROM tTrain WHERE ticketFk) THEN
|
||||||
SELECT tt.wagon
|
SELECT wagon INTO vFreeWagonFk
|
||||||
INTO vFreeWagonFk
|
|
||||||
FROM tTrain tt
|
|
||||||
LEFT JOIN (
|
|
||||||
SELECT DISTINCT wagon
|
|
||||||
FROM tTrain
|
FROM tTrain
|
||||||
WHERE ticketFk IS NOT NULL
|
GROUP BY wagon
|
||||||
) nn ON nn.wagon = tt.wagon
|
HAVING SUM(IFNULL(ticketFk, 0)) = 0
|
||||||
WHERE nn.wagon IS NULL
|
|
||||||
ORDER BY wagon
|
ORDER BY wagon
|
||||||
LIMIT 1;
|
LIMIT 1;
|
||||||
|
|
||||||
|
@ -295,38 +250,35 @@ BEGIN
|
||||||
SET ticketFk = vFirstTicketFk
|
SET ticketFk = vFirstTicketFk
|
||||||
WHERE wagon = vFreeWagonFk;
|
WHERE wagon = vFreeWagonFk;
|
||||||
|
|
||||||
-- Se anulan el resto de carros libres para que sólo uno lleve un pedido excesivo
|
-- Se anulan el resto de carros libres,
|
||||||
DELETE tt.*
|
-- máximo un carro con pedido excesivo
|
||||||
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;
|
DELETE tt
|
||||||
IF vDone OR NOT (SELECT COUNT(*) FROM tTrain WHERE ticketFk IS NULL) THEN
|
FROM tTrain tt
|
||||||
LEAVE read_loop;
|
JOIN (SELECT wagon
|
||||||
|
FROM tTrain
|
||||||
|
GROUP BY wagon
|
||||||
|
HAVING SUM(IFNULL(ticketFk, 0)) = 0
|
||||||
|
) sub ON sub.wagon = tt.wagon;
|
||||||
END IF;
|
END IF;
|
||||||
ELSE
|
|
||||||
FETCH c1 INTO vTicketFk, vTicketLines, vTicketVolume;
|
|
||||||
IF vDone THEN
|
|
||||||
LEAVE read_loop;
|
|
||||||
END IF;
|
END IF;
|
||||||
END IF;
|
END IF;
|
||||||
END LOOP;
|
END LOOP;
|
||||||
CLOSE c1;
|
CLOSE vTickets;
|
||||||
|
|
||||||
IF (SELECT COUNT(*) FROM tTrain WHERE ticketFk) THEN
|
IF (SELECT COUNT(*) FROM tTrain WHERE ticketFk) THEN
|
||||||
UPDATE collection c
|
-- Se obtiene nº de colección
|
||||||
JOIN state st ON st.code = 'ON_PREPARATION'
|
|
||||||
SET c.stateFk = st.id
|
INSERT INTO collection
|
||||||
WHERE c.id = vCollectionFk;
|
SET itemPackingTypeFk = vItemPackingTypeFk,
|
||||||
|
trainFk = vTrainFk,
|
||||||
|
wagons = vWagons,
|
||||||
|
warehouseFk = vWarehouseFk;
|
||||||
|
|
||||||
|
SELECT LAST_INSERT_ID() INTO vCollectionFk;
|
||||||
|
|
||||||
-- Asigna las bandejas
|
-- Asigna las bandejas
|
||||||
|
|
||||||
INSERT IGNORE INTO ticketCollection(ticketFk, collectionFk, `level`, wagon, liters)
|
INSERT IGNORE INTO ticketCollection(ticketFk, collectionFk, `level`, wagon, liters)
|
||||||
SELECT tt.ticketFk, vCollectionFk, tt.shelve, tt.wagon, tt.liters
|
SELECT tt.ticketFk, vCollectionFk, tt.shelve, tt.wagon, tt.liters
|
||||||
FROM tTrain tt
|
FROM tTrain tt
|
||||||
|
@ -334,15 +286,17 @@ BEGIN
|
||||||
ORDER BY tt.wagon, tt.shelve;
|
ORDER BY tt.wagon, tt.shelve;
|
||||||
|
|
||||||
-- Actualiza el estado de los tickets
|
-- Actualiza el estado de los tickets
|
||||||
CALL collection_setState(vCollectionFk, vStateFk);
|
|
||||||
|
CALL collection_setState(vCollectionFk, vStateCode);
|
||||||
|
|
||||||
-- Aviso para la preparacion previa
|
-- Aviso para la preparacion previa
|
||||||
|
|
||||||
INSERT INTO ticketDown(ticketFk, collectionFk)
|
INSERT INTO ticketDown(ticketFk, collectionFk)
|
||||||
SELECT tc.ticketFk, tc.collectionFk
|
SELECT tc.ticketFk, tc.collectionFk
|
||||||
FROM ticketCollection tc
|
FROM ticketCollection tc
|
||||||
WHERE tc.collectionFk = vCollectionFk;
|
WHERE tc.collectionFk = vCollectionFk;
|
||||||
|
|
||||||
CALL sales_mergeByCollection(vCollectionFk);
|
CALL collection_mergeSales(vCollectionFk);
|
||||||
|
|
||||||
UPDATE `collection` c
|
UPDATE `collection` c
|
||||||
JOIN(
|
JOIN(
|
||||||
|
@ -356,15 +310,10 @@ BEGIN
|
||||||
SET c.saleTotalCount = sub.saleTotalCount,
|
SET c.saleTotalCount = sub.saleTotalCount,
|
||||||
c.salePickedCount = sub.salePickedCount
|
c.salePickedCount = sub.salePickedCount
|
||||||
WHERE c.id = vCollectionFk;
|
WHERE c.id = vCollectionFk;
|
||||||
|
|
||||||
ELSE
|
ELSE
|
||||||
DELETE FROM `collection`
|
|
||||||
WHERE id = vCollectionFk;
|
|
||||||
SET vCollectionFk = NULL;
|
SET vCollectionFk = NULL;
|
||||||
END IF;
|
END IF;
|
||||||
|
|
||||||
DO RELEASE_LOCK(vLockName);
|
|
||||||
|
|
||||||
DROP TEMPORARY TABLE
|
DROP TEMPORARY TABLE
|
||||||
tTrain,
|
tTrain,
|
||||||
tmp.productionBuffer;
|
tmp.productionBuffer;
|
||||||
|
|
|
@ -268,12 +268,10 @@ proc: BEGIN
|
||||||
UPDATE tmp.productionBuffer pb
|
UPDATE tmp.productionBuffer pb
|
||||||
JOIN sale s ON s.ticketFk = pb.ticketFk
|
JOIN sale s ON s.ticketFk = pb.ticketFk
|
||||||
JOIN item i ON i.id = s.itemFk
|
JOIN item i ON i.id = s.itemFk
|
||||||
JOIN itemType it ON it.id = i.typeFk
|
JOIN cache.last_buy lb ON lb.warehouse_id = vWarehouseFk
|
||||||
JOIN itemCategory ic ON ic.id = it.categoryFk
|
AND lb.item_id = s.itemFk
|
||||||
JOIN cache.last_buy lb ON lb.warehouse_id = vWarehouseFk AND lb.item_id = s.itemFk
|
|
||||||
JOIN buy b ON b.id = lb.buy_id
|
JOIN buy b ON b.id = lb.buy_id
|
||||||
JOIN packaging p ON p.id = b.packagingFk
|
JOIN packaging p ON p.id = b.packagingFk
|
||||||
JOIN productionConfig pc
|
|
||||||
SET pb.hasPlantTray = TRUE
|
SET pb.hasPlantTray = TRUE
|
||||||
WHERE p.isPlantTray
|
WHERE p.isPlantTray
|
||||||
AND s.quantity >= b.packing
|
AND s.quantity >= b.packing
|
||||||
|
|
|
@ -3,12 +3,19 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_mergeSales`(
|
||||||
vSelf INT
|
vSelf INT
|
||||||
)
|
)
|
||||||
BEGIN
|
BEGIN
|
||||||
|
DECLARE vHasSalesToMerge BOOL;
|
||||||
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
DECLARE EXIT HANDLER FOR SQLEXCEPTION
|
||||||
BEGIN
|
BEGIN
|
||||||
ROLLBACK;
|
ROLLBACK;
|
||||||
RESIGNAL;
|
RESIGNAL;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
|
START TRANSACTION;
|
||||||
|
|
||||||
|
SELECT id INTO vSelf
|
||||||
|
FROM ticket
|
||||||
|
WHERE id = vSelf FOR UPDATE;
|
||||||
|
|
||||||
CREATE OR REPLACE TEMPORARY TABLE tSalesToPreserve
|
CREATE OR REPLACE TEMPORARY TABLE tSalesToPreserve
|
||||||
(PRIMARY KEY (id))
|
(PRIMARY KEY (id))
|
||||||
ENGINE = MEMORY
|
ENGINE = MEMORY
|
||||||
|
@ -18,26 +25,25 @@ BEGIN
|
||||||
JOIN itemType it ON it.id = i.typeFk
|
JOIN itemType it ON it.id = i.typeFk
|
||||||
WHERE s.ticketFk = vSelf
|
WHERE s.ticketFk = vSelf
|
||||||
AND it.isMergeable
|
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
|
UPDATE sale s
|
||||||
JOIN tSalesToPreserve stp ON stp.id = s.id
|
JOIN tSalesToPreserve stp ON stp.id = s.id
|
||||||
SET s.quantity = newQuantity
|
SET s.quantity = newQuantity;
|
||||||
WHERE s.ticketFk = vSelf;
|
|
||||||
|
|
||||||
DELETE s.*
|
DELETE s
|
||||||
FROM sale s
|
FROM sale s
|
||||||
LEFT JOIN tSalesToPreserve stp ON stp.id = s.id
|
JOIN tSalesToPreserve stp ON stp.itemFk = s.itemFk
|
||||||
JOIN item i ON i.id = s.itemFk
|
|
||||||
JOIN itemType it ON it.id = i.typeFk
|
|
||||||
WHERE s.ticketFk = vSelf
|
WHERE s.ticketFk = vSelf
|
||||||
AND stp.id IS NULL
|
AND s.id <> stp.id;
|
||||||
AND it.isMergeable;
|
END IF;
|
||||||
|
|
||||||
COMMIT;
|
COMMIT;
|
||||||
|
|
||||||
DROP TEMPORARY TABLE tSalesToPreserve;
|
DROP TEMPORARY TABLE tSalesToPreserve;
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
||||||
|
|
|
@ -3,83 +3,62 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`ticket_splitItemPacki
|
||||||
vSelf INT,
|
vSelf INT,
|
||||||
vOriginalItemPackingTypeFk VARCHAR(1)
|
vOriginalItemPackingTypeFk VARCHAR(1)
|
||||||
)
|
)
|
||||||
BEGIN
|
proc: BEGIN
|
||||||
/**
|
/**
|
||||||
* Clona y reparte las ventas de un ticket en funcion del tipo de empaquetado.
|
* Clona y reparte las líneas de ventas de un ticket en funcion del tipo de empaquetado.
|
||||||
* Respeta el id inicial para el tipo propuesto.
|
* Respeta el id de ticket inicial para el tipo de empaquetado propuesto.
|
||||||
*
|
*
|
||||||
* @param vSelf Id ticket
|
* @param vSelf Id ticket
|
||||||
* @param vOriginalItemPackingTypeFk Tipo para el que se reserva el número de ticket original
|
* @param vOriginalItemPackingTypeFk Tipo empaquetado al que se mantiene el ticket original
|
||||||
* @return table tmp.ticketIPT(ticketFk, itemPackingTypeFk)
|
* @return table tmp.ticketIPT(ticketFk, itemPackingTypeFk)
|
||||||
*/
|
*/
|
||||||
DECLARE vItemPackingTypeFk VARCHAR(1) DEFAULT 'H';
|
|
||||||
DECLARE vNewTicketFk INT;
|
|
||||||
DECLARE vPackingTypesToSplit INT;
|
|
||||||
DECLARE vDone INT DEFAULT FALSE;
|
DECLARE vDone INT DEFAULT FALSE;
|
||||||
|
DECLARE vHasItemPackingType BOOL;
|
||||||
|
DECLARE vItemPackingTypeFk INT;
|
||||||
|
DECLARE vNewTicketFk INT;
|
||||||
|
|
||||||
DECLARE vSaleGroup CURSOR FOR
|
DECLARE vItemPackingTypes CURSOR FOR
|
||||||
SELECT itemPackingTypeFk
|
SELECT DISTINCT itemPackingTypeFk
|
||||||
FROM tSaleGroup
|
FROM tSalesToMove;
|
||||||
WHERE itemPackingTypeFk IS NOT NULL
|
|
||||||
ORDER BY (itemPackingTypeFk = vOriginalItemPackingTypeFk) DESC;
|
|
||||||
|
|
||||||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE;
|
||||||
|
|
||||||
START TRANSACTION;
|
SELECT COUNT(*) INTO vHasItemPackingType
|
||||||
|
FROM ticket t
|
||||||
SELECT id
|
JOIN sale s ON s.ticketFk = t.id
|
||||||
FROM sale
|
|
||||||
WHERE ticketFk = vSelf
|
|
||||||
AND NOT quantity
|
|
||||||
FOR UPDATE;
|
|
||||||
|
|
||||||
DELETE FROM sale
|
|
||||||
WHERE NOT quantity
|
|
||||||
AND ticketFk = vSelf;
|
|
||||||
|
|
||||||
CREATE OR REPLACE TEMPORARY TABLE tSale
|
|
||||||
(PRIMARY KEY (id))
|
|
||||||
ENGINE = MEMORY
|
|
||||||
SELECT s.id, i.itemPackingTypeFk, IFNULL(sv.litros, 0) litros
|
|
||||||
FROM sale s
|
|
||||||
JOIN item i ON i.id = s.itemFk
|
JOIN item i ON i.id = s.itemFk
|
||||||
LEFT JOIN saleVolume sv ON sv.saleFk = s.id
|
WHERE t.id = vSelf
|
||||||
WHERE s.ticketFk = vSelf;
|
AND i.itemPackingTypeFk = vOriginalItemPackingTypeFk;
|
||||||
|
|
||||||
CREATE OR REPLACE TEMPORARY TABLE tSaleGroup
|
|
||||||
ENGINE = MEMORY
|
|
||||||
SELECT itemPackingTypeFk, SUM(litros) totalLitros
|
|
||||||
FROM tSale
|
|
||||||
GROUP BY itemPackingTypeFk;
|
|
||||||
|
|
||||||
SELECT COUNT(*) INTO vPackingTypesToSplit
|
|
||||||
FROM tSaleGroup
|
|
||||||
WHERE itemPackingTypeFk IS NOT NULL;
|
|
||||||
|
|
||||||
CREATE OR REPLACE TEMPORARY TABLE tmp.ticketIPT(
|
CREATE OR REPLACE TEMPORARY TABLE tmp.ticketIPT(
|
||||||
ticketFk INT,
|
ticketFk INT,
|
||||||
itemPackingTypeFk VARCHAR(1)
|
itemPackingTypeFk VARCHAR(1)
|
||||||
|
) ENGINE=MEMORY
|
||||||
|
SELECT vSelf, vOriginalItemPackingTypeFk;
|
||||||
|
|
||||||
|
IF NOT vHasItemPackingType THEN
|
||||||
|
LEAVE proc;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
CREATE OR REPLACE TEMPORARY TABLE tSalesToMove (
|
||||||
|
ticketFk INT,
|
||||||
|
saleFk INT,
|
||||||
|
itemPackingTypeFk INT
|
||||||
) ENGINE=MEMORY;
|
) ENGINE=MEMORY;
|
||||||
|
|
||||||
CASE vPackingTypesToSplit
|
INSERT INTO tSalesToMove (saleFk, itemPackingTypeFk)
|
||||||
WHEN 0 THEN
|
SELECT s.id, i.itemPackingTypeFk
|
||||||
INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk)
|
FROM ticket t
|
||||||
VALUES(vSelf, vItemPackingTypeFk);
|
JOIN sale s ON s.ticketFk = t.id
|
||||||
WHEN 1 THEN
|
JOIN item i ON i.id = s.itemFk
|
||||||
INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk)
|
WHERE t.id = vSelf
|
||||||
SELECT vSelf, itemPackingTypeFk
|
AND i.itemPackingTypeFk <> vOriginalItemPackingTypeFk;
|
||||||
FROM tSaleGroup
|
|
||||||
WHERE itemPackingTypeFk IS NOT NULL;
|
|
||||||
ELSE
|
|
||||||
OPEN vSaleGroup;
|
|
||||||
FETCH vSaleGroup INTO vItemPackingTypeFk;
|
|
||||||
|
|
||||||
INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk)
|
OPEN vItemPackingTypes;
|
||||||
VALUES(vSelf, vItemPackingTypeFk);
|
|
||||||
|
|
||||||
l: LOOP
|
l: LOOP
|
||||||
SET vDone = FALSE;
|
SET vDone = FALSE;
|
||||||
FETCH vSaleGroup INTO vItemPackingTypeFk;
|
FETCH vItemPackingTypes INTO vItemPackingTypeFk;
|
||||||
|
|
||||||
IF vDone THEN
|
IF vDone THEN
|
||||||
LEAVE l;
|
LEAVE l;
|
||||||
|
@ -87,40 +66,24 @@ BEGIN
|
||||||
|
|
||||||
CALL ticket_Clone(vSelf, vNewTicketFk);
|
CALL ticket_Clone(vSelf, vNewTicketFk);
|
||||||
|
|
||||||
INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk)
|
UPDATE tSalesToMove
|
||||||
VALUES(vNewTicketFk, vItemPackingTypeFk);
|
SET ticketFk = vNewTicketFk
|
||||||
|
WHERE itemPackingTypeFk = vItemPackingTypeFk;
|
||||||
|
|
||||||
END LOOP;
|
END LOOP;
|
||||||
|
|
||||||
CLOSE vSaleGroup;
|
CLOSE vItemPackingTypes;
|
||||||
|
|
||||||
SELECT s.id
|
|
||||||
FROM sale s
|
|
||||||
JOIN tSale ts ON ts.id = s.id
|
|
||||||
JOIN tmp.ticketIPT t ON t.itemPackingTypeFk = ts.itemPackingTypeFk
|
|
||||||
FOR UPDATE;
|
|
||||||
|
|
||||||
UPDATE sale s
|
UPDATE sale s
|
||||||
JOIN tSale ts ON ts.id = s.id
|
JOIN tSalesToMove stm ON stm.saleFk = s.id
|
||||||
JOIN tmp.ticketIPT t ON t.itemPackingTypeFk = ts.itemPackingTypeFk
|
SET s.ticketFk = stm.ticketFk
|
||||||
SET s.ticketFk = t.ticketFk;
|
WHERE stm.ticketFk;
|
||||||
|
|
||||||
SELECT itemPackingTypeFk INTO vItemPackingTypeFk
|
INSERT INTO tmp.ticketIPT
|
||||||
FROM tSaleGroup sg
|
SELECT ticketFk, itemPackingTypeFk
|
||||||
WHERE sg.itemPackingTypeFk IS NOT NULL
|
FROM tSalesToMove
|
||||||
ORDER BY sg.itemPackingTypeFk
|
GROUP BY ticketFk;
|
||||||
LIMIT 1;
|
|
||||||
|
|
||||||
UPDATE sale s
|
DROP TEMPORARY TABLE tSalesToMove;
|
||||||
JOIN tSale ts ON ts.id = s.id
|
|
||||||
JOIN tmp.ticketIPT t ON t.itemPackingTypeFk = vItemPackingTypeFk
|
|
||||||
SET s.ticketFk = t.ticketFk
|
|
||||||
WHERE ts.itemPackingTypeFk IS NULL;
|
|
||||||
END CASE;
|
|
||||||
|
|
||||||
COMMIT;
|
|
||||||
|
|
||||||
DROP TEMPORARY TABLE
|
|
||||||
tSale,
|
|
||||||
tSaleGroup;
|
|
||||||
END$$
|
END$$
|
||||||
DELIMITER ;
|
DELIMITER ;
|
||||||
|
|
|
@ -0,0 +1,2 @@
|
||||||
|
ALTER TABLE vn.packaging ADD IF NOT EXISTS isPlantTray BOOL DEFAULT FALSE NOT NULL
|
||||||
|
COMMENT 'The container is a plant tray. Used to restrict the picking of full plant trays, to make previous picking.';
|
Loading…
Reference in New Issue