From 974228eedd3c99b28ac3bd1cfe4ae24304c6b3b8 Mon Sep 17 00:00:00 2001 From: guillermo Date: Thu, 8 Feb 2024 11:37:15 +0100 Subject: [PATCH 1/6] refactor: refs #5586 Optimized SQL negativeBases --- db/routines/vn/procedures/ticket_getTax.sql | 59 +++++++++---------- .../back/methods/invoiceOut/negativeBases.js | 55 ++++++++--------- 2 files changed, 54 insertions(+), 60 deletions(-) diff --git a/db/routines/vn/procedures/ticket_getTax.sql b/db/routines/vn/procedures/ticket_getTax.sql index 7269a1caf..fbdbdc785 100644 --- a/db/routines/vn/procedures/ticket_getTax.sql +++ b/db/routines/vn/procedures/ticket_getTax.sql @@ -9,32 +9,31 @@ BEGIN * @return tmp.ticketAmount (ticketFk, taxableBase, tax, code) * @return tmp.ticketTax (ticketFk, pgcFk, taxableBase, rate, code) Impuesto desglosado para cada ticket. */ - DROP TEMPORARY TABLE IF EXISTS tmp.addressCompany; - CREATE TEMPORARY TABLE tmp.addressCompany + CREATE OR REPLACE TEMPORARY TABLE tmp.addressCompany (INDEX (addressFk, companyFk)) ENGINE = MEMORY SELECT DISTINCT t.addressFk, t.companyFk FROM tmp.ticket tmpTicket JOIN ticket t ON t.id = tmpTicket.ticketFk; - CALL addressTaxArea (); + CALL addressTaxArea(); IF vTaxArea IS NOT NULL THEN UPDATE tmp.addressTaxArea SET areaFk = vTaxArea; END IF; - /* Solo se calcula la base imponible (taxableBase) y el impuesto se calculará posteriormente - * No se debería cambiar el sistema por problemas con los decimales - */ - DROP TEMPORARY TABLE IF EXISTS tmp.ticketTax; - CREATE TEMPORARY TABLE tmp.ticketTax + -- Solo se calcula la base imponible (taxableBase) y + -- el impuesto se calculará posteriormente + -- No se debería cambiar el sistema por problemas con los decimales + + CREATE OR REPLACE TEMPORARY TABLE tmp.ticketTax (PRIMARY KEY (ticketFk, code, rate)) ENGINE = MEMORY SELECT * FROM ( SELECT tmpTicket.ticketFk, bp.pgcFk, - SUM(s.quantity * s.price * (100 - s.discount)/100 ) taxableBase, + SUM(s.quantity * s.price * (100 - s.discount) / 100 ) taxableBase, pgc.rate, tc.code, bp.priority @@ -43,22 +42,21 @@ BEGIN JOIN item i ON i.id = s.itemFk JOIN ticket t ON t.id = tmpTicket.ticketFk JOIN supplier su ON su.id = t.companyFk - JOIN tmp.addressTaxArea ata - ON ata.addressFk = t.addressFk AND ata.companyFk = t.companyFk - JOIN itemTaxCountry itc - ON itc.itemFk = i.id AND itc.countryFk = su.countryFk - JOIN bookingPlanner bp - ON bp.countryFk = su.countryFk - AND bp.taxAreaFk = ata.areaFk - AND bp.taxClassFk = itc.taxClassFk + JOIN tmp.addressTaxArea ata ON ata.addressFk = t.addressFk + AND ata.companyFk = t.companyFk + JOIN itemTaxCountry itc ON itc.itemFk = i.id + AND itc.countryFk = su.countryFk + JOIN bookingPlanner bp ON bp.countryFk = su.countryFk + AND bp.taxAreaFk = ata.areaFk + AND bp.taxClassFk = itc.taxClassFk JOIN pgc ON pgc.code = bp.pgcFk JOIN taxClass tc ON tc.id = bp.taxClassFk GROUP BY tmpTicket.ticketFk, pgc.code, pgc.rate - HAVING taxableBase <> 0) t3 + HAVING taxableBase + ) t3 ORDER BY priority; - DROP TEMPORARY TABLE IF EXISTS tmp.ticketServiceTax; - CREATE TEMPORARY TABLE tmp.ticketServiceTax + CREATE OR REPLACE TEMPORARY TABLE tmp.ticketServiceTax (PRIMARY KEY (ticketFk, code, rate)) ENGINE = MEMORY SELECT tt.ticketFk, @@ -70,24 +68,22 @@ BEGIN JOIN ticketService ts ON ts.ticketFk = tt.ticketFk JOIN ticket t ON t.id = tt.ticketFk JOIN supplier su ON su.id = t.companyFk - JOIN tmp.addressTaxArea ata - ON ata.addressFk = t.addressFk AND ata.companyFk = t.companyFk - JOIN bookingPlanner bp - ON bp.countryFk = su.countryFk - AND bp.taxAreaFk = ata.areaFk - AND bp.taxClassFk = ts.taxClassFk + JOIN tmp.addressTaxArea ata ON ata.addressFk = t.addressFk + AND ata.companyFk = t.companyFk + JOIN bookingPlanner bp ON bp.countryFk = su.countryFk + AND bp.taxAreaFk = ata.areaFk + AND bp.taxClassFk = ts.taxClassFk JOIN pgc ON pgc.code = bp.pgcFk JOIN taxClass tc ON tc.id = bp.taxClassFk GROUP BY tt.ticketFk, pgc.code - HAVING taxableBase <> 0; + HAVING taxableBase; INSERT INTO tmp.ticketTax (ticketFk, pgcFk, taxableBase, rate, code) SELECT ts.ticketFk, ts.pgcFk, ts.taxableBase, ts.rate, ts.code FROM tmp.ticketServiceTax ts ON DUPLICATE KEY UPDATE ticketTax.taxableBase = VALUES (taxableBase) + ticketTax.taxableBase ; - DROP TEMPORARY TABLE IF EXISTS tmp.ticketAmount; - CREATE TEMPORARY TABLE tmp.ticketAmount + CREATE OR REPLACE TEMPORARY TABLE tmp.ticketAmount (INDEX (ticketFk)) ENGINE = MEMORY SELECT ticketFk, @@ -97,7 +93,8 @@ BEGIN FROM tmp.ticketTax GROUP BY ticketFk, code; - DROP TEMPORARY TABLE tmp.addressCompany; - DROP TEMPORARY TABLE tmp.addressTaxArea; + DROP TEMPORARY TABLE + tmp.addressCompany, + tmp.addressTaxArea; END$$ DELIMITER ; diff --git a/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js b/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js index 96c789316..0b152441b 100644 --- a/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js +++ b/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js @@ -46,23 +46,19 @@ module.exports = Self => { const stmts = []; let stmt; - stmts.push(`DROP TEMPORARY TABLE IF EXISTS tmp.ticket`); - stmts.push(new ParameterizedSQL( - `CREATE TEMPORARY TABLE tmp.ticket + `CREATE OR REPLACE TEMPORARY TABLE tmp.ticket (KEY (ticketFk)) ENGINE = MEMORY SELECT id ticketFk FROM ticket t - WHERE shipped BETWEEN ? AND ? + WHERE shipped BETWEEN ? AND util.dayEnd(?) AND refFk IS NULL`, [args.from, args.to])); stmts.push(`CALL vn.ticket_getTax(NULL)`); - stmts.push(`DROP TEMPORARY TABLE IF EXISTS tmp.filter`); stmts.push(new ParameterizedSQL( - `CREATE TEMPORARY TABLE tmp.filter + `CREATE OR REPLACE TEMPORARY TABLE tmp.filter ENGINE = MEMORY - SELECT - co.code company, + SELECT co.code company, cou.country, c.id clientId, c.socialName clientSocialName, @@ -74,27 +70,25 @@ module.exports = Self => { c.isTaxDataChecked, w.id comercialId, CONCAT(w.firstName, ' ', w.lastName) comercialName - FROM vn.ticket t - JOIN vn.company co ON co.id = t.companyFk - JOIN vn.sale s ON s.ticketFk = t.id - JOIN vn.client c ON c.id = t.clientFk - JOIN vn.country cou ON cou.id = c.countryFk - LEFT JOIN vn.worker w ON w.id = c.salesPersonFk - LEFT JOIN ( - SELECT ticketFk, taxableBase - FROM tmp.ticketAmount - GROUP BY ticketFk - HAVING taxableBase < 0 - ) negativeBase ON negativeBase.ticketFk = t.id - WHERE t.shipped BETWEEN ? AND ? - AND t.refFk IS NULL - AND c.typeFk IN ('normal','trust') - GROUP BY t.clientFk, negativeBase.taxableBase - HAVING amount < 0`, [args.from, args.to])); + FROM vn.ticket t + JOIN vn.company co ON co.id = t.companyFk + JOIN vn.sale s ON s.ticketFk = t.id + JOIN vn.client c ON c.id = t.clientFk + JOIN vn.country cou ON cou.id = c.countryFk + LEFT JOIN vn.worker w ON w.id = c.salesPersonFk + LEFT JOIN ( + SELECT ticketFk, taxableBase + FROM tmp.ticketAmount + GROUP BY ticketFk + HAVING taxableBase < 0 + ) negativeBase ON negativeBase.ticketFk = t.id + WHERE t.shipped BETWEEN ? AND util.dayEnd(?) + AND t.refFk IS NULL + AND c.typeFk IN ('normal','trust') + GROUP BY t.clientFk, negativeBase.taxableBase + HAVING amount < 0`, [args.from, args.to])); - stmt = new ParameterizedSQL(` - SELECT f.* - FROM tmp.filter f`); + stmt = new ParameterizedSQL(`SELECT * FROM tmp.filter`); if (args.filter) { stmt.merge(conn.makeWhere(args.filter.where)); @@ -104,7 +98,10 @@ module.exports = Self => { const negativeBasesIndex = stmts.push(stmt) - 1; - stmts.push(`DROP TEMPORARY TABLE tmp.filter, tmp.ticket, tmp.ticketTax, tmp.ticketAmount`); + stmts.push(`DROP TEMPORARY TABLE tmp.filter, + tmp.ticket, + tmp.ticketTax, + tmp.ticketAmount`); const sql = ParameterizedSQL.join(stmts, ';'); const result = await conn.executeStmt(sql); From bdc6192a7c39784d2c52fce27068c2bda83fba1a Mon Sep 17 00:00:00 2001 From: guillermo Date: Tue, 13 Feb 2024 12:50:39 +0100 Subject: [PATCH 2/6] refactor: refs #5586 Optimized SQL negativeBases --- .../back/methods/invoiceOut/negativeBases.js | 28 ++++--------------- 1 file changed, 5 insertions(+), 23 deletions(-) diff --git a/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js b/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js index c40373963..193397b53 100644 --- a/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js +++ b/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js @@ -46,15 +46,6 @@ module.exports = Self => { const stmts = []; let stmt; - stmts.push(new ParameterizedSQL( - `CREATE OR REPLACE TEMPORARY TABLE tmp.ticket - (KEY (ticketFk)) - ENGINE = MEMORY - SELECT id ticketFk - FROM ticket t - WHERE shipped BETWEEN ? AND util.dayEnd(?) - AND refFk IS NULL`, [args.from, args.to])); - stmts.push(`CALL vn.ticket_getTax(NULL)`); stmts.push(new ParameterizedSQL( `CREATE OR REPLACE TEMPORARY TABLE tmp.filter ENGINE = MEMORY @@ -64,8 +55,8 @@ module.exports = Self => { c.socialName clientSocialName, u.nickname workerSocialName, SUM(s.quantity * s.price * ( 100 - s.discount ) / 100) amount, - negativeBase.taxableBase, - negativeBase.ticketFk, + t.totalWithoutVat taxableBase, + s.ticketFk, c.isActive, c.hasToInvoice, c.isTaxDataChecked, @@ -78,16 +69,10 @@ module.exports = Self => { JOIN vn.country cou ON cou.id = c.countryFk LEFT JOIN vn.worker w ON w.id = c.salesPersonFk JOIN account.user u ON u.id = w.id - LEFT JOIN ( - SELECT ticketFk, taxableBase - FROM tmp.ticketAmount - GROUP BY ticketFk - HAVING taxableBase < 0 - ) negativeBase ON negativeBase.ticketFk = t.id - WHERE t.shipped BETWEEN ? AND ? + WHERE t.shipped BETWEEN ? AND util.dayEnd(?) AND t.refFk IS NULL AND c.typeFk IN ('normal','trust') - GROUP BY t.clientFk, negativeBase.taxableBase + GROUP BY t.clientFk, t.totalWithoutVat HAVING amount < 0`, [args.from, args.to])); stmt = new ParameterizedSQL(`SELECT * FROM tmp.filter`); @@ -100,10 +85,7 @@ module.exports = Self => { const negativeBasesIndex = stmts.push(stmt) - 1; - stmts.push(`DROP TEMPORARY TABLE tmp.filter, - tmp.ticket, - tmp.ticketTax, - tmp.ticketAmount`); + stmts.push(`DROP TEMPORARY TABLE tmp.filter`); const sql = ParameterizedSQL.join(stmts, ';'); const result = await conn.executeStmt(sql); From 92261ebe0d36732315fe48d1d745415834e41819 Mon Sep 17 00:00:00 2001 From: guillermo Date: Tue, 13 Feb 2024 13:09:12 +0100 Subject: [PATCH 3/6] fix: refs #5586 Tests fix --- db/routines/vn/procedures/ticket_getTax.sql | 5 ++++- 1 file changed, 4 insertions(+), 1 deletion(-) diff --git a/db/routines/vn/procedures/ticket_getTax.sql b/db/routines/vn/procedures/ticket_getTax.sql index fbdbdc785..b9f5c14e3 100644 --- a/db/routines/vn/procedures/ticket_getTax.sql +++ b/db/routines/vn/procedures/ticket_getTax.sql @@ -9,7 +9,10 @@ BEGIN * @return tmp.ticketAmount (ticketFk, taxableBase, tax, code) * @return tmp.ticketTax (ticketFk, pgcFk, taxableBase, rate, code) Impuesto desglosado para cada ticket. */ - CREATE OR REPLACE TEMPORARY TABLE tmp.addressCompany + -- Mantengo el drop porque si no da error en los tests de back de salix + -- Table 'addressCompany' was locked with a READ lock and can't be updated' + DROP TEMPORARY TABLE IF EXISTS tmp.addressCompany; + CREATE TEMPORARY TABLE tmp.addressCompany (INDEX (addressFk, companyFk)) ENGINE = MEMORY SELECT DISTINCT t.addressFk, t.companyFk From 05b7c37b94c6c51ecb1fb0c9754de2950f1f1c0b Mon Sep 17 00:00:00 2001 From: guillermo Date: Thu, 15 Feb 2024 07:49:17 +0100 Subject: [PATCH 4/6] fix: refs #5586 Rollback --- .../back/methods/invoiceOut/negativeBases.js | 21 ++++++++++++++++--- 1 file changed, 18 insertions(+), 3 deletions(-) diff --git a/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js b/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js index 193397b53..9242ffb8b 100644 --- a/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js +++ b/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js @@ -46,6 +46,15 @@ module.exports = Self => { const stmts = []; let stmt; + stmts.push(new ParameterizedSQL( + `CREATE OR REPLACE TEMPORARY TABLE tmp.ticket + (KEY (ticketFk)) + ENGINE = MEMORY + SELECT id ticketFk + FROM ticket t + WHERE shipped BETWEEN ? AND ? + AND refFk IS NULL`, [args.from, args.to])); + stmts.push(`CALL vn.ticket_getTax(NULL)`); stmts.push(new ParameterizedSQL( `CREATE OR REPLACE TEMPORARY TABLE tmp.filter ENGINE = MEMORY @@ -55,8 +64,8 @@ module.exports = Self => { c.socialName clientSocialName, u.nickname workerSocialName, SUM(s.quantity * s.price * ( 100 - s.discount ) / 100) amount, - t.totalWithoutVat taxableBase, - s.ticketFk, + negativeBase.taxableBase, + negativeBase.ticketFk, c.isActive, c.hasToInvoice, c.isTaxDataChecked, @@ -69,6 +78,12 @@ module.exports = Self => { JOIN vn.country cou ON cou.id = c.countryFk LEFT JOIN vn.worker w ON w.id = c.salesPersonFk JOIN account.user u ON u.id = w.id + LEFT JOIN ( + SELECT ticketFk, taxableBase + FROM tmp.ticketAmount + GROUP BY ticketFk + HAVING taxableBase < 0 + ) negativeBase ON negativeBase.ticketFk = t.id WHERE t.shipped BETWEEN ? AND util.dayEnd(?) AND t.refFk IS NULL AND c.typeFk IN ('normal','trust') @@ -85,7 +100,7 @@ module.exports = Self => { const negativeBasesIndex = stmts.push(stmt) - 1; - stmts.push(`DROP TEMPORARY TABLE tmp.filter`); + stmts.push(`DROP TEMPORARY TABLE tmp.filter, tmp.ticket, tmp.ticketTax, tmp.ticketAmount`); const sql = ParameterizedSQL.join(stmts, ';'); const result = await conn.executeStmt(sql); From 10bfb7a7d789ecaeb241f03ad5a9cf23ac005da0 Mon Sep 17 00:00:00 2001 From: guillermo Date: Thu, 15 Feb 2024 07:52:33 +0100 Subject: [PATCH 5/6] fix: refs #5586 Minor change --- modules/invoiceOut/back/methods/invoiceOut/negativeBases.js | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js b/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js index 9242ffb8b..993ac2c0e 100644 --- a/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js +++ b/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js @@ -52,7 +52,7 @@ module.exports = Self => { ENGINE = MEMORY SELECT id ticketFk FROM ticket t - WHERE shipped BETWEEN ? AND ? + WHERE shipped BETWEEN ? AND util.dayEnd(?) AND refFk IS NULL`, [args.from, args.to])); stmts.push(`CALL vn.ticket_getTax(NULL)`); stmts.push(new ParameterizedSQL( From 5a0ce700b3310f429ee5e8c84a3e5251ab5590aa Mon Sep 17 00:00:00 2001 From: guillermo Date: Thu, 15 Feb 2024 09:38:34 +0100 Subject: [PATCH 6/6] fix: refs #5586 Requested changes --- modules/invoiceOut/back/methods/invoiceOut/negativeBases.js | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js b/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js index 993ac2c0e..66440616c 100644 --- a/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js +++ b/modules/invoiceOut/back/methods/invoiceOut/negativeBases.js @@ -87,7 +87,7 @@ module.exports = Self => { WHERE t.shipped BETWEEN ? AND util.dayEnd(?) AND t.refFk IS NULL AND c.typeFk IN ('normal','trust') - GROUP BY t.clientFk, t.totalWithoutVat + GROUP BY t.clientFk, negativeBase.taxableBase HAVING amount < 0`, [args.from, args.to])); stmt = new ParameterizedSQL(`SELECT * FROM tmp.filter`);