From 3146f4f5b611a57d371ad3456049f1300d7deb45 Mon Sep 17 00:00:00 2001 From: guillermo Date: Thu, 2 May 2024 14:59:30 +0200 Subject: [PATCH 1/8] refactor: refs #6701 Refactor claim_ratio_routine --- .../bi/procedures/claim_ratio_routine.sql | 166 ------------------ db/routines/vn/procedures/claimRatio_add.sql | 154 ++++++++++++++++ .../11028-silverCarnation/00-firstScript.sql | 4 + 3 files changed, 158 insertions(+), 166 deletions(-) delete mode 100644 db/routines/bi/procedures/claim_ratio_routine.sql create mode 100644 db/routines/vn/procedures/claimRatio_add.sql create mode 100644 db/versions/11028-silverCarnation/00-firstScript.sql diff --git a/db/routines/bi/procedures/claim_ratio_routine.sql b/db/routines/bi/procedures/claim_ratio_routine.sql deleted file mode 100644 index ae87e15a2..000000000 --- a/db/routines/bi/procedures/claim_ratio_routine.sql +++ /dev/null @@ -1,166 +0,0 @@ -DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `bi`.`claim_ratio_routine`() -BEGIN - DECLARE vMonthToRefund INT DEFAULT 4; - - /* - * PAK 2015-11-20 - * Se trata de añadir a la tabla Greuges todos los - * cargos que luego vamos a utilizar para calcular el recobro - */ - - -- Reclamaciones demasiado sensibles - - INSERT INTO vn.greuge(shipped, clientFk, description, - amount, greugeTypeFk, ticketFk) - SELECT c.ticketCreated - , c.clientFk - , concat('Claim ', c.id,' : ', s.concept) - ,round( -1 * ((c.responsibility -1)/4) * s.quantity * - s.price * (100 - s.discount) / 100, 2) - , 4 - , s.ticketFk - FROM vn.sale s - JOIN vn.claimEnd ce ON ce.saleFk = s.id - JOIN vn.claim c ON c.id = ce.claimFk - WHERE ce.claimDestinationFk NOT IN (1,5) - AND NOT ce.isGreuge - AND c.claimStateFk = 3; - - -- Reclamaciones que pasan a Maná - - INSERT INTO vn.greuge(shipped, clientFk, description, - amount, greugeTypeFk, ticketFk) - SELECT c.ticketCreated - , c.clientFk - , concat('Claim_mana ',c.id,' : ', s.concept) - ,round( ((c.responsibility -1)/4) * s.quantity * s.price * (100 - s.discount) / 100, 2) - ,3 - ,s.ticketFk - FROM vn.sale s - JOIN vn.claimEnd ce ON ce.saleFk = s.id - JOIN vn.claim c ON c.id = ce.claimFk - WHERE ce.claimDestinationFk NOT IN (1,5) - AND NOT ce.isGreuge - AND c.claimStateFk = 3 - AND c.isChargedToMana; - - -- Marcamos para no repetir - UPDATE vn.claimEnd ce - JOIN vn.claim c ON c.id = ce.claimFk - SET c.isChargedToMana = TRUE - WHERE ce.claimDestinationFk NOT IN (1,5) - AND NOT ce.isGreuge - AND c.claimStateFk = 3; - - -- Recobros - - DROP TEMPORARY TABLE IF EXISTS tmp.ticket_list; - CREATE TEMPORARY TABLE tmp.ticket_list - (PRIMARY KEY (Id_Ticket)) - SELECT DISTINCT t.id Id_Ticket - FROM vn.saleComponent sc - JOIN vn.sale s ON sc.saleFk = s.id - JOIN vn.ticket t ON t.id = s.ticketFk - JOIN vn.ticketLastState ts ON ts.ticketFk = t.id - JOIN vn.ticketTracking tt ON tt.id = ts.ticketTrackingFk - JOIN vn.state st ON st.id = tt.stateFk - WHERE sc.componentFk = 17 - AND sc.isGreuge = 0 - AND t.shipped >= '2016-10-01' - AND t.shipped < util.VN_CURDATE() - AND st.alertLevel >= 3; - - DELETE g.* - FROM vn.greuge g - JOIN tmp.ticket_list t ON g.ticketFk = t.Id_Ticket - WHERE g.greugeTypeFk = 2; - - INSERT INTO vn.greuge(clientFk, description, amount,shipped, - greugeTypeFk, ticketFk) - SELECT t.clientFk - ,concat('recobro ', s.ticketFk), - round(SUM(sc.value*s.quantity),2) - AS dif, - date(t.shipped) - , 2 - ,tt.Id_Ticket - FROM vn.sale s - JOIN vn.ticket t ON t.id = s.ticketFk - JOIN tmp.ticket_list tt ON tt.Id_Ticket = t.id - JOIN vn.saleComponent sc - ON sc.saleFk = s.id AND sc.componentFk = 17 - GROUP BY t.id - HAVING ABS(dif) > 1; - - UPDATE vn.saleComponent sc - JOIN vn.sale s ON s.id = sc.saleFk - JOIN tmp.ticket_list tt ON tt.Id_Ticket = s.ticketFk - SET sc.isGreuge = 1 - WHERE sc.componentFk = 17; - - /* - * Recalculamos la ratio de las reclamaciones, que luego - * se va a utilizar en el recobro - */ - - REPLACE bi.claims_ratio(Id_Cliente, Consumo, Reclamaciones, Ratio, recobro) - SELECT id, 0,0,0,0 - FROM vn.client; - - REPLACE bi.claims_ratio(Id_Cliente, Consumo, Reclamaciones, Ratio, recobro) - SELECT fm.Id_Cliente, 12 * fm.Consumo, Reclamaciones, - round(Reclamaciones / (12*fm.Consumo),4), 0 - FROM bi.facturacion_media_anual fm - LEFT JOIN( - SELECT c.clientFk, round(sum(-1 * ((c.responsibility -1)/4) * - s.quantity * s.price * (100 - s.discount) / 100)) - AS Reclamaciones - FROM vn.sale s - JOIN vn.claimEnd ce ON ce.saleFk = s.id - JOIN vn.claim c ON c.id = ce.claimFk - WHERE ce.claimDestinationFk NOT IN (1,5) - AND c.claimStateFk = 3 - AND c.ticketCreated >= TIMESTAMPADD(YEAR, -1, util.VN_CURDATE()) - GROUP BY c.clientFk - ) claims ON claims.clientFk = fm.Id_Cliente; - - - -- Calculamos el porcentaje del recobro para añadirlo al precio de venta - UPDATE bi.claims_ratio cr - JOIN ( - SELECT clientFk Id_Cliente, IFNULL(SUM(amount), 0) AS Greuge - FROM vn.greuge - WHERE shipped <= util.VN_CURDATE() - GROUP BY clientFk - ) g ON g.Id_Cliente = cr.Id_Cliente - SET recobro = GREATEST(0,round(IFNULL(Greuge, 0) / - (IFNULL(Consumo, 0) * vMonthToRefund / 12 ) ,3)); - - -- Protección neonatos - UPDATE bi.claims_ratio cr - JOIN vn.firstTicketShipped fts ON fts.clientFk = cr.Id_Cliente - SET recobro = 0, Ratio = 0 - WHERE fts.shipped > TIMESTAMPADD(MONTH,-1,util.VN_CURDATE()); - - -- CLIENTE 7983, JULIAN SUAU - UPDATE bi.claims_ratio SET recobro = LEAST(0.05, recobro) WHERE Id_Cliente = 7983; - - -- CLIENTE 4358 - UPDATE bi.claims_ratio SET recobro = GREATEST(0.05, recobro) WHERE Id_Cliente = 4358; - - -- CLIENTE 5523, VERDECORA - UPDATE bi.claims_ratio SET recobro = GREATEST(0.12, recobro) WHERE Id_Cliente = 5523; - - -- CLIENTE 15979, SERVEIS VETERINARIS - UPDATE bi.claims_ratio SET recobro = GREATEST(0.05, recobro) WHERE Id_Cliente = 15979; - - -- CLIENTE 5189 i 8942, son de CSR i son el mateix client - UPDATE bi.claims_ratio cr - JOIN (SELECT sum(Consumo * recobro)/sum(Consumo) as recobro - FROM bi.claims_ratio - WHERE Id_Cliente IN ( 5189,8942) - ) sub - SET cr.recobro = sub.recobro - WHERE Id_Cliente IN ( 5189,8942); -END$$ -DELIMITER ; diff --git a/db/routines/vn/procedures/claimRatio_add.sql b/db/routines/vn/procedures/claimRatio_add.sql new file mode 100644 index 000000000..2f64f8c7e --- /dev/null +++ b/db/routines/vn/procedures/claimRatio_add.sql @@ -0,0 +1,154 @@ +DELIMITER $$ +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`claimRatio_add`() +BEGIN +/* +* PAK 2015-11-20 +* Se trata de añadir a la tabla Greuges todos los +* cargos que luego vamos a utilizar para calcular el recobro +*/ + DECLARE vMonthToRefund INT DEFAULT 4; + DECLARE vRecoveryGreugeType INT; + + SELECT id INTO vRecoveryGreugeType + FROM greugeType + WHERE code = 'recovery'; + + -- Reclamaciones demasiado sensibles + INSERT INTO greuge(shipped, clientFk, description, + amount, greugeTypeFk, ticketFk) + SELECT c.ticketCreated + , c.clientFk + , concat('Claim ', c.id,' : ', s.concept) + ,round( -1 * ((c.responsibility -1)/4) * s.quantity * + s.price * (100 - s.discount) / 100, 2) + , 4 + , s.ticketFk + FROM sale s + JOIN claimEnd ce ON ce.saleFk = s.id + JOIN claim c ON c.id = ce.claimFk + WHERE ce.claimDestinationFk NOT IN (1,5) + AND NOT ce.isGreuge + AND c.claimStateFk = 3; + + -- Reclamaciones que pasan a Maná + INSERT INTO greuge(shipped, + clientFk, + `description`, + amount, + greugeTypeFk, + ticketFk) + SELECT c.ticketCreated, + c.clientFk, + concat('Claim_mana ',c.id,' : ', s.concept), + round( ((c.responsibility -1)/4) * s.quantity * s.price * (100 - s.discount) / 100, 2), + 3, + s.ticketFk + FROM sale s + JOIN claimEnd ce ON ce.saleFk = s.id + JOIN claim c ON c.id = ce.claimFk + WHERE ce.claimDestinationFk NOT IN (1,5) + AND NOT ce.isGreuge + AND c.claimStateFk = 3 + AND c.isChargedToMana; + + -- Marcamos para no repetir + UPDATE claimEnd ce + JOIN claim c ON c.id = ce.claimFk + SET c.isChargedToMana = TRUE + WHERE ce.claimDestinationFk NOT IN (1,5) + AND NOT ce.isGreuge + AND c.claimStateFk = 3; + + -- Recobros + CREATE OR REPLACE TEMPORARY TABLE tTicketList + (PRIMARY KEY (ticketFk)) + SELECT DISTINCT s.ticketFk + FROM saleComponent sc + JOIN sale s ON sc.saleFk = s.id + JOIN ticket t ON t.id = s.ticketFk + JOIN ticketLastState ts ON ts.ticketFk = t.id + JOIN ticketTracking tt ON tt.id = ts.ticketTrackingFk + JOIN state st ON st.id = tt.stateFk + WHERE sc.componentFk = 17 + AND sc.isGreuge = 0 + AND t.shipped >= '2016-10-01' + AND t.shipped < util.VN_CURDATE() + AND st.alertLevel >= 3; + + DELETE g.* + FROM greuge g + JOIN tTicketList t ON t.ticketFk = g.ticketFk + WHERE g.greugeTypeFk = vRecoveryGreugeType; + + INSERT INTO greuge(clientFk, + `description`, + amount, + shipped, + greugeTypeFk, + ticketFk) + SELECT t.clientFk, + 'Recobro', + - ROUND(SUM(sc.value * s.quantity), 2) dif, + DATE(t.shipped), + vRecoveryGreugeType, + tl.ticketFk + FROM sale s + JOIN ticket t ON t.id = s.ticketFk + JOIN tTicketList tl ON tl.ticketFk = t.id + JOIN saleComponent sc ON sc.saleFk = s.id + AND sc.componentFk = 17 + GROUP BY t.id + HAVING ABS(dif) > 1; + + UPDATE saleComponent sc + JOIN sale s ON s.id = sc.saleFk + JOIN tTicketList tl ON tl.ticketFk = s.ticketFk + SET sc.isGreuge = TRUE + WHERE sc.componentFk = 17; + + /* + * Recalculamos la ratio de las reclamaciones, que luego + * se va a utilizar en el recobro + */ + REPLACE claimRatio(clientFk, yearSale, claimAmount, claimingRate, priceIncreasing) + SELECT id, 0, 0, 0, 0 + FROM client; + + REPLACE claimRatio(clientFk, yearSale, claimAmount, claimingRate, priceIncreasing) + SELECT cac.clientFk, 12 * cac.invoiced, totalClaims, + ROUND(totalClaims / (12 * cac.invoiced), 4), 0 + FROM bs.clientAnnualConsumption cac + LEFT JOIN( + SELECT c.clientFk, round(sum(-1 * ((c.responsibility -1)/4) * + s.quantity * s.price * (100 - s.discount) / 100)) + totalClaims + FROM sale s + JOIN claimEnd ce ON ce.saleFk = s.id + JOIN claim c ON c.id = ce.claimFk + WHERE ce.claimDestinationFk NOT IN (1,5) + AND c.claimStateFk = 3 + AND c.ticketCreated >= util.VN_CURDATE() - INTERVAL 1 YEAR + GROUP BY c.clientFk + ) claims ON claims.clientFk = fm.Id_Cliente; + + -- Calculamos el porcentaje del recobro para añadirlo al precio de venta + UPDATE claimRatio cr + JOIN ( + SELECT clientFk, IFNULL(SUM(amount), 0) AS Greuge + FROM greuge + WHERE shipped <= util.VN_CURDATE() + GROUP BY clientFk + ) g ON g.clientFk = cr.clientFk + SET cr.priceIncreasing = GREATEST(0, round(IFNULL(Greuge, 0) / + (IFNULL(Consumo, 0) * vMonthToRefund / 12 ), 3)); + + -- Protección neonatos + UPDATE claimRatio cr + JOIN firstTicketShipped fts ON fts.clientFk = cr.clientFk + SET cr.priceIncreasing = 0, + cr.claimingRate = 0 + WHERE fts.shipped > util.VN_CURDATE() - INTERVAL 1 MONTH; + + DROP TEMPORARY TABLE tTicketList; +END$$ +DELIMITER ; diff --git a/db/versions/11028-silverCarnation/00-firstScript.sql b/db/versions/11028-silverCarnation/00-firstScript.sql new file mode 100644 index 000000000..f865b0caf --- /dev/null +++ b/db/versions/11028-silverCarnation/00-firstScript.sql @@ -0,0 +1,4 @@ +UPDATE IGNORE bs.nightTask + SET `procedure` = 'claimRatio_add', + `schema` = 'vn' + WHERE `procedure` = 'claim_ratio_routine'; From 883f6f18a3b48560e82446251453057f5ef4a894 Mon Sep 17 00:00:00 2001 From: guillermo Date: Fri, 3 May 2024 13:47:55 +0200 Subject: [PATCH 2/8] refactor: refs #6701 Refactor claim_ratio_routine --- db/routines/vn/procedures/claimRatio_add.sql | 171 ++++++++++++------- 1 file changed, 108 insertions(+), 63 deletions(-) diff --git a/db/routines/vn/procedures/claimRatio_add.sql b/db/routines/vn/procedures/claimRatio_add.sql index 2f64f8c7e..deb5cc068 100644 --- a/db/routines/vn/procedures/claimRatio_add.sql +++ b/db/routines/vn/procedures/claimRatio_add.sql @@ -7,57 +7,82 @@ BEGIN * cargos que luego vamos a utilizar para calcular el recobro */ DECLARE vMonthToRefund INT DEFAULT 4; - DECLARE vRecoveryGreugeType INT; + DECLARE vRecoveryGreugeType INT + DEFAULT (SELECT id FROM greugeType WHERE code = 'recovery'); + DECLARE vManaGreugeType INT + DEFAULT (SELECT id FROM greugeType WHERE code = 'mana'); + DECLARE vClaimGreugeType INT + DEFAULT (SELECT id FROM greugeType WHERE code = 'claim'); + DECLARE vDebtComponentType INT + DEFAULT (SELECT id FROM component WHERE code = 'debtCollection'); - SELECT id INTO vRecoveryGreugeType - FROM greugeType - WHERE code = 'recovery'; + IF vRecoveryGreugeType IS NULL + OR vManaGreugeType IS NULL + OR vClaimGreugeType IS NULL + OR vDebtComponentType IS NULL THEN + + CALL util.throw('Required variables not found'); + END IF; -- Reclamaciones demasiado sensibles - INSERT INTO greuge(shipped, clientFk, description, - amount, greugeTypeFk, ticketFk) - SELECT c.ticketCreated - , c.clientFk - , concat('Claim ', c.id,' : ', s.concept) - ,round( -1 * ((c.responsibility -1)/4) * s.quantity * - s.price * (100 - s.discount) / 100, 2) - , 4 - , s.ticketFk - FROM sale s - JOIN claimEnd ce ON ce.saleFk = s.id - JOIN claim c ON c.id = ce.claimFk - WHERE ce.claimDestinationFk NOT IN (1,5) - AND NOT ce.isGreuge - AND c.claimStateFk = 3; - - -- Reclamaciones que pasan a Maná - INSERT INTO greuge(shipped, - clientFk, - `description`, - amount, - greugeTypeFk, - ticketFk) + INSERT INTO greuge( + shipped, + clientFk, + `description`, + amount, + greugeTypeFk, + ticketFk + ) SELECT c.ticketCreated, c.clientFk, - concat('Claim_mana ',c.id,' : ', s.concept), - round( ((c.responsibility -1)/4) * s.quantity * s.price * (100 - s.discount) / 100, 2), - 3, + CONCAT('Claim ', c.id,' : ', s.concept), + ROUND(-1 * ((c.responsibility - 1) / 4) * s.quantity * + s.price * (100 - s.discount) / 100, 2), + vClaimGreugeType, s.ticketFk FROM sale s JOIN claimEnd ce ON ce.saleFk = s.id + JOIN claimDestination cd ON cd.id = ce.claimDestinationFk JOIN claim c ON c.id = ce.claimFk - WHERE ce.claimDestinationFk NOT IN (1,5) + JOIN claimState cs ON cs.id = c.claimStateFk + WHERE ce.claimDestinationFk NOT IN ('Bueno', 'Corregido') AND NOT ce.isGreuge - AND c.claimStateFk = 3 + AND cs.code = 'resolved'; + + -- Reclamaciones que pasan a Maná + INSERT INTO greuge( + shipped, + clientFk, + `description`, + amount, + greugeTypeFk, + ticketFk + ) + SELECT c.ticketCreated, + c.clientFk, + CONCAT('Claim_mana ', c.id,' : ', s.concept), + ROUND( ((c.responsibility -1)/4) * s.quantity * s.price * (100 - s.discount) / 100, 2), + vManaGreugeType, + s.ticketFk + FROM sale s + JOIN claimEnd ce ON ce.saleFk = s.id + JOIN claimDestination cd ON cd.id = ce.claimDestinationFk + JOIN claim c ON c.id = ce.claimFk + JOIN claimState cs ON cs.id = c.claimStateFk + WHERE cd.description NOT IN ('Bueno', 'Corregido') + AND NOT ce.isGreuge + AND cs.code = 'resolved' AND c.isChargedToMana; -- Marcamos para no repetir UPDATE claimEnd ce + JOIN claimDestination cd ON cd.id = ce.claimDestinationFk JOIN claim c ON c.id = ce.claimFk + JOIN claimState cs ON cs.id = c.claimStateFk SET c.isChargedToMana = TRUE - WHERE ce.claimDestinationFk NOT IN (1,5) + WHERE cd.description NOT IN ('Bueno', 'Corregido') AND NOT ce.isGreuge - AND c.claimStateFk = 3; + AND cs.code = 'resolved'; -- Recobros CREATE OR REPLACE TEMPORARY TABLE tTicketList @@ -69,23 +94,26 @@ BEGIN JOIN ticketLastState ts ON ts.ticketFk = t.id JOIN ticketTracking tt ON tt.id = ts.ticketTrackingFk JOIN state st ON st.id = tt.stateFk - WHERE sc.componentFk = 17 - AND sc.isGreuge = 0 + JOIN alertLevel al ON al.id = st.alertLevel + WHERE sc.componentFk = vDebtComponentType + AND NOT sc.isGreuge AND t.shipped >= '2016-10-01' AND t.shipped < util.VN_CURDATE() - AND st.alertLevel >= 3; + AND al.code = 'DELIVERED'; DELETE g.* FROM greuge g JOIN tTicketList t ON t.ticketFk = g.ticketFk WHERE g.greugeTypeFk = vRecoveryGreugeType; - INSERT INTO greuge(clientFk, - `description`, - amount, - shipped, - greugeTypeFk, - ticketFk) + INSERT INTO greuge( + clientFk, + `description`, + amount, + shipped, + greugeTypeFk, + ticketFk + ) SELECT t.clientFk, 'Recobro', - ROUND(SUM(sc.value * s.quantity), 2) dif, @@ -96,51 +124,68 @@ BEGIN JOIN ticket t ON t.id = s.ticketFk JOIN tTicketList tl ON tl.ticketFk = t.id JOIN saleComponent sc ON sc.saleFk = s.id - AND sc.componentFk = 17 + AND sc.componentFk = vDebtComponentType GROUP BY t.id - HAVING ABS(dif) > 1; + HAVING ABS(dif) > 1; UPDATE saleComponent sc JOIN sale s ON s.id = sc.saleFk JOIN tTicketList tl ON tl.ticketFk = s.ticketFk SET sc.isGreuge = TRUE - WHERE sc.componentFk = 17; + WHERE sc.componentFk = vDebtComponentType; /* * Recalculamos la ratio de las reclamaciones, que luego * se va a utilizar en el recobro */ - REPLACE claimRatio(clientFk, yearSale, claimAmount, claimingRate, priceIncreasing) - SELECT id, 0, 0, 0, 0 - FROM client; + REPLACE claimRatio( + clientFk, + yearSale, + claimAmount, + claimingRate, + priceIncreasing + ) + SELECT id, 0, 0, 0, 0 FROM client; - REPLACE claimRatio(clientFk, yearSale, claimAmount, claimingRate, priceIncreasing) - SELECT cac.clientFk, 12 * cac.invoiced, totalClaims, - ROUND(totalClaims / (12 * cac.invoiced), 4), 0 + REPLACE claimRatio( + clientFk, + yearSale, + claimAmount, + claimingRate, + priceIncreasing + ) + SELECT cac.clientFk, + 12 * cac.invoiced, + totalClaims, + ROUND(totalClaims / (12 * cac.invoiced), 4), + 0 FROM bs.clientAnnualConsumption cac - LEFT JOIN( - SELECT c.clientFk, round(sum(-1 * ((c.responsibility -1)/4) * - s.quantity * s.price * (100 - s.discount) / 100)) - totalClaims + LEFT JOIN ( + SELECT c.clientFk, + ROUND(SUM(-1 * ((c.responsibility - 1) / 4) * + s.quantity * s.price * (100 - s.discount) + / 100)) totalClaims FROM sale s JOIN claimEnd ce ON ce.saleFk = s.id + JOIN claimDestination cd ON cd.id = ce.claimDestinationFk JOIN claim c ON c.id = ce.claimFk - WHERE ce.claimDestinationFk NOT IN (1,5) - AND c.claimStateFk = 3 + JOIN claimState cs ON cs.id = c.claimStateFk + WHERE ce.claimDestinationFk NOT IN ('Bueno', 'Corregido') + AND cs.code = 'resolved' AND c.ticketCreated >= util.VN_CURDATE() - INTERVAL 1 YEAR GROUP BY c.clientFk - ) claims ON claims.clientFk = fm.Id_Cliente; + ) sub ON sub.clientFk = cac.clientFk; -- Calculamos el porcentaje del recobro para añadirlo al precio de venta UPDATE claimRatio cr JOIN ( - SELECT clientFk, IFNULL(SUM(amount), 0) AS Greuge + SELECT clientFk, IFNULL(SUM(amount), 0) greuge FROM greuge WHERE shipped <= util.VN_CURDATE() GROUP BY clientFk - ) g ON g.clientFk = cr.clientFk - SET cr.priceIncreasing = GREATEST(0, round(IFNULL(Greuge, 0) / - (IFNULL(Consumo, 0) * vMonthToRefund / 12 ), 3)); + ) sub ON subg.clientFk = cr.clientFk + SET cr.priceIncreasing = GREATEST(0, ROUND(IFNULL(sub.greuge, 0) / + (IFNULL(cr.yearSale, 0) * vMonthToRefund / 12 ), 3)); -- Protección neonatos UPDATE claimRatio cr From f0b814c79b895ee4ac6487a6a4494c35feaf8c64 Mon Sep 17 00:00:00 2001 From: guillermo Date: Fri, 3 May 2024 14:15:55 +0200 Subject: [PATCH 3/8] refactor: refs #6701 Refactor claim_ratio_routine --- db/dump/fixtures.before.sql | 6 +-- db/routines/vn/procedures/claimRatio_add.sql | 37 +++++++------------ .../11028-silverCarnation/00-firstScript.sql | 6 +++ 3 files changed, 22 insertions(+), 27 deletions(-) diff --git a/db/dump/fixtures.before.sql b/db/dump/fixtures.before.sql index 06e94c99e..6b8166caa 100644 --- a/db/dump/fixtures.before.sql +++ b/db/dump/fixtures.before.sql @@ -831,9 +831,9 @@ INSERT INTO `vn`.`config`(`id`, `mdbServer`, `fakeEmail`, `defaultersMaxAmount`, INSERT INTO `vn`.`greugeType`(`id`, `name`, `code`) VALUES (1, 'Diff', 'diff'), - (2, 'Recover', 'recover'), - (3, 'Mana', 'mana'), - (4, 'Reclaim', 'reclaim'), + (2, 'Recobro', 'recovery'), + (3, 'Maná', 'mana'), + (4, 'Reclamación', 'claim'), (5, 'Heritage', 'heritage'), (6, 'Miscellaneous', 'miscellaneous'), (7, 'Freight Pickup', 'freightPickUp'); diff --git a/db/routines/vn/procedures/claimRatio_add.sql b/db/routines/vn/procedures/claimRatio_add.sql index deb5cc068..36b9023da 100644 --- a/db/routines/vn/procedures/claimRatio_add.sql +++ b/db/routines/vn/procedures/claimRatio_add.sql @@ -2,9 +2,8 @@ DELIMITER $$ CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`claimRatio_add`() BEGIN /* -* PAK 2015-11-20 -* Se trata de añadir a la tabla Greuges todos los -* cargos que luego vamos a utilizar para calcular el recobro +* Añade a la tabla greuges todos los cargos necesario y +* que luego lo utilizamos para calcular el recobro. */ DECLARE vMonthToRefund INT DEFAULT 4; DECLARE vRecoveryGreugeType INT @@ -61,7 +60,8 @@ BEGIN SELECT c.ticketCreated, c.clientFk, CONCAT('Claim_mana ', c.id,' : ', s.concept), - ROUND( ((c.responsibility -1)/4) * s.quantity * s.price * (100 - s.discount) / 100, 2), + ROUND(((c.responsibility - 1) / 4) * s.quantity * + s.price * (100 - s.discount) / 100, 2), vManaGreugeType, s.ticketFk FROM sale s @@ -134,20 +134,7 @@ BEGIN SET sc.isGreuge = TRUE WHERE sc.componentFk = vDebtComponentType; - /* - * Recalculamos la ratio de las reclamaciones, que luego - * se va a utilizar en el recobro - */ - REPLACE claimRatio( - clientFk, - yearSale, - claimAmount, - claimingRate, - priceIncreasing - ) - SELECT id, 0, 0, 0, 0 FROM client; - - REPLACE claimRatio( + INSERT INTO claimRatio( clientFk, yearSale, claimAmount, @@ -163,8 +150,8 @@ BEGIN LEFT JOIN ( SELECT c.clientFk, ROUND(SUM(-1 * ((c.responsibility - 1) / 4) * - s.quantity * s.price * (100 - s.discount) - / 100)) totalClaims + s.quantity * s.price * (100 - s.discount) + / 100)) totalClaims FROM sale s JOIN claimEnd ce ON ce.saleFk = s.id JOIN claimDestination cd ON cd.id = ce.claimDestinationFk @@ -183,17 +170,19 @@ BEGIN FROM greuge WHERE shipped <= util.VN_CURDATE() GROUP BY clientFk - ) sub ON subg.clientFk = cr.clientFk + ) sub ON sub.clientFk = cr.clientFk SET cr.priceIncreasing = GREATEST(0, ROUND(IFNULL(sub.greuge, 0) / - (IFNULL(cr.yearSale, 0) * vMonthToRefund / 12 ), 3)); + (IFNULL(cr.yearSale, 0) * vMonthToRefund / 12 ), 3)) + WHERE cr.dated = util.VN_CURDATE(); -- Protección neonatos UPDATE claimRatio cr JOIN firstTicketShipped fts ON fts.clientFk = cr.clientFk SET cr.priceIncreasing = 0, cr.claimingRate = 0 - WHERE fts.shipped > util.VN_CURDATE() - INTERVAL 1 MONTH; - + WHERE fts.shipped > util.VN_CURDATE() - INTERVAL 1 MONTH + AND cr.dated = util.VN_CURDATE(); + DROP TEMPORARY TABLE tTicketList; END$$ DELIMITER ; diff --git a/db/versions/11028-silverCarnation/00-firstScript.sql b/db/versions/11028-silverCarnation/00-firstScript.sql index f865b0caf..9d291f451 100644 --- a/db/versions/11028-silverCarnation/00-firstScript.sql +++ b/db/versions/11028-silverCarnation/00-firstScript.sql @@ -2,3 +2,9 @@ UPDATE IGNORE bs.nightTask SET `procedure` = 'claimRatio_add', `schema` = 'vn' WHERE `procedure` = 'claim_ratio_routine'; + +ALTER TABLE vn.claimRatio ADD dated DATE DEFAULT current_timestamp() NOT NULL; +ALTER TABLE vn.claimRatio CHANGE dated dated DATE DEFAULT current_timestamp() NOT NULL FIRST; +ALTER TABLE vn.claimRatio DROP FOREIGN KEY claimRatio_ibfk_1; +ALTER TABLE vn.claimRatio DROP PRIMARY KEY; +ALTER TABLE vn.claimRatio ADD CONSTRAINT claimRatio_pk PRIMARY KEY (dated,clientFk); From 4703ebbdf3ce7922f16a52d852d90ee3abd94cbe Mon Sep 17 00:00:00 2001 From: guillermo Date: Mon, 3 Jun 2024 11:38:09 +0200 Subject: [PATCH 4/8] refactor: refs #7519 Minor change --- db/dump/fixtures.before.sql | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/db/dump/fixtures.before.sql b/db/dump/fixtures.before.sql index 6b8166caa..8bcedeb8d 100644 --- a/db/dump/fixtures.before.sql +++ b/db/dump/fixtures.before.sql @@ -831,9 +831,9 @@ INSERT INTO `vn`.`config`(`id`, `mdbServer`, `fakeEmail`, `defaultersMaxAmount`, INSERT INTO `vn`.`greugeType`(`id`, `name`, `code`) VALUES (1, 'Diff', 'diff'), - (2, 'Recobro', 'recovery'), - (3, 'Maná', 'mana'), - (4, 'Reclamación', 'claim'), + (2, 'Recovery', 'recovery'), + (3, 'Mana', 'mana'), + (4, 'Claim', 'claim'), (5, 'Heritage', 'heritage'), (6, 'Miscellaneous', 'miscellaneous'), (7, 'Freight Pickup', 'freightPickUp'); From 8cef8eace7a92a8fb96fd124dd720fd07a455304 Mon Sep 17 00:00:00 2001 From: guillermo Date: Mon, 3 Jun 2024 11:41:09 +0200 Subject: [PATCH 5/8] refactor: refs #7519 Minor change --- db/routines/vn/procedures/claimRatio_add.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/db/routines/vn/procedures/claimRatio_add.sql b/db/routines/vn/procedures/claimRatio_add.sql index 36b9023da..2e999f738 100644 --- a/db/routines/vn/procedures/claimRatio_add.sql +++ b/db/routines/vn/procedures/claimRatio_add.sql @@ -79,7 +79,7 @@ BEGIN JOIN claimDestination cd ON cd.id = ce.claimDestinationFk JOIN claim c ON c.id = ce.claimFk JOIN claimState cs ON cs.id = c.claimStateFk - SET c.isChargedToMana = TRUE + SET ce.isGreuge = TRUE WHERE cd.description NOT IN ('Bueno', 'Corregido') AND NOT ce.isGreuge AND cs.code = 'resolved'; From b8e95c02840358fb279008df97e0b4fed160bc0f Mon Sep 17 00:00:00 2001 From: guillermo Date: Mon, 3 Jun 2024 11:46:52 +0200 Subject: [PATCH 6/8] refactor: refs #7519 Minor change --- db/routines/vn/procedures/claimRatio_add.sql | 6 ++---- db/versions/11028-silverCarnation/00-firstScript.sql | 10 ---------- 2 files changed, 2 insertions(+), 14 deletions(-) delete mode 100644 db/versions/11028-silverCarnation/00-firstScript.sql diff --git a/db/routines/vn/procedures/claimRatio_add.sql b/db/routines/vn/procedures/claimRatio_add.sql index 2e999f738..7def0837f 100644 --- a/db/routines/vn/procedures/claimRatio_add.sql +++ b/db/routines/vn/procedures/claimRatio_add.sql @@ -172,16 +172,14 @@ BEGIN GROUP BY clientFk ) sub ON sub.clientFk = cr.clientFk SET cr.priceIncreasing = GREATEST(0, ROUND(IFNULL(sub.greuge, 0) / - (IFNULL(cr.yearSale, 0) * vMonthToRefund / 12 ), 3)) - WHERE cr.dated = util.VN_CURDATE(); + (IFNULL(cr.yearSale, 0) * vMonthToRefund / 12 ), 3)); -- Protección neonatos UPDATE claimRatio cr JOIN firstTicketShipped fts ON fts.clientFk = cr.clientFk SET cr.priceIncreasing = 0, cr.claimingRate = 0 - WHERE fts.shipped > util.VN_CURDATE() - INTERVAL 1 MONTH - AND cr.dated = util.VN_CURDATE(); + WHERE fts.shipped > util.VN_CURDATE() - INTERVAL 1 MONTH; DROP TEMPORARY TABLE tTicketList; END$$ diff --git a/db/versions/11028-silverCarnation/00-firstScript.sql b/db/versions/11028-silverCarnation/00-firstScript.sql deleted file mode 100644 index 9d291f451..000000000 --- a/db/versions/11028-silverCarnation/00-firstScript.sql +++ /dev/null @@ -1,10 +0,0 @@ -UPDATE IGNORE bs.nightTask - SET `procedure` = 'claimRatio_add', - `schema` = 'vn' - WHERE `procedure` = 'claim_ratio_routine'; - -ALTER TABLE vn.claimRatio ADD dated DATE DEFAULT current_timestamp() NOT NULL; -ALTER TABLE vn.claimRatio CHANGE dated dated DATE DEFAULT current_timestamp() NOT NULL FIRST; -ALTER TABLE vn.claimRatio DROP FOREIGN KEY claimRatio_ibfk_1; -ALTER TABLE vn.claimRatio DROP PRIMARY KEY; -ALTER TABLE vn.claimRatio ADD CONSTRAINT claimRatio_pk PRIMARY KEY (dated,clientFk); From cfc5e327154fdc7e5a680395c7ccfce22bde4199 Mon Sep 17 00:00:00 2001 From: guillermo Date: Thu, 13 Jun 2024 13:11:50 +0200 Subject: [PATCH 7/8] feat: refs #6701 Fix error --- db/routines/vn/procedures/claimRatio_add.sql | 43 ++++++++++--------- .../11101-limeCordyline/00-firstScript.sql | 4 ++ 2 files changed, 26 insertions(+), 21 deletions(-) create mode 100644 db/versions/11101-limeCordyline/00-firstScript.sql diff --git a/db/routines/vn/procedures/claimRatio_add.sql b/db/routines/vn/procedures/claimRatio_add.sql index 7def0837f..8d94805db 100644 --- a/db/routines/vn/procedures/claimRatio_add.sql +++ b/db/routines/vn/procedures/claimRatio_add.sql @@ -44,7 +44,7 @@ BEGIN JOIN claimDestination cd ON cd.id = ce.claimDestinationFk JOIN claim c ON c.id = ce.claimFk JOIN claimState cs ON cs.id = c.claimStateFk - WHERE ce.claimDestinationFk NOT IN ('Bueno', 'Corregido') + WHERE cd.description NOT IN ('Bueno', 'Corregido') AND NOT ce.isGreuge AND cs.code = 'resolved'; @@ -86,20 +86,20 @@ BEGIN -- Recobros CREATE OR REPLACE TEMPORARY TABLE tTicketList - (PRIMARY KEY (ticketFk)) - SELECT DISTINCT s.ticketFk - FROM saleComponent sc - JOIN sale s ON sc.saleFk = s.id - JOIN ticket t ON t.id = s.ticketFk - JOIN ticketLastState ts ON ts.ticketFk = t.id - JOIN ticketTracking tt ON tt.id = ts.ticketTrackingFk - JOIN state st ON st.id = tt.stateFk - JOIN alertLevel al ON al.id = st.alertLevel - WHERE sc.componentFk = vDebtComponentType - AND NOT sc.isGreuge - AND t.shipped >= '2016-10-01' - AND t.shipped < util.VN_CURDATE() - AND al.code = 'DELIVERED'; + (PRIMARY KEY (ticketFk)) + SELECT DISTINCT s.ticketFk + FROM saleComponent sc + JOIN sale s ON sc.saleFk = s.id + JOIN ticket t ON t.id = s.ticketFk + JOIN ticketLastState ts ON ts.ticketFk = t.id + JOIN ticketTracking tt ON tt.id = ts.ticketTrackingFk + JOIN state st ON st.id = tt.stateFk + JOIN alertLevel al ON al.id = st.alertLevel + WHERE sc.componentFk = vDebtComponentType + AND NOT sc.isGreuge + AND t.shipped >= '2016-10-01' + AND t.shipped < util.VN_CURDATE() + AND al.code = 'DELIVERED'; DELETE g.* FROM greuge g @@ -133,20 +133,21 @@ BEGIN JOIN tTicketList tl ON tl.ticketFk = s.ticketFk SET sc.isGreuge = TRUE WHERE sc.componentFk = vDebtComponentType; - - INSERT INTO claimRatio( + + REPLACE claimRatio( clientFk, yearSale, claimAmount, claimingRate, priceIncreasing ) - SELECT cac.clientFk, + SELECT c.id, 12 * cac.invoiced, totalClaims, ROUND(totalClaims / (12 * cac.invoiced), 4), 0 - FROM bs.clientAnnualConsumption cac + FROM client c + LEFT JOIN bs.clientAnnualConsumption cac ON cac.clientFk = c.id LEFT JOIN ( SELECT c.clientFk, ROUND(SUM(-1 * ((c.responsibility - 1) / 4) * @@ -157,11 +158,11 @@ BEGIN JOIN claimDestination cd ON cd.id = ce.claimDestinationFk JOIN claim c ON c.id = ce.claimFk JOIN claimState cs ON cs.id = c.claimStateFk - WHERE ce.claimDestinationFk NOT IN ('Bueno', 'Corregido') + WHERE cd.description NOT IN ('Bueno', 'Corregido') AND cs.code = 'resolved' AND c.ticketCreated >= util.VN_CURDATE() - INTERVAL 1 YEAR GROUP BY c.clientFk - ) sub ON sub.clientFk = cac.clientFk; + ) sub ON sub.clientFk = c.id; -- Calculamos el porcentaje del recobro para añadirlo al precio de venta UPDATE claimRatio cr diff --git a/db/versions/11101-limeCordyline/00-firstScript.sql b/db/versions/11101-limeCordyline/00-firstScript.sql new file mode 100644 index 000000000..e9ffa1b12 --- /dev/null +++ b/db/versions/11101-limeCordyline/00-firstScript.sql @@ -0,0 +1,4 @@ +UPDATE IGNORE bs.nightTask + SET `schema` = 'vn', + `procedure` = 'claimRatio_add' + WHERE `procedure` = 'claim_ratio_routine'; From 1d0b89ed526b03bf5f40b85705dcb0550b848b21 Mon Sep 17 00:00:00 2001 From: guillermo Date: Mon, 17 Jun 2024 09:42:16 +0200 Subject: [PATCH 8/8] refs #7519 Requested changes --- db/dump/fixtures.before.sql | 4 ++-- db/routines/vn/procedures/claimRatio_add.sql | 9 ++++++--- db/versions/11101-limeCordyline/00-firstScript.sql | 8 ++++++++ 3 files changed, 16 insertions(+), 5 deletions(-) diff --git a/db/dump/fixtures.before.sql b/db/dump/fixtures.before.sql index 60ef58861..eb165aeec 100644 --- a/db/dump/fixtures.before.sql +++ b/db/dump/fixtures.before.sql @@ -1885,9 +1885,9 @@ INSERT INTO `vn`.`claimEnd`(`id`, `saleFk`, `claimFk`, `workerFk`, `claimDestina (1, 31, 4, 21, 2), (2, 32, 3, 21, 3); -INSERT INTO `vn`.`claimConfig`(`id`, `maxResponsibility`) +INSERT INTO `vn`.`claimConfig`(`id`, `maxResponsibility`, `monthsToRefund`, `minShipped`) VALUES - (1, 50); + (1, 5, 4, '2016-10-01'); INSERT INTO `vn`.`claimRatio`(`clientFk`, `yearSale`, `claimAmount`, `claimingRate`, `priceIncreasing`, `packingRate`) VALUES diff --git a/db/routines/vn/procedures/claimRatio_add.sql b/db/routines/vn/procedures/claimRatio_add.sql index 8d94805db..c375f8736 100644 --- a/db/routines/vn/procedures/claimRatio_add.sql +++ b/db/routines/vn/procedures/claimRatio_add.sql @@ -5,7 +5,8 @@ BEGIN * Añade a la tabla greuges todos los cargos necesario y * que luego lo utilizamos para calcular el recobro. */ - DECLARE vMonthToRefund INT DEFAULT 4; + DECLARE vMonthToRefund INT + DEFAULT (SELECT monthsToRefund FROM claimConfig); DECLARE vRecoveryGreugeType INT DEFAULT (SELECT id FROM greugeType WHERE code = 'recovery'); DECLARE vManaGreugeType INT @@ -15,7 +16,8 @@ BEGIN DECLARE vDebtComponentType INT DEFAULT (SELECT id FROM component WHERE code = 'debtCollection'); - IF vRecoveryGreugeType IS NULL + IF vMonthToRefund IS NULL + OR vRecoveryGreugeType IS NULL OR vManaGreugeType IS NULL OR vClaimGreugeType IS NULL OR vDebtComponentType IS NULL THEN @@ -87,6 +89,7 @@ BEGIN -- Recobros CREATE OR REPLACE TEMPORARY TABLE tTicketList (PRIMARY KEY (ticketFk)) + ENGINE = MEMORY SELECT DISTINCT s.ticketFk FROM saleComponent sc JOIN sale s ON sc.saleFk = s.id @@ -97,7 +100,7 @@ BEGIN JOIN alertLevel al ON al.id = st.alertLevel WHERE sc.componentFk = vDebtComponentType AND NOT sc.isGreuge - AND t.shipped >= '2016-10-01' + AND t.shipped >= (SELECT minShipped FROM claimConfig) AND t.shipped < util.VN_CURDATE() AND al.code = 'DELIVERED'; diff --git a/db/versions/11101-limeCordyline/00-firstScript.sql b/db/versions/11101-limeCordyline/00-firstScript.sql index e9ffa1b12..d6f30ce3f 100644 --- a/db/versions/11101-limeCordyline/00-firstScript.sql +++ b/db/versions/11101-limeCordyline/00-firstScript.sql @@ -2,3 +2,11 @@ UPDATE IGNORE bs.nightTask SET `schema` = 'vn', `procedure` = 'claimRatio_add' WHERE `procedure` = 'claim_ratio_routine'; + +ALTER TABLE vn.claimConfig + ADD monthsToRefund int(11) DEFAULT NULL NULL, + ADD minShipped date DEFAULT NULL NULL; + +UPDATE IGNORE vn.claimConfig + SET monthsToRefund = 4, + minShipped = '2016-10-01';