Add support for WHERE clauses to "upsert" queries (#4148)

This commit is contained in:
Mark Boyd 2020-12-09 10:51:29 -05:00 committed by GitHub
parent 07ae5c0725
commit 76c131e2a9
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
5 changed files with 170 additions and 2 deletions

View File

@ -26,7 +26,13 @@ class QueryCompiler_MySQL extends QueryCompiler {
const { ignore, merge, insert } = this.single;
if (ignore) sql = sql.replace('insert into', 'insert ignore into');
if (merge) sql += this._merge(merge.updates, insert);
if (merge) {
sql += this._merge(merge.updates, insert);
const wheres = this.where();
if (wheres) {
throw new Error('.onConflict().merge().where() is not supported for mysql');
}
}
return sql;
}

View File

@ -26,8 +26,11 @@ class QueryCompiler_PG extends QueryCompiler {
const { returning, onConflict, ignore, merge, insert } = this.single;
if (onConflict && ignore) sql += this._ignore(onConflict);
if (onConflict && merge)
if (onConflict && merge) {
sql += this._merge(merge.updates, onConflict, insert);
const wheres = this.where();
if (wheres) sql += ` ${wheres}`;
}
if (returning) sql += this._returning(returning);
return {

View File

@ -87,6 +87,8 @@ class QueryCompiler_SQLite3 extends QueryCompiler {
if (onConflict && ignore) sql += this._ignore(onConflict);
else if (onConflict && merge) {
sql += this._merge(merge.updates, onConflict, insertValues);
const wheres = this.where();
if (wheres) sql += ` ${wheres}`;
}
return sql;

View File

@ -1465,6 +1465,130 @@ module.exports = function (knex) {
expect(rows[0].name).to.equal('AFTER');
});
it('conditionally updates rows when inserting a duplicate key to unique column and merge with where clause matching row(s) is specified', async function () {
if (/redshift/i.test(knex.client.driverName)) {
return this.skip();
}
// Setup: Create table with unique email column
await knex.schema.dropTableIfExists('upsert_tests');
await knex.schema.createTable('upsert_tests', (table) => {
table.string('name');
table.string('email');
table.string('role');
table.unique('email');
});
// Setup: Create row to conflict against
await knex('upsert_tests').insert({
email: 'mergetest@example.com',
role: 'tester',
name: 'BEFORE',
});
// Perform insert..merge (upsert)
try {
await knex('upsert_tests')
.insert({ email: 'mergetest@example.com', name: 'AFTER' }, 'email')
.onConflict('email')
.merge()
.where('upsert_tests.role', 'tester')
.testSql(function (tester) {
tester(
'pg',
'insert into "upsert_tests" ("email", "name") values (?, ?) on conflict ("email") do update set "email" = excluded."email", "name" = excluded."name" where "upsert_tests"."role" = ? returning "email"',
['mergetest@example.com', 'AFTER', 'tester']
);
tester(
'sqlite3',
'insert into `upsert_tests` (`email`, `name`) values (?, ?) on conflict (`email`) do update set `email` = excluded.`email`, `name` = excluded.`name` where `upsert_tests`.`role` = ?',
['mergetest@example.com', 'AFTER', 'tester']
);
});
} catch (err) {
if (/oracle|mssql/i.test(knex.client.driverName)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
}
if (/mysql|mysql2/i.test(knex.client.driverName)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict().merge().where() is not supported for'))
return;
}
throw err;
}
// Check that row HAS been updated
const rows = await knex('upsert_tests')
.where({ email: 'mergetest@example.com' })
.select();
expect(rows.length).to.equal(1);
expect(rows[0].name).to.equal('AFTER');
});
it('will silently do nothing when inserting a duplicate key to unique column and merge with where clause matching no rows is specified', async function () {
if (/redshift/i.test(knex.client.driverName)) {
return this.skip();
}
// Setup: Create table with unique email column
await knex.schema.dropTableIfExists('upsert_tests');
await knex.schema.createTable('upsert_tests', (table) => {
table.string('name');
table.string('email');
table.string('role');
table.unique('email');
});
// Setup: Create row to conflict against
await knex('upsert_tests').insert({
email: 'mergetest@example.com',
role: 'tester',
name: 'BEFORE',
});
// Perform insert..merge (upsert)
try {
await knex('upsert_tests')
.insert({ email: 'mergetest@example.com', name: 'AFTER' }, 'email')
.onConflict('email')
.merge()
.where('upsert_tests.role', 'fake-role')
.testSql(function (tester) {
tester(
'pg',
'insert into "upsert_tests" ("email", "name") values (?, ?) on conflict ("email") do update set "email" = excluded."email", "name" = excluded."name" where "upsert_tests"."role" = ? returning "email"',
['mergetest@example.com', 'AFTER', 'fake-role']
);
tester(
'sqlite3',
'insert into `upsert_tests` (`email`, `name`) values (?, ?) on conflict (`email`) do update set `email` = excluded.`email`, `name` = excluded.`name` where `upsert_tests`.`role` = ?',
['mergetest@example.com', 'AFTER', 'fake-role']
);
});
} catch (err) {
if (/oracle|mssql/i.test(knex.client.driverName)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
}
if (/mysql|mysql2/i.test(knex.client.driverName)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict().merge().where() is not supported for'))
return;
}
throw err;
}
// Check that row HAS NOT been updated
const rows = await knex('upsert_tests')
.where({ email: 'mergetest@example.com' })
.select();
expect(rows.length).to.equal(1);
expect(rows[0].name).to.equal('BEFORE');
});
it('updates columns with raw value when inserting a duplicate key to unique column and merge is specified', async function () {
if (/redshift/i.test(knex.client.driverName)) {
return this.skip();

View File

@ -6348,6 +6348,39 @@ describe('QueryBuilder', () => {
);
});
it('insert merge with where clause', () => {
testsql(
qb()
.from('users')
.insert({ email: 'foo', name: 'taylor' })
.onConflict('email')
.merge()
.where('email', 'foo2'),
{
pg: {
sql:
'insert into "users" ("email", "name") values (?, ?) on conflict ("email") do update set "email" = excluded."email", "name" = excluded."name" where "email" = ?',
bindings: ['foo', 'taylor', 'foo2'],
},
sqlite3: {
sql:
'insert into `users` (`email`, `name`) values (?, ?) on conflict (`email`) do update set `email` = excluded.`email`, `name` = excluded.`name` where `email` = ?',
bindings: ['foo', 'taylor', 'foo2'],
},
}
);
expect(() => {
clients.mysql
.queryBuilder()
.insert({ email: 'foo', name: 'taylor' })
.onConflict('email')
.merge()
.where('email', 'foo2')
.toString();
}).to.throw('onConflict().merge().where() is not supported for mysql');
});
it('Calling decrement and then increment will overwrite the previous value', () => {
testsql(
qb()