diff --git a/db/routines/vn/procedures/collection_assign.sql b/db/routines/vn/procedures/collection_assign.sql index f9032a91d..2265b04f1 100644 --- a/db/routines/vn/procedures/collection_assign.sql +++ b/db/routines/vn/procedures/collection_assign.sql @@ -13,39 +13,40 @@ BEGIN * @param vCollectionFk Id de colección */ DECLARE vHasTooMuchCollections BOOL; - DECLARE vItemPackingTypeFk VARCHAR(1); - DECLARE vWarehouseFk INT; - DECLARE vLockName VARCHAR(215); - DECLARE vLockTime INT DEFAULT 30; - DECLARE vErrorNumber INT; - DECLARE vErrorMsg TEXT; - - DECLARE EXIT HANDLER FOR SQLEXCEPTION - BEGIN - GET DIAGNOSTICS CONDITION 1 - vErrorNumber = MYSQL_ERRNO, - vErrorMsg = MESSAGE_TEXT; - - CALL util.debugAdd('collection_assign', JSON_OBJECT( - 'errorNumber', vErrorNumber, - 'errorMsg', vErrorMsg, - 'lockName', vLockName, - 'userFk', vUserFk - )); -- Tmp - - IF vLockName IS NOT NULL THEN - DO RELEASE_LOCK(vLockName); - END IF; - RESIGNAL; - END; + DECLARE vDone INT DEFAULT FALSE; + DECLARE vCollectionWorker INT; + + DECLARE vCollections CURSOR FOR + WITH collections AS( + SELECT tc.collectionFk, + SUM(sv.volume) volume, + c.saleTotalCount, + c.itemPackingTypeFk, + c.trainFk, + c.warehouseFk, + c.wagons + FROM vn.ticketCollection tc + JOIN vn.collection c ON c.id = tc.collectionFk + JOIN vn.saleVolume sv ON sv.ticketFk = tc.ticketFk + WHERE c.workerFk IS NULL + AND sv.shipped >= util.VN_CURDATE() + GROUP BY tc.collectionFk + ) SELECT c.collectionFk + FROM collections c + JOIN vn.operator o + WHERE o.workerFk = vUserFk + AND (c.saleTotalCount <= o.linesLimit OR o.linesLimit IS NULL) + AND (c.itemPackingTypeFk = o.itemPackingTypeFk OR o.itemPackingTypeFk IS NULL) + AND o.numberOfWagons = c.wagons + AND o.trainFk = c.trainFk + AND o.warehouseFk = c.warehouseFk; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; -- Si hay colecciones sin terminar, sale del proceso + CALL collection_get(vUserFk); - SELECT (pc.maxNotReadyCollections - COUNT(*)) <= 0, - collection_assign_lockname - INTO vHasTooMuchCollections, - vLockName + SELECT (pc.maxNotReadyCollections - COUNT(*)) <= 0 INTO vHasTooMuchCollections FROM productionConfig pc LEFT JOIN tmp.collection ON TRUE; @@ -55,69 +56,72 @@ BEGIN CALL util.throw('Hay colecciones pendientes'); END IF; - SELECT warehouseFk, itemPackingTypeFk - INTO vWarehouseFk, vItemPackingTypeFk - FROM operator - WHERE 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; - -- Se eliminan las colecciones sin asignar que estan obsoletas + INSERT INTO ticketTracking(stateFk, ticketFk) - SELECT s.id, tc.ticketFk - FROM `collection` c - JOIN ticketCollection tc ON tc.collectionFk = c.id - JOIN `state` s ON s.code = 'PRINTED_AUTO' - JOIN productionConfig pc + SELECT s.id, tc.ticketFk + FROM `collection` c + JOIN ticketCollection tc ON tc.collectionFk = c.id + JOIN `state` s ON s.code = 'PRINTED_AUTO' + JOIN productionConfig pc WHERE c.workerFk IS NULL AND TIMEDIFF(util.VN_NOW(), c.created) > pc.maxNotAssignedCollectionLifeTime; - DELETE c.* + DELETE c FROM `collection` c JOIN productionConfig pc WHERE c.workerFk IS NULL AND TIMEDIFF(util.VN_NOW(), c.created) > pc.maxNotAssignedCollectionLifeTime; -- Se añade registro al semillero - INSERT INTO collectionHotbed(userFk) - VALUES(vUserFk); + + INSERT INTO collectionHotbed(userFk) VALUES(vUserFk); -- Comprueba si hay colecciones disponibles que se ajustan a su configuracion - SELECT MIN(c.id) INTO vCollectionFk - FROM `collection` c - JOIN operator o - ON (o.itemPackingTypeFk = c.itemPackingTypeFk OR c.itemPackingTypeFk IS NULL) - AND o.numberOfWagons = c.wagons - AND o.trainFk = c.trainFk - AND o.warehouseFk = c.warehouseFk - AND c.workerFk IS NULL - AND (c.saleTotalCount <= o.linesLimit OR o.linesLimit IS NULL) - JOIN ( - SELECT tc.collectionFk, SUM(sv.volume) volume - FROM ticketCollection tc - JOIN saleVolume sv ON sv.ticketFk = tc.ticketFk - WHERE sv.shipped >= util.VN_CURDATE() - GROUP BY tc.collectionFk - ) sub ON sub.collectionFk = c.id - AND (volume <= o.volumeLimit OR o.volumeLimit IS NULL) - WHERE o.workerFk = vUserFk; + + OPEN vCollections; + l: LOOP + SET vDone = FALSE; + FETCH vCollections INTO vCollectionFk; + + IF vDone THEN + LEAVE l; + END IF; + + BEGIN + DECLARE EXIT HANDLER FOR SQLEXCEPTION + BEGIN + ROLLBACK; + SET vCollectionFk = NULL; + RESIGNAL; + END; + + START TRANSACTION; + + SELECT workerFk INTO vCollectionWorker + FROM `collection` + WHERE id = vCollectionFk FOR UPDATE; + + IF vCollectionWorker IS NULL THEN + UPDATE `collection` + SET workerFk = vUserFk + WHERE id = vCollectionFk; + + COMMIT; + LEAVE l; + END IF; + + ROLLBACK; + END; + END LOOP; + CLOSE vCollections; IF vCollectionFk IS NULL THEN CALL collection_new(vUserFk, vCollectionFk); + + UPDATE `collection` + SET workerFk = vUserFk + WHERE id = vCollectionFk; END IF; - - UPDATE `collection` - SET workerFk = vUserFk - WHERE id = vCollectionFk; - - DO RELEASE_LOCK(vLockName); END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/sales_mergeByCollection.sql b/db/routines/vn/procedures/collection_mergeSales.sql similarity index 66% rename from db/routines/vn/procedures/sales_mergeByCollection.sql rename to db/routines/vn/procedures/collection_mergeSales.sql index 4c0693753..270f3fa30 100644 --- a/db/routines/vn/procedures/sales_mergeByCollection.sql +++ b/db/routines/vn/procedures/collection_mergeSales.sql @@ -1,7 +1,6 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sales_mergeByCollection`(vCollectionFk INT) +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_mergeSales`(vCollectionFk INT) BEGIN - DECLARE vDone BOOL; -- Fetch variables DECLARE vTicketFk INT; @@ -15,22 +14,17 @@ BEGIN SET vDone = TRUE; OPEN cCur; - - myLoop: LOOP - + l: LOOP SET vDone = FALSE; - + FETCH cCur INTO vTicketFk; IF vDone THEN - LEAVE myLoop; + LEAVE l; END IF; - - CALL vn.sales_merge(vTicketFk); - + + CALL vn.ticket_mergeSales(vTicketFk); END LOOP; - CLOSE cCur; - END$$ DELIMITER ; diff --git a/db/routines/vn/procedures/collection_new.sql b/db/routines/vn/procedures/collection_new.sql index 0bd6e1b25..8b18d05f5 100644 --- a/db/routines/vn/procedures/collection_new.sql +++ b/db/routines/vn/procedures/collection_new.sql @@ -1,5 +1,8 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_new`(vUserFk INT, OUT vCollectionFk INT) +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`collection_new`( + vUserFk INT, + OUT vCollectionFk INT +) BEGIN /** * Genera colecciones de tickets sin asignar trabajador. @@ -16,25 +19,24 @@ BEGIN 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 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, @@ -47,26 +49,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, @@ -76,35 +58,25 @@ BEGIN o.numberOfWagons, o.trainFk, o.linesLimit, - o.volumeLimit, - pc.collection_new_lockname + o.volumeLimit INTO vMaxTickets, - vHasUniqueCollectionTime, - vWorkerCode, - vWarehouseFk, - vItemPackingTypeFk, - vStateFk, - vWagons, - vTrainFk, - vLinesLimit, - vVolumeLimit, - vLockName - FROM productionConfig pc - JOIN worker w ON w.id = vUserFk + vHasUniqueCollectionTime, + vWorkerCode, + vWarehouseFk, + vItemPackingTypeFk, + vStateFk, + vWagons, + vTrainFk, + vLinesLimit, + vVolumeLimit + 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, @@ -115,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 + 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; - 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 - FROM tmp.productionBuffer pb - JOIN state s ON s.id = pb.state - WHERE s.code = 'PICKER_DESIGNED' - AND pb.workerCode = vWorkerCode; + -- 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 + LIMIT 1 + ) 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 @@ -187,66 +158,59 @@ BEGIN 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; + + 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; - SET vTicketFk = vFirstTicketFk; - SET @lines = 0; - SET @volume = 0; - - OPEN c1; - read_loop: LOOP + 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 ((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; + 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 - 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 + SET pb.liters = vLiters, + pb.`lines` = vLines, + pb.height = vHeight WHERE pb.ticketFk = vTicketFk; UPDATE tTrain tt @@ -263,17 +227,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 - FROM tTrain - WHERE ticketFk IS NOT NULL - ) nn ON nn.wagon = tt.wagon - WHERE nn.wagon IS NULL + SELECT wagon INTO vFreeWagonFk + FROM tTrain + GROUP BY wagon + HAVING SUM(IFNULL(ticketFk, 0)) = 0 ORDER BY wagon LIMIT 1; @@ -282,38 +242,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; - END IF; - ELSE - FETCH c1 INTO vTicketFk, vTicketLines, vTicketVolume; - IF vDone THEN - LEAVE read_loop; - END IF; + 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 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 @@ -321,37 +278,34 @@ BEGIN 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); + CALL collection_mergeSales(vCollectionFk); UPDATE `collection` c - JOIN ( + JOIN( SELECT COUNT(*) saleTotalCount, SUM(s.isPicked <> 0) salePickedCount FROM ticketCollection tc - JOIN sale s ON s.ticketFk = tc.ticketFk + JOIN sale s ON s.ticketFk = tc.ticketFk WHERE tc.collectionFk = vCollectionFk AND s.quantity > 0 - ) sub + )sub SET c.saleTotalCount = sub.saleTotalCount, c.salePickedCount = sub.salePickedCount WHERE c.id = vCollectionFk; - ELSE - DELETE FROM `collection` - WHERE id = vCollectionFk; - SET vCollectionFk = NULL; + SET vCollectionFk = NULL; END IF; - DO RELEASE_LOCK(vLockName); - DROP TEMPORARY TABLE tTrain, tmp.productionBuffer; diff --git a/db/routines/vn/procedures/sales_merge.sql b/db/routines/vn/procedures/sales_merge.sql deleted file mode 100644 index 3dd01f9bc..000000000 --- a/db/routines/vn/procedures/sales_merge.sql +++ /dev/null @@ -1,41 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`sales_merge`(vTicketFk INT) -BEGIN - DECLARE EXIT HANDLER FOR SQLEXCEPTION - BEGIN - ROLLBACK; - RESIGNAL; - END; - - CREATE OR REPLACE TEMPORARY TABLE tSalesToPreserve - (PRIMARY KEY (id)) - ENGINE = MEMORY - SELECT s.id, s.itemFk, SUM(s.quantity) newQuantity - FROM sale s - JOIN item i ON i.id = s.itemFk - JOIN itemType it ON it.id = i.typeFk - WHERE s.ticketFk = vTicketFk - AND it.isMergeable - GROUP BY s.itemFk, s.price, s.discount; - - START TRANSACTION; - - UPDATE sale s - JOIN tSalesToPreserve stp ON stp.id = s.id - SET s.quantity = newQuantity - WHERE s.ticketFk = vTicketFk; - - 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 - WHERE s.ticketFk = vTicketFk - AND stp.id IS NULL - AND it.isMergeable; - - COMMIT; - - DROP TEMPORARY TABLE tSalesToPreserve; -END$$ -DELIMITER ; diff --git a/db/routines/vn/procedures/ticket_mergeSales.sql b/db/routines/vn/procedures/ticket_mergeSales.sql new file mode 100644 index 000000000..12fe7329a --- /dev/null +++ b/db/routines/vn/procedures/ticket_mergeSales.sql @@ -0,0 +1,49 @@ +DELIMITER $$ +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 + SELECT s.id, s.itemFk, SUM(s.quantity) newQuantity + FROM sale s + JOIN item i ON i.id = s.itemFk + JOIN itemType it ON it.id = i.typeFk + WHERE s.ticketFk = vSelf + AND it.isMergeable + GROUP BY s.itemFk, s.price, s.discount + HAVING COUNT(*) > 1; + + SELECT COUNT(*) INTO vHasSalesToMerge + FROM tSalesToPreserve; + + IF vHasSalesToMerge THEN + UPDATE sale s + JOIN tSalesToPreserve stp ON stp.id = s.id + SET s.quantity = newQuantity; + + DELETE s + FROM sale s + JOIN tSalesToPreserve stp ON stp.itemFk = s.itemFk + WHERE s.ticketFk = vSelf + AND s.id <> stp.id; + END IF; + + COMMIT; + DROP TEMPORARY TABLE tSalesToPreserve; +END$$ +DELIMITER ; diff --git a/db/routines/vn/procedures/ticket_splitItemPackingType.sql b/db/routines/vn/procedures/ticket_splitItemPackingType.sql index 5ae9fb9bc..e9d8ba983 100644 --- a/db/routines/vn/procedures/ticket_splitItemPackingType.sql +++ b/db/routines/vn/procedures/ticket_splitItemPackingType.sql @@ -5,139 +5,73 @@ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`ticket_splitItemPac ) BEGIN /** - * Clona y reparte las ventas de un ticket en funcion del tipo de empaquetado. - * Respeta el id inicial para el tipo propuesto. + * Clona y reparte las líneas de ventas de un ticket en funcion del tipo de empaquetado. + * Respeta el id de ticket inicial para el tipo de empaquetado propuesto. * * @param vSelf Id ticket - * @param vOriginalItemPackingTypeFk Tipo para el que se reserva el número de ticket original - * @return table tmp.ticketIPT(ticketFk, itemPackingTypeFk) + * @param vOriginalItemPackingTypeFk Tipo empaquetado al que se mantiene el ticket original */ - DECLARE vItemPackingTypeFk VARCHAR(1) DEFAULT 'H'; - DECLARE vNewTicketFk INT; - DECLARE vPackingTypesToSplit INT; DECLARE vDone INT DEFAULT FALSE; - DECLARE vErrorNumber INT; - DECLARE vErrorMsg TEXT; + DECLARE vHasItemPackingType BOOL; + DECLARE vItemPackingTypeFk INT; + DECLARE vNewTicketFk INT; - DECLARE vSaleGroup CURSOR FOR - SELECT itemPackingTypeFk - FROM tSaleGroup - WHERE itemPackingTypeFk IS NOT NULL - ORDER BY (itemPackingTypeFk = vOriginalItemPackingTypeFk) DESC; + DECLARE vItemPackingTypes CURSOR FOR + SELECT DISTINCT itemPackingTypeFk + FROM tmp.salesToMove; 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; + SELECT COUNT(*) INTO vHasItemPackingType + 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; - CALL util.debugAdd('ticket_splitItemPackingType', JSON_OBJECT( - 'errorNumber', vErrorNumber, - 'errorMsg', vErrorMsg, - 'ticketFk', vSelf - )); -- Tmp - ROLLBACK; - RESIGNAL; - END; + IF NOT vHasItemPackingType THEN + CALL util.throw('The ticket has not sales with the itemPackingType'); + END IF; - START TRANSACTION; - - SELECT 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 - 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.salesToMove ( ticketFk INT, - itemPackingTypeFk VARCHAR(1) - ) ENGINE = MEMORY; + saleFk INT, + itemPackingTypeFk INT + ) ENGINE=MEMORY; - CASE vPackingTypesToSplit - WHEN 0 THEN - INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk) - 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.salesToMove (saleFk, itemPackingTypeFk) + SELECT s.id, i.itemPackingTypeFk + 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; - INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk) - VALUES(vSelf, vItemPackingTypeFk); + OPEN vItemPackingTypes; - l: LOOP - SET vDone = FALSE; - FETCH vSaleGroup INTO vItemPackingTypeFk; + l: LOOP + SET vDone = FALSE; + FETCH vItemPackingTypes INTO vitemPackingTypeFk; + + IF vDone THEN + LEAVE l; + END IF; + + CALL ticket_Clone(vSelf, vNewTicketFk); + + UPDATE tmp.salesToMove + SET ticketFk = vNewTicketFk + WHERE itemPackingTypeFk = vItemPackingTypeFk; + + END LOOP; - IF vDone THEN - LEAVE l; - END IF; + CLOSE vItemPackingTypes; - CALL ticket_Clone(vSelf, vNewTicketFk); + UPDATE sale s + JOIN tmp.salesToMove stm ON stm.saleFk = s.id + SET s.ticketFk = stm.ticketFk + WHERE stm.ticketFk; - INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk) - VALUES(vNewTicketFk, vItemPackingTypeFk); - END LOOP; - - CLOSE vSaleGroup; - - 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 - 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 - FROM tSaleGroup sg - WHERE sg.itemPackingTypeFk IS NOT NULL - ORDER BY sg.itemPackingTypeFk - LIMIT 1; - - UPDATE sale s - 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; + DROP TEMPORARY TABLE tmp.salesToMove; END$$ DELIMITER ;