From 586f37afd2169cf8874d2ad253da187444916b3d Mon Sep 17 00:00:00 2001 From: Javier Segarra Date: Tue, 2 Apr 2024 13:28:26 +0200 Subject: [PATCH] refs #6321 perf: add arguments into procedure --- back/tests.js | 2 +- db/routines/vn/procedures/item_getLack.sql | 41 +++++-- .../ticket/back/methods/ticket/itemLack.js | 108 +++--------------- 3 files changed, 50 insertions(+), 101 deletions(-) diff --git a/back/tests.js b/back/tests.js index 824d6ca5a..cfb681435 100644 --- a/back/tests.js +++ b/back/tests.js @@ -18,7 +18,7 @@ const opts = getopts(process.argv.slice(2), { let server; const PARALLEL = false; const SETUP_TIMEOUT = 15 * 60 * 1000; -const SPEC_TIMEOUT = 30 * 10000; +const SPEC_TIMEOUT = 30 * 1000; process.on('exit', teardown); process.on('uncaughtException', onError); diff --git a/db/routines/vn/procedures/item_getLack.sql b/db/routines/vn/procedures/item_getLack.sql index e0531e2ac..17cff0246 100644 --- a/db/routines/vn/procedures/item_getLack.sql +++ b/db/routines/vn/procedures/item_getLack.sql @@ -1,9 +1,20 @@ DELIMITER $$ -CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getLack`(IN vForce BOOLEAN, IN vDays INT) +CREATE OR REPLACE DEFINER=`root`@`localhost` PROCEDURE `vn`.`item_getLack`( + vForce BOOLEAN, + vDays INT, + vId INT, + vLongname INT, + vSupplierFk VARCHAR(255), + vColor VARCHAR(255), + vSize INT, + vOrigen VARCHAR(255), + vLack INT, + vWarehouseFk INT + ) BEGIN /** * Calcula una tabla con el máximo negativo visible para cada producto y almacen - * + * * @param vForce Fuerza el recalculo del stock * @param vDays Numero de dias a considerar **/ @@ -13,33 +24,33 @@ BEGIN CALL item_getMinETD(); CALL item_zoneClosure(); - SELECT i.id itemFk, + SELECT i.id itemFk, i.longName, w.id warehouseFk, - p.`name` producer, + p.`name` producer, i.`size`, i.category, - w.name warehouse, + w.name warehouse, SUM(IFNULL(sub.amount,0)) lack, i.inkFk, IFNULL(im.timed, util.midnight()) timed, IFNULL(izc.timed, util.midnight()) minTimed, o.name originFk - FROM (SELECT item_id, - warehouse_id, + FROM (SELECT item_id, + warehouse_id, amount FROM cache.stock WHERE amount > 0 UNION ALL - SELECT itemFk, - warehouseFk, + SELECT itemFk, + warehouseFk, amount FROM tmp.itemMinacum ) sub JOIN warehouse w ON w.id = sub.warehouse_id JOIN item i ON i.id = sub.item_id - LEFT JOIN producer p ON p.id = i.producerFk - JOIN itemType it ON it.id = i.typeFk + LEFT JOIN producer p ON p.id = i.producerFk + JOIN itemType it ON it.id = i.typeFk JOIN itemCategory ic ON ic.id = it.categoryFk LEFT JOIN tmp.itemMinETD im ON im.itemFk = i.id LEFT JOIN tmp.itemZoneClosure izc ON izc.itemFk = i.id @@ -47,6 +58,14 @@ BEGIN WHERE w.isForTicket AND ic.display AND it.code != 'GEN' + AND (vId IS NULL OR i.id = vId) + AND (vLongname IS NULL OR i.longName = vLongname) + AND (vSupplierFk IS NULL OR p.`name` LIKE CONCAT('%', vSupplierFk, '%')) + AND (vColor IS NULL OR vColor = i.inkFk) + AND (vSize IS NULL OR vSize = i.`size`) + AND (vOrigen IS NULL OR vOrigen = w.name) + AND (vLack IS NULL OR vLack = sub.amount) + AND (vWarehouseFk IS NULL OR vWarehouseFk = w.id) GROUP BY i.id, w.id HAVING lack < 0; diff --git a/modules/ticket/back/methods/ticket/itemLack.js b/modules/ticket/back/methods/ticket/itemLack.js index 932d50b52..b11ae74d1 100644 --- a/modules/ticket/back/methods/ticket/itemLack.js +++ b/modules/ticket/back/methods/ticket/itemLack.js @@ -1,7 +1,3 @@ - -const ParameterizedSQL = require('loopback-connector').ParameterizedSQL; -const {buildFilter} = require('vn-loopback/util/filter'); - module.exports = Self => { Self.remoteMethod('itemLack', { description: 'Download a ticket delivery note document', @@ -34,9 +30,9 @@ module.exports = Self => { description: 'Supplier id', }, { - arg: 'color', + arg: 'colour', type: 'string', - description: 'Color\'s item', + description: 'Colour\'s item', }, { arg: 'size', @@ -48,9 +44,15 @@ module.exports = Self => { type: 'string', description: 'origen id', }, + { + arg: 'warehouse', + type: 'number', + description: 'The warehouse id', + }, { arg: 'lack', - type: 'number', description: 'The item id', + type: 'number', + description: 'The item id', } ], returns: [ @@ -70,91 +72,19 @@ module.exports = Self => { const myOptions = {}; if (typeof options == 'object') Object.assign(myOptions, options); - const conn = Self.dataSource.connector; - let where = {}; - filter = Object.assign(ctx.args ?? {}, filter); - where = buildFilter(filter, (param, value) => { - switch (param) { - case 'id': - return {'i.id': value}; - case 'longname': - return {'i.longName': value}; - case 'name': - return {'p.name': {like: `%${value}%`}}; - case 'color': - return {'i.inkFk': value}; - case 'size': - return {'i.size': value}; - case 'origen': - return {'w.id': value}; - case 'lack': - return {'sub.amount': value}; - } - }) ?? {}; + const filterKeyOrder = ['id', 'longname', 'supplier', 'colour', 'size', 'origen', 'lack', 'warehouse']; - const stmts = []; - stmts.push(`SET @_optimizer_search_depth = @@optimizer_search_depth`); - stmts.push(`SET SESSION optimizer_search_depth = 0`); + delete ctx.args.ctx; + delete ctx.args.filter; - stmts.push(`CALL cache.stock_refresh(true)`); - stmts.push(`CALL item_getMinacum(NULL, util.VN_CURDATE(), 2, NULL)`); - stmts.push(`CALL item_getMinETD()`); - stmts.push(`CALL item_zoneClosure()`); + let procedureParams = [true, 2]; + procedureParams.push(...filterKeyOrder.map(clave => ctx.args[clave] ?? null)); + const procedureArgs = Array(procedureParams.length).fill('?').join(', '); + let query = `CALL vn.item_getLack(${procedureArgs})`; - const stmt = new ParameterizedSQL(` - SELECT i.id itemFk, - i.longName, - w.id warehouseFk, - p.name producer, - p.id producerFk, - i.size, - i.category, - w.name warehouse, - SUM(IFNULL(sub.amount,0)) lack, - i.inkFk, - IFNULL(im.timed, util.midnight()) timed, - IFNULL(izc.timed, util.midnight()) minTimed - FROM (SELECT item_id, - warehouse_id, - amount - FROM cache.stock - WHERE amount > 0 - UNION ALL - SELECT itemFk, - warehouseFk, - amount - FROM tmp.itemMinacum - ) sub - JOIN warehouse w ON w.id = sub.warehouse_id - JOIN item i ON i.id = sub.item_id - LEFT JOIN producer p ON p.id = i.producerFk - JOIN itemType it ON it.id = i.typeFk - JOIN itemCategory ic ON ic.id = it.categoryFk - LEFT JOIN tmp.itemMinETD im ON im.itemFk = i.id - LEFT JOIN tmp.itemZoneClosure izc ON izc.itemFk = i.id - `); + const result = await Self.rawSql(query, procedureParams, myOptions); - const sqlWhere = conn.makeWhere(where); - stmt.merge(sqlWhere); - const prefix = Object.keys(where).length > 0 ? 'AND' : 'WHERE'; - stmt.merge(`${prefix} w.isForTicket - AND ic.display - AND it.code != 'GEN'`); - - stmt.merge(` - GROUP BY i.id, w.id - HAVING lack < 0` - ); - stmt.merge(conn.makeSuffix(filter)); - const itemsIndex = stmts.push(stmt) - 1; - stmts.push( - `DROP TEMPORARY TABLE - tmp.itemMinacum, - tmp.itemMinETD, - tmp.itemZoneClosure`); - - const sql = ParameterizedSQL.join(stmts, ';'); - const result = await conn.executeStmt(sql, myOptions); - return itemsIndex === 0 ? result : result[itemsIndex]; + const itemsIndex = 0; + return result[itemsIndex]; }; };