From ac76b135b3ce61c4e2a3f3afa4ef34b583d29521 Mon Sep 17 00:00:00 2001 From: Samarpan Bhattacharya Date: Sun, 10 Jul 2022 18:13:24 +0530 Subject: [PATCH 1/2] feat: add capability for insert multiple rows in single query Signed-off-by: Samarpan Bhattacharya --- .gitignore | 3 ++ lib/sql.js | 101 +++++++++++++++++++++++++++++++++++++++++++++++ test/sql.test.js | 34 ++++++++++++++++ 3 files changed, 138 insertions(+) diff --git a/.gitignore b/.gitignore index 2db30da6..c734d2b6 100644 --- a/.gitignore +++ b/.gitignore @@ -13,3 +13,6 @@ node_modules checkstyle.xml loopback-connector-*.tgz +.nyc_output +coverage +.vscode \ No newline at end of file diff --git a/lib/sql.js b/lib/sql.js index 4d97a2fa..ba3c3af7 100644 --- a/lib/sql.js +++ b/lib/sql.js @@ -46,6 +46,14 @@ SQLConnector.Transaction = Transaction; */ SQLConnector.prototype.relational = true; +/** + * Set the multiInsertSupported property to indicate if multiple value insert SQL dialect is supported or not + * This can be overridden by derived connectors to allow `insert multiple values` dialect for createAll + * By default, it is set to false for backward compatibility + * @type {boolean} + */ +SQLConnector.prototype.multiInsertSupported = false; + /** * Invoke a prototype method on the super class * @param {String} methodName Method name @@ -540,6 +548,53 @@ SQLConnector.prototype.buildInsert = function(model, data, options) { return this.parameterize(insertStmt); }; +/** + * Build INSERT SQL statement for multiple values + * @param {String} model The model name + * @param {Object} data The array of model data object + * @param {Object} options The options object + * @returns {Object} The ParameterizedSQL Object with INSERT SQL statement + */ +SQLConnector.prototype.buildInsertAll = function(model, data, options) { + if (!this.multiInsertSupported) { + debug('multiple value insert SQL dialect is not supported by this connector'); + // return immediately if multiInsertSupported=false in connector + return null; + } + const fieldsArray = this.buildFieldsFromArray(model, data); + if (fieldsArray.length === 0) { + debug('no fields found for insert query'); + // return immediately if no fields found + return null; + } + const insertStmt = this.buildInsertInto(model, fieldsArray[0], options); + + for (let i = 0; i < fieldsArray.length; i++) { + const columnValues = fieldsArray[i].columnValues; + const isLast = (i === (fieldsArray.length - 1)); + const isFirst = (i === 0); + + if (columnValues.length) { + const values = ParameterizedSQL.join(columnValues, ','); + // Multi value query. + // This lets multiple row insertion in single query + values.sql = (isFirst ? 'VALUES ' : '') + + '(' + values.sql + ')' + + (isLast ? '' : ','); + insertStmt.merge(values); + } else { + // Insert default values if no values provided + insertStmt.merge(this.buildInsertDefaultValues(model, data, options)); + } + } + + const returning = this.buildInsertReturning(model, data, options); + if (returning) { + insertStmt.merge(returning); + } + return this.parameterize(insertStmt); +}; + /** * Execute a SQL statement with given parameters. * @@ -630,6 +685,34 @@ SQLConnector.prototype.create = function(model, data, options, callback) { }); }; +/** + * Create multiple data models in a single insert query + * Works only if `multiInsertSupported` is set to true for the connector + * + * @param {String} model The model name + * @param {Object} data The model instances data + * @param {Object} options Options object + * @param {Function} [callback] The callback function + */ +SQLConnector.prototype.createAll = function(model, data, options, callback) { + const self = this; + const stmt = this.buildInsertAll(model, data, options); + if (!stmt) { + debug('empty SQL statement returned for insert into multiple values'); + callback(new Error( + g.f('empty SQL statement returned for insert into multiple values'), + )); + } + this.execute(stmt.sql, stmt.params, options, function(err, info) { + if (err) { + callback(err); + } else { + const insertedId = self.getInsertedId(model, info); + callback(err, insertedId); + } + }); +}; + /** * Save the model instance into the database * @param {String} model The model name @@ -1177,6 +1260,24 @@ SQLConnector.prototype.buildFields = function(model, data, excludeIds) { return this._buildFieldsForKeys(model, data, keys, excludeIds); }; +/** + * Build an array of fields for the database operation from data array + * @param {String} model Model name + * @param {Object} data Array of Model data object + * @param {Boolean} excludeIds Exclude id properties or not, default to false + * @returns {[{names: Array, values: Array, properties: Array}]} + */ +SQLConnector.prototype.buildFieldsFromArray = function(model, data, excludeIds) { + const fields = []; + if (data.length > 0) { + const keys = Object.keys(data[0]); + for (let i = 0; i < data.length; i++) { + fields.push(this._buildFieldsForKeys(model, data[i], keys, excludeIds)); + } + } + return fields; +}; + /** * Build an array of fields for the replace database operation * @param {String} model Model name diff --git a/test/sql.test.js b/test/sql.test.js index 87ea4388..405801b0 100644 --- a/test/sql.test.js +++ b/test/sql.test.js @@ -514,4 +514,38 @@ describe('sql connector', function() { expect(function() { runExecute(); }).to.not.throw(); ds.connected = true; }); + + it('should build INSERT for multiple rows if multiInsertSupported is true', function() { + connector.multiInsertSupported = true; + const sql = connector.buildInsertAll('customer', [ + {name: 'Adam', middleName: 'abc', vip: true}, + {name: 'Test', middleName: null, vip: false}, + ]); + expect(sql.toJSON()).to.eql({ + sql: + 'INSERT INTO `CUSTOMER`(`NAME`,`middle_name`,`VIP`) VALUES ($1,$2,$3), ($4,$5,$6)', + params: ['Adam', 'abc', true, 'Test', null, false], + }); + }); + + it('should return null for INSERT multiple rows if multiInsertSupported is false', + function() { + connector.multiInsertSupported = false; + const sql = connector.buildInsertAll('customer', [ + {name: 'Adam', middleName: 'abc', vip: true}, + {name: 'Test', middleName: null, vip: false}, + ]); + // eslint-disable-next-line no-unused-expressions + expect(sql).to.be.null; + }); + + it('should return null for INSERT multiple rows if multiInsertSupported not set', + function() { + const sql = connector.buildInsertAll('customer', [ + {name: 'Adam', middleName: 'abc', vip: true}, + {name: 'Test', middleName: null, vip: false}, + ]); + // eslint-disable-next-line no-unused-expressions + expect(sql).to.be.null; + }); }); From 4edc6aed9af62eb5886bdfb84fdd39e196ade75a Mon Sep 17 00:00:00 2001 From: Samarpan Bhattacharya Date: Wed, 7 Sep 2022 14:42:31 +0900 Subject: [PATCH 2/2] fix: rebiew comments Signed-off-by: Samarpan Bhattacharya --- lib/sql.js | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/lib/sql.js b/lib/sql.js index ba3c3af7..4f07a6bc 100644 --- a/lib/sql.js +++ b/lib/sql.js @@ -562,7 +562,7 @@ SQLConnector.prototype.buildInsertAll = function(model, data, options) { return null; } const fieldsArray = this.buildFieldsFromArray(model, data); - if (fieldsArray.length === 0) { + if (Array.isArray(fieldsArray) && fieldsArray.length === 0) { debug('no fields found for insert query'); // return immediately if no fields found return null; @@ -1269,7 +1269,7 @@ SQLConnector.prototype.buildFields = function(model, data, excludeIds) { */ SQLConnector.prototype.buildFieldsFromArray = function(model, data, excludeIds) { const fields = []; - if (data.length > 0) { + if (Array.isArray(data) && data.length > 0) { const keys = Object.keys(data[0]); for (let i = 0; i < data.length; i++) { fields.push(this._buildFieldsForKeys(model, data[i], keys, excludeIds));