From 43e121a2f3da3a730389f6889db21ba9f0ba8eb3 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Carlos=20Andr=C3=A9s?= Date: Tue, 19 Nov 2024 11:04:16 +0100 Subject: [PATCH 1/4] refactor: refs #8210 ticket_splitItemPackingType --- .../ticket_splitItemPackingType.sql | 166 ++++++++---------- .../11351-bronzeMedeola/00-firstScript.sql | 2 + 2 files changed, 71 insertions(+), 97 deletions(-) create mode 100644 db/versions/11351-bronzeMedeola/00-firstScript.sql diff --git a/db/routines/vn/procedures/ticket_splitItemPackingType.sql b/db/routines/vn/procedures/ticket_splitItemPackingType.sql index 0ee865af5..594cd9836 100644 --- a/db/routines/vn/procedures/ticket_splitItemPackingType.sql +++ b/db/routines/vn/procedures/ticket_splitItemPackingType.sql @@ -5,122 +5,94 @@ CREATE OR REPLACE DEFINER=`vn`@`localhost` PROCEDURE `vn`.`ticket_splitItemPacki ) BEGIN /** - * Clona y reparte las ventas de un ticket en funcion del tipo de empaquetado. - * Respeta el id inicial para el tipo propuesto. + * Separa en diferentes tickets según el tipo de empaquetado + * El ticket original conserva las líneas del tipo de empaquetado especificado + * Las líneas sin tipo de empaquetado se asignan al ticket del tipo por defecto. * - * @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 vSelf ID del ticket original + * @param vOriginalItemPackingTypeFk Tipo de empaquetado a mantener en el ticket original + * @return Tabla temporal tmp.ticketIPT(ticketFk, itemPackingTypeFk) */ - DECLARE vItemPackingTypeFk VARCHAR(1) DEFAULT 'H'; + DECLARE vIsDone BOOLEAN DEFAULT FALSE; + DECLARE vCurrentPackingType VARCHAR(1); + DECLARE vDefaultPackingType VARCHAR(1); + DECLARE vHasOriginalPackingType BOOLEAN; DECLARE vNewTicketFk INT; - DECLARE vPackingTypesToSplit INT; - DECLARE vDone INT DEFAULT FALSE; - 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 tSalesToMove; - DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE; + DECLARE CONTINUE HANDLER FOR NOT FOUND SET vIsDone = TRUE; - START TRANSACTION; + CREATE OR REPLACE TEMPORARY TABLE tSalesToMove ( + ticketFk INT, + saleFk INT, + itemPackingTypeFk VARCHAR(1) + ) ENGINE=MEMORY; - SELECT id - FROM sale - WHERE ticketFk = vSelf - AND NOT quantity - FOR UPDATE; + SELECT vDefaultPackingTypeFk INTO vDefaultPackingType FROM itemConfig LIMIT 1; - 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 + SELECT EXISTS ( + SELECT TRUE FROM sale s JOIN item i ON i.id = s.itemFk - LEFT JOIN saleVolume sv ON sv.saleFk = s.id - WHERE s.ticketFk = vSelf; + WHERE s.ticketFk = vSelf + AND i.itemPackingTypeFk = vOriginalItemPackingTypeFk + ) INTO vHasOriginalPackingType; - CREATE OR REPLACE TEMPORARY TABLE tSaleGroup - ENGINE = MEMORY - SELECT itemPackingTypeFk, SUM(litros) totalLitros - FROM tSale - GROUP BY itemPackingTypeFk; + IF vOriginalItemPackingTypeFk IS NULL OR NOT vHasOriginalPackingType THEN + SET vOriginalItemPackingTypeFk = vDefaultPackingType; + END IF; - SELECT COUNT(*) INTO vPackingTypesToSplit - FROM tSaleGroup - WHERE itemPackingTypeFk IS NOT NULL; + INSERT INTO tSalesToMove (saleFk, itemPackingTypeFk) + SELECT s.id, i.itemPackingTypeFk + FROM sale s + JOIN item i ON i.id = s.itemFk + WHERE s.ticketFk = vSelf + AND i.itemPackingTypeFk <> vOriginalItemPackingTypeFk; - CREATE OR REPLACE TEMPORARY TABLE tmp.ticketIPT( - ticketFk INT, - itemPackingTypeFk VARCHAR(1) - ) ENGINE = MEMORY; + OPEN vItemPackingTypes; + l: LOOP + FETCH vItemPackingTypes INTO vCurrentPackingType; - 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; + IF vIsDone THEN + LEAVE l; + END IF; - INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk) - VALUES(vSelf, vItemPackingTypeFk); + CALL ticket_Clone(vSelf, vNewTicketFk); - l: LOOP - SET vDone = FALSE; - FETCH vSaleGroup INTO vItemPackingTypeFk; + UPDATE tSalesToMove + SET ticketFk = vNewTicketFk + WHERE itemPackingTypeFk = vCurrentPackingType; - IF vDone THEN - LEAVE l; - END IF; + IF vCurrentPackingType = vDefaultPackingType THEN + INSERT INTO tSalesToMove (ticketFk, saleFk, itemPackingTypeFk) + SELECT vNewTicketFk, s.id, i.itemPackingTypeFk + FROM sale s + JOIN item i ON i.id = s.itemFk + WHERE s.ticketFk = vSelf + AND i.itemPackingTypeFk IS NULL; + END IF; + END LOOP; + CLOSE vItemPackingTypes; - CALL ticket_Clone(vSelf, vNewTicketFk); + UPDATE sale s + JOIN tSalesToMove t ON t.saleFk = s.id + SET s.ticketFk = t.ticketFk + WHERE t.ticketFk IS NOT NULL; - INSERT INTO tmp.ticketIPT(ticketFk, itemPackingTypeFk) - VALUES(vNewTicketFk, vItemPackingTypeFk); - END LOOP; + CREATE OR REPLACE TEMPORARY TABLE tmp.ticketIPT + ENGINE=MEMORY + SELECT s.ticketFk, i.itemPackingTypeFk + FROM sale s + JOIN item i ON i.id = s.itemFk + WHERE s.ticketFk = vSelf + GROUP BY s.ticketFk, i.itemPackingTypeFk + UNION + SELECT ticketFk, itemPackingTypeFk + FROM tSalesToMove + GROUP BY ticketFk, itemPackingTypeFk; - 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 tSalesToMove; END$$ DELIMITER ; diff --git a/db/versions/11351-bronzeMedeola/00-firstScript.sql b/db/versions/11351-bronzeMedeola/00-firstScript.sql new file mode 100644 index 000000000..c94447a89 --- /dev/null +++ b/db/versions/11351-bronzeMedeola/00-firstScript.sql @@ -0,0 +1,2 @@ + +ALTER TABLE vn.itemConfig ADD defaultPackingTypeFk VARCHAR(1) DEFAULT 'H' NULL; -- 2.40.1 From a7ab8696ac915a99aa6896b1e1aa8e02263f9d80 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Carlos=20Andr=C3=A9s?= Date: Tue, 19 Nov 2024 11:07:19 +0100 Subject: [PATCH 2/4] refactor: refs #8210 ticket_splitItemPackingType --- db/routines/vn/procedures/ticket_splitItemPackingType.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/db/routines/vn/procedures/ticket_splitItemPackingType.sql b/db/routines/vn/procedures/ticket_splitItemPackingType.sql index 594cd9836..95b734b44 100644 --- a/db/routines/vn/procedures/ticket_splitItemPackingType.sql +++ b/db/routines/vn/procedures/ticket_splitItemPackingType.sql @@ -9,9 +9,9 @@ BEGIN * El ticket original conserva las líneas del tipo de empaquetado especificado * Las líneas sin tipo de empaquetado se asignan al ticket del tipo por defecto. * - * @param vSelf ID del ticket original + * @param vSelf Id del ticket original * @param vOriginalItemPackingTypeFk Tipo de empaquetado a mantener en el ticket original - * @return Tabla temporal tmp.ticketIPT(ticketFk, itemPackingTypeFk) + * @return table tmp.ticketIPT(ticketFk, itemPackingTypeFk) */ DECLARE vIsDone BOOLEAN DEFAULT FALSE; DECLARE vCurrentPackingType VARCHAR(1); -- 2.40.1 From 43abb52efc250a81ebd652c222dc4206dfba67de Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Carlos=20Andr=C3=A9s?= Date: Tue, 19 Nov 2024 16:58:15 +0100 Subject: [PATCH 3/4] refactor: refs #8210 ticket_splitItemPackingType --- .../ticket_splitItemPackingType.sql | 41 +++++++++++++++---- 1 file changed, 32 insertions(+), 9 deletions(-) diff --git a/db/routines/vn/procedures/ticket_splitItemPackingType.sql b/db/routines/vn/procedures/ticket_splitItemPackingType.sql index 95b734b44..1a1e1ff07 100644 --- a/db/routines/vn/procedures/ticket_splitItemPackingType.sql +++ b/db/routines/vn/procedures/ticket_splitItemPackingType.sql @@ -18,19 +18,34 @@ BEGIN DECLARE vDefaultPackingType VARCHAR(1); DECLARE vHasOriginalPackingType BOOLEAN; DECLARE vNewTicketFk INT; + DECLARE vThrowAway INT; DECLARE vItemPackingTypes CURSOR FOR SELECT DISTINCT itemPackingTypeFk FROM tSalesToMove; DECLARE CONTINUE HANDLER FOR NOT FOUND SET vIsDone = TRUE; + DECLARE EXIT HANDLER FOR SQLEXCEPTION + BEGIN + ROLLBACK; + RESIGNAL; + END; + CREATE OR REPLACE TEMPORARY TABLE tSalesToMove ( ticketFk INT, saleFk INT, itemPackingTypeFk VARCHAR(1) ) ENGINE=MEMORY; - SELECT vDefaultPackingTypeFk INTO vDefaultPackingType FROM itemConfig LIMIT 1; + SELECT defaultPackingTypeFk INTO vDefaultPackingType FROM itemConfig LIMIT 1; + + START TRANSACTION; + + SELECT t.id INTO vThrowAway + FROM ticket t + JOIN sale s ON s.id = t.id + WHERE t.id = vSelf + FOR UPDATE; SELECT EXISTS ( SELECT TRUE @@ -48,11 +63,12 @@ BEGIN SELECT s.id, i.itemPackingTypeFk FROM sale s JOIN item i ON i.id = s.itemFk - WHERE s.ticketFk = vSelf - AND i.itemPackingTypeFk <> vOriginalItemPackingTypeFk; + WHERE s.ticketFk = vSelf + AND i.itemPackingTypeFk <> vOriginalItemPackingTypeFk; OPEN vItemPackingTypes; l: LOOP + SET vIsDone = FALSE; FETCH vItemPackingTypes INTO vCurrentPackingType; IF vIsDone THEN @@ -61,6 +77,11 @@ BEGIN CALL ticket_Clone(vSelf, vNewTicketFk); + SELECT id INTO vThrowAway + FROM ticket t + WHERE t.id = vNewTicketFk + FOR UPDATE; + UPDATE tSalesToMove SET ticketFk = vNewTicketFk WHERE itemPackingTypeFk = vCurrentPackingType; @@ -73,25 +94,27 @@ BEGIN WHERE s.ticketFk = vSelf AND i.itemPackingTypeFk IS NULL; END IF; + END LOOP; CLOSE vItemPackingTypes; UPDATE sale s JOIN tSalesToMove t ON t.saleFk = s.id - SET s.ticketFk = t.ticketFk - WHERE t.ticketFk IS NOT NULL; + SET s.ticketFk = t.ticketFk; CREATE OR REPLACE TEMPORARY TABLE tmp.ticketIPT ENGINE=MEMORY - SELECT s.ticketFk, i.itemPackingTypeFk + SELECT s.ticketFk, MAX(i.itemPackingTypeFk) itemPackingTypeFk FROM sale s JOIN item i ON i.id = s.itemFk WHERE s.ticketFk = vSelf - GROUP BY s.ticketFk, i.itemPackingTypeFk + GROUP BY s.ticketFk UNION - SELECT ticketFk, itemPackingTypeFk + SELECT ticketFk, MAX(itemPackingTypeFk) FROM tSalesToMove - GROUP BY ticketFk, itemPackingTypeFk; + GROUP BY ticketFk; + + COMMIT; DROP TEMPORARY TABLE tSalesToMove; END$$ -- 2.40.1 From 031c4398aea2607553126ecc1237384bd87398bb Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Carlos=20Andr=C3=A9s?= Date: Wed, 20 Nov 2024 19:19:03 +0100 Subject: [PATCH 4/4] refactor: refs #8210 ticket_splitItemPackingType --- .../ticket_splitItemPackingType.sql | 27 +++++++++++-------- 1 file changed, 16 insertions(+), 11 deletions(-) diff --git a/db/routines/vn/procedures/ticket_splitItemPackingType.sql b/db/routines/vn/procedures/ticket_splitItemPackingType.sql index 1a1e1ff07..31e0c24e7 100644 --- a/db/routines/vn/procedures/ticket_splitItemPackingType.sql +++ b/db/routines/vn/procedures/ticket_splitItemPackingType.sql @@ -18,7 +18,7 @@ BEGIN DECLARE vDefaultPackingType VARCHAR(1); DECLARE vHasOriginalPackingType BOOLEAN; DECLARE vNewTicketFk INT; - DECLARE vThrowAway INT; + DECLARE vTicketFk INT; DECLARE vItemPackingTypes CURSOR FOR SELECT DISTINCT itemPackingTypeFk FROM tSalesToMove; @@ -37,15 +37,12 @@ BEGIN itemPackingTypeFk VARCHAR(1) ) ENGINE=MEMORY; - SELECT defaultPackingTypeFk INTO vDefaultPackingType FROM itemConfig LIMIT 1; - - START TRANSACTION; - - SELECT t.id INTO vThrowAway - FROM ticket t - JOIN sale s ON s.id = t.id - WHERE t.id = vSelf - FOR UPDATE; + SELECT COALESCE(MAX(ic.defaultPackingTypeFk), MAX(i.itemPackingTypeFk)) INTO vDefaultPackingType + FROM vn.sale s + JOIN item i ON i.id = s.itemFk + LEFT JOIN itemConfig ic ON ic.defaultPackingTypeFk = i.itemPackingTypeFk + WHERE s.ticketFk = vSelf + GROUP BY s.ticketFk; SELECT EXISTS ( SELECT TRUE @@ -59,6 +56,14 @@ BEGIN SET vOriginalItemPackingTypeFk = vDefaultPackingType; END IF; + START TRANSACTION; + + SELECT t.id INTO vTicketFk + FROM ticket t + JOIN sale s ON s.id = t.id + WHERE t.id = vSelf + FOR UPDATE; + INSERT INTO tSalesToMove (saleFk, itemPackingTypeFk) SELECT s.id, i.itemPackingTypeFk FROM sale s @@ -77,7 +82,7 @@ BEGIN CALL ticket_Clone(vSelf, vNewTicketFk); - SELECT id INTO vThrowAway + SELECT id INTO vTicketFk FROM ticket t WHERE t.id = vNewTicketFk FOR UPDATE; -- 2.40.1