Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat: add capability for insert multiple rows in single query #228

Merged
merged 2 commits into from
Sep 22, 2022
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
3 changes: 3 additions & 0 deletions .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -13,3 +13,6 @@
node_modules
checkstyle.xml
loopback-connector-*.tgz
.nyc_output
coverage
.vscode
101 changes: 101 additions & 0 deletions lib/sql.js
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down Expand Up @@ -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');
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

i wonder if we want to throw an error in this case.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Actually, this flag will be checked at juggler level and rejected from there itself. I'll be raising that PR soon. I have added this to ensure backwards compatibility in connector code too. Let me know if you still feel we should throw error.

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

sounds good to me.

// return immediately if multiInsertSupported=false in connector
return null;
}
const fieldsArray = this.buildFieldsFromArray(model, data);
if (Array.isArray(fieldsArray) && 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.
*
Expand Down Expand Up @@ -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
Expand Down Expand Up @@ -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 (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));
}
}
return fields;
};

/**
* Build an array of fields for the replace database operation
* @param {String} model Model name
Expand Down
34 changes: 34 additions & 0 deletions test/sql.test.js
Original file line number Diff line number Diff line change
Expand Up @@ -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;
});
});