Merge pull request 'fix: refs #7779 refactor collection' (!3021) from 7779-refactor-collection into dev
gitea/salix/pipeline/head This commit looks good Details

Reviewed-on: #3021
Reviewed-by: Javi Gallego <jgallego@verdnatura.es>
Reviewed-by: Pako Natek <pako@verdnatura.es>
This commit is contained in:
Carlos Andrés 2024-09-27 09:29:36 +00:00
commit 4156a0f0fe
4 changed files with 220 additions and 296 deletions

View File

@ -1,5 +1,8 @@
DELIMITER $$ DELIMITER $$
CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`collection_new`(vUserFk INT, OUT vCollectionFk INT) CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`collection_new`(
vUserFk INT,
OUT vCollectionFk INT
)
BEGIN BEGIN
/** /**
* Genera colecciones de tickets sin asignar trabajador. * Genera colecciones de tickets sin asignar trabajador.
@ -12,30 +15,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 +50,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 +60,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 +90,58 @@ BEGIN
PRIMARY KEY(wagon, shelve)) PRIMARY KEY(wagon, shelve))
ENGINE = MEMORY; ENGINE = MEMORY;
WHILE vWagons > vWagonCounter DO INSERT INTO tTrain (wagon, shelve, liters, `lines`, height)
SET vWagonCounter = vWagonCounter + 1; WITH RECURSIVE wagonSequence AS (
SELECT vWagonCounter wagon
INSERT INTO tTrain(wagon, shelve, liters, `lines`, height) UNION ALL
SELECT vWagonCounter, cv.`level` , cv.liters , cv.`lines` , cv.height SELECT wagon + 1 wagon
FROM collectionVolumetry cv FROM wagonSequence
WHERE cv.trainFk = vTrainFk 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 (
FROM tmp.productionBuffer pb SELECT TRUE
JOIN state s ON s.id = pb.state FROM tmp.productionBuffer pb
WHERE s.code = 'PICKER_DESIGNED' JOIN state s ON s.id = pb.state
AND pb.workerCode = vWorkerCode; WHERE s.code = 'PICKER_DESIGNED'
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,26 +164,25 @@ 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,
HH, IF vHasUniqueCollectionTime THEN
mm, DELETE pb
`lines`, FROM tmp.productionBuffer pb
m3 JOIN tmp.productionBuffer pb2 ON pb2.ticketFk = vFirstTicketFk
INTO vFirstTicketFk, AND (pb.HH <> pb2.HH OR pb.mm <> pb2.mm);
vHour, END IF;
vMinute,
vTicketLines, SELECT ticketFk INTO vFirstTicketFk
vTicketVolume
FROM tmp.productionBuffer FROM tmp.productionBuffer
ORDER BY HH, ORDER BY HH,
mm, mm,
productionOrder DESC, productionOrder DESC,
m3 DESC, m3 DESC,
@ -222,44 +192,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
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; 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 -- 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;
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 UPDATE tmp.productionBuffer pb
JOIN ( SET pb.liters = vLiters,
SELECT SUM(litros) liters, pb.`lines` = vLines,
@lines:= COUNT(*) + @lines, pb.height = vHeight
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; WHERE pb.ticketFk = vTicketFk;
UPDATE tTrain tt UPDATE tTrain tt
@ -276,17 +239,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
FROM tTrain tt GROUP BY wagon
LEFT JOIN ( HAVING COUNT(ticketFk) = 0
SELECT DISTINCT wagon
FROM tTrain
WHERE ticketFk IS NOT NULL
) nn ON nn.wagon = tt.wagon
WHERE nn.wagon IS NULL
ORDER BY wagon ORDER BY wagon
LIMIT 1; LIMIT 1;
@ -295,38 +254,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
END IF; FROM tTrain
ELSE GROUP BY wagon
FETCH c1 INTO vTicketFk, vTicketLines, vTicketVolume; HAVING COUNT(ticketFk) = 0
IF vDone THEN ) sub ON sub.wagon = tt.wagon;
LEAVE read_loop; END IF;
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,39 +290,36 @@ 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(
SELECT COUNT(*) saleTotalCount, SELECT COUNT(*) saleTotalCount,
SUM(s.isPicked <> 0) salePickedCount SUM(s.isPicked <> 0) salePickedCount
FROM ticketCollection tc FROM ticketCollection tc
JOIN sale s ON s.ticketFk = tc.ticketFk JOIN sale s ON s.ticketFk = tc.ticketFk
WHERE tc.collectionFk = vCollectionFk WHERE tc.collectionFk = vCollectionFk
AND s.quantity > 0 AND s.quantity > 0
) sub )sub
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` SET vCollectionFk = NULL;
WHERE id = vCollectionFk;
SET vCollectionFk = NULL;
END IF; END IF;
DO RELEASE_LOCK(vLockName);
DROP TEMPORARY TABLE DROP TEMPORARY TABLE
tTrain, tTrain,
tmp.productionBuffer; tmp.productionBuffer;
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -15,13 +15,11 @@ proc: BEGIN
DECLARE vEndingDate DATETIME; DECLARE vEndingDate DATETIME;
DECLARE vIsTodayRelative BOOLEAN; DECLARE vIsTodayRelative BOOLEAN;
SELECT util.dayEnd(util.VN_CURDATE()) + INTERVAL LEAST(vScopeDays, maxProductionScopeDays) DAY SELECT w.isTodayRelative, util.dayEnd(util.VN_CURDATE()) + INTERVAL LEAST(vScopeDays, pc.maxProductionScopeDays) DAY
INTO vEndingDate INTO vIsTodayRelative,vEndingDate
FROM productionConfig; FROM worker w
JOIN productionConfig pc
SELECT isTodayRelative INTO vIsTodayRelative WHERE w.id = account.myUser_getId();
FROM worker
WHERE id = getUser(); -- Cambiar por account.myUser_getId(), falta dar permisos
CALL prepareTicketList(util.yesterday(), vEndingDate); CALL prepareTicketList(util.yesterday(), vEndingDate);
@ -268,15 +266,14 @@ 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 cache.last_buy lb ON lb.warehouse_id = vWarehouseFk JOIN cache.last_buy lb ON lb.warehouse_id = vWarehouseFk
AND lb.item_id = s.itemFk 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
AND pb.isOwn; AND pb.isOwn;
DROP TEMPORARY TABLE DROP TEMPORARY TABLE
tmp.productionTicket, tmp.productionTicket,

View File

@ -3,12 +3,25 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_mergeSales`(
vSelf INT vSelf INT
) )
BEGIN BEGIN
/**
* Para un ticket se agrupa las diferentes líneas de venta de un mismo artículo en una sola
* siempre y cuando tengan el mismo precio y dto.
*
* @param vSelf Id de ticket
*/
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 +31,24 @@ 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;
UPDATE sale s IF vHasSalesToMerge THEN
JOIN tSalesToPreserve stp ON stp.id = s.id UPDATE sale s
SET s.quantity = newQuantity JOIN tSalesToPreserve stp ON stp.id = s.id
WHERE s.ticketFk = vSelf; SET s.quantity = newQuantity;
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 WHERE s.ticketFk = vSelf
JOIN itemType it ON it.id = i.typeFk AND s.id <> stp.id;
WHERE s.ticketFk = vSelf END IF;
AND stp.id IS NULL
AND it.isMergeable;
COMMIT; COMMIT;
DROP TEMPORARY TABLE tSalesToPreserve; DROP TEMPORARY TABLE tSalesToPreserve;
END$$ END$$
DELIMITER ; DELIMITER ;

View File

@ -3,124 +3,87 @@ 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 original 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 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 JOIN item i ON i.id = s.itemFk
WHERE ticketFk = vSelf WHERE t.id = vSelf
AND NOT quantity AND i.itemPackingTypeFk = vOriginalItemPackingTypeFk;
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
LEFT JOIN saleVolume sv ON sv.saleFk = s.id
WHERE s.ticketFk = vSelf;
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; ) ENGINE=MEMORY
SELECT vSelf ticketFk, vOriginalItemPackingTypeFk itemPackingTypeFk;
CASE vPackingTypesToSplit IF NOT vHasItemPackingType THEN
WHEN 0 THEN LEAVE proc;
INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk) END IF;
VALUES(vSelf, vItemPackingTypeFk);
WHEN 1 THEN
INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk)
SELECT vSelf, itemPackingTypeFk
FROM tSaleGroup
WHERE itemPackingTypeFk IS NOT NULL;
ELSE
OPEN vSaleGroup;
FETCH vSaleGroup INTO vItemPackingTypeFk;
INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk) CREATE OR REPLACE TEMPORARY TABLE tSalesToMove (
VALUES(vSelf, vItemPackingTypeFk); ticketFk INT,
saleFk INT,
itemPackingTypeFk INT
) ENGINE=MEMORY;
l: LOOP INSERT INTO tSalesToMove (saleFk, itemPackingTypeFk)
SET vDone = FALSE; SELECT s.id, i.itemPackingTypeFk
FETCH vSaleGroup INTO vItemPackingTypeFk; FROM ticket t
JOIN sale s ON s.ticketFk = t.id
JOIN item i ON i.id = s.itemFk
WHERE t.id = vSelf
AND i.itemPackingTypeFk <> vOriginalItemPackingTypeFk;
IF vDone THEN OPEN vItemPackingTypes;
LEAVE l;
END IF;
CALL ticket_Clone(vSelf, vNewTicketFk); l: LOOP
SET vDone = FALSE;
FETCH vItemPackingTypes INTO vItemPackingTypeFk;
INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk) IF vDone THEN
VALUES(vNewTicketFk, vItemPackingTypeFk); LEAVE l;
END LOOP; END IF;
CLOSE vSaleGroup; CALL ticket_Clone(vSelf, vNewTicketFk);
SELECT s.id UPDATE tSalesToMove
FROM sale s SET ticketFk = vNewTicketFk
JOIN tSale ts ON ts.id = s.id WHERE itemPackingTypeFk = vItemPackingTypeFk;
JOIN tmp.ticketIPT t ON t.itemPackingTypeFk = ts.itemPackingTypeFk
FOR UPDATE;
UPDATE sale s END LOOP;
JOIN tSale ts ON ts.id = s.id
JOIN tmp.ticketIPT t ON t.itemPackingTypeFk = ts.itemPackingTypeFk
SET s.ticketFk = t.ticketFk;
SELECT itemPackingTypeFk INTO vItemPackingTypeFk CLOSE vItemPackingTypes;
FROM tSaleGroup sg
WHERE sg.itemPackingTypeFk IS NOT NULL
ORDER BY sg.itemPackingTypeFk
LIMIT 1;
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 = vItemPackingTypeFk SET s.ticketFk = stm.ticketFk
SET s.ticketFk = t.ticketFk WHERE stm.ticketFk;
WHERE ts.itemPackingTypeFk IS NULL;
END CASE;
COMMIT; INSERT INTO tmp.ticketIPT (ticketFk, itemPackingTypeFk)
SELECT ticketFk, itemPackingTypeFk
FROM tSalesToMove
GROUP BY ticketFk;
DROP TEMPORARY TABLE DROP TEMPORARY TABLE tSalesToMove;
tSale,
tSaleGroup;
END$$ END$$
DELIMITER ; DELIMITER ;