Skip to content

Commit

Permalink
Add raw support in onConflict clause (#4960)
Browse files Browse the repository at this point in the history
  • Loading branch information
OlivierCavadenti committed Jan 22, 2022
1 parent 6398098 commit 6ee3f94
Show file tree
Hide file tree
Showing 6 changed files with 132 additions and 8 deletions.
6 changes: 2 additions & 4 deletions lib/dialects/postgres/query/pg-querycompiler.js
Original file line number Diff line number Diff line change
Expand Up @@ -145,13 +145,11 @@ class QueryCompiler_PG extends QueryCompiler {
if (columns === true) {
return ' on conflict do nothing';
}
return ` on conflict (${this.formatter.columnize(columns)}) do nothing`;
return ` on conflict ${this._onConflictClause(columns)} do nothing`;
}

_merge(updates, columns, insert) {
let sql = ` on conflict (${this.formatter.columnize(
columns
)}) do update set `;
let sql = ` on conflict ${this._onConflictClause(columns)} do update set `;
if (updates && Array.isArray(updates)) {
sql += updates
.map((column) =>
Expand Down
6 changes: 2 additions & 4 deletions lib/dialects/sqlite3/query/sqlite-querycompiler.js
Original file line number Diff line number Diff line change
Expand Up @@ -153,13 +153,11 @@ class QueryCompiler_SQLite3 extends QueryCompiler {
if (columns === true) {
return ' on conflict do nothing';
}
return ` on conflict (${this.formatter.columnize(columns)}) do nothing`;
return ` on conflict ${this._onConflictClause(columns)} do nothing`;
}

_merge(updates, columns, insert) {
let sql = ` on conflict (${this.formatter.columnize(
columns
)}) do update set `;
let sql = ` on conflict ${this._onConflictClause(columns)} do update set `;
if (updates && Array.isArray(updates)) {
sql += updates
.map((column) =>
Expand Down
6 changes: 6 additions & 0 deletions lib/query/querycompiler.js
Original file line number Diff line number Diff line change
Expand Up @@ -149,6 +149,12 @@ class QueryCompiler {
return body === '' ? '' : sql + body;
}

_onConflictClause(columns) {
return columns instanceof Raw
? this.formatter.wrap(columns)
: `(${this.formatter.columnize(columns)})`;
}

_buildInsertValues(insertData) {
let sql = '';
let i = -1;
Expand Down
94 changes: 94 additions & 0 deletions test/integration2/query/insert/inserts.spec.js
Original file line number Diff line number Diff line change
Expand Up @@ -1996,6 +1996,100 @@ describe('Inserts', function () {
expect(row3 && row3.name).to.equal('AFTER');
});

it('update values on conflit with "where" condition and partial unique index #4590', async function () {
if (!isPostgreSQL(knex) && !isSQLite(knex)) {
return this.skip();
}

await knex.schema.dropTableIfExists('upsert_tests');
await knex.schema.createTable('upsert_tests', (table) => {
table.string('name');
table.string('type');
table.string('email');
});
await knex.raw(
'create unique index email_type1 ' +
'on upsert_tests(email) ' +
"where type = 'type1'"
);

await knex('upsert_tests').insert([
{ email: 'one@example.com', name: 'BEFORE', type: 'type1' },
{ email: 'two@example.com', name: 'BEFORE', type: 'type1' },
{ email: 'two@example.com', name: 'BEFORE', type: 'type2' },
]);

// Perform insert..merge (upsert)
try {
await knex('upsert_tests')
.insert([
{ email: 'one@example.com', name: 'AFTER', type: 'type1' },
{ email: 'two@example.com', name: 'AFTER', type: 'type1' },
{ email: 'three@example.com', name: 'AFTER', type: 'type1' },
])
.onConflict(knex.raw("(email) where type = 'type1'"))
.merge()
.testSql(function (tester) {
tester(
'mysql',
'insert into `upsert_tests` (`email`, `name`) values (?, ?), (?, ?) on duplicate key update `email` = values(`email`), `name` = values(`name`)',
['two@example.com', 'AFTER', 'three@example.com', 'AFTER']
);
tester(
'pg',
'insert into "upsert_tests" ("email", "name", "type") values (?, ?, ?), (?, ?, ?), (?, ?, ?) on conflict (email) where type = \'type1\' do update set "email" = excluded."email", "name" = excluded."name", "type" = excluded."type"',
[
'one@example.com',
'AFTER',
'type1',
'two@example.com',
'AFTER',
'type1',
'three@example.com',
'AFTER',
'type1',
]
);
tester(
'sqlite3',
'insert into `upsert_tests` (`email`, `name`, `type`) select ? as `email`, ? as `name`, ? as `type` union all select ? as `email`, ? as `name`, ? as `type` union all select ? as `email`, ? as `name`, ? as `type` where true ' +
"on conflict (email) where type = 'type1' do update set `email` = excluded.`email`, `name` = excluded.`name`, `type` = excluded.`type`",
[
'one@example.com',
'AFTER',
'type1',
'two@example.com',
'AFTER',
'type1',
'three@example.com',
'AFTER',
'type1',
]
);
});
} catch (err) {
if (isOracle(knex) || isMssql(knex)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
}
throw err;
}

// Check that row HAS been updated
const rows = await knex('upsert_tests')
.select()
.orderBy(['email', 'name']);
expect(rows.length).to.equal(4);

expect(rows).to.eql([
{ email: 'one@example.com', name: 'AFTER', type: 'type1' }, // type1 => updated
{ email: 'three@example.com', name: 'AFTER', type: 'type1' },
{ email: 'two@example.com', name: 'AFTER', type: 'type1' }, // type1 => updated
{ email: 'two@example.com', name: 'BEFORE', type: 'type2' }, // type2 => not updated
]);
});

it('#1423 should replace undefined keys in single insert with DEFAULT also in transacting query', function () {
if (isSQLite(knex)) {
return true;
Expand Down
24 changes: 24 additions & 0 deletions test/unit/query/builder.js
Original file line number Diff line number Diff line change
Expand Up @@ -6185,6 +6185,30 @@ describe('QueryBuilder', () => {
);
});

it('insert ignore multiple with raw onConflict', () => {
testsql(
qb()
.insert([{ email: 'foo' }, { email: 'bar' }])
.onConflict(raw('(value) WHERE deleted_at IS NULL'))
.ignore()
.into('users'),
{
mysql: {
sql: 'insert ignore into `users` (`email`) values (?), (?)',
bindings: ['foo', 'bar'],
},
pg: {
sql: 'insert into "users" ("email") values (?), (?) on conflict (value) WHERE deleted_at IS NULL do nothing',
bindings: ['foo', 'bar'],
},
sqlite3: {
sql: 'insert into `users` (`email`) select ? as `email` union all select ? as `email` where true on conflict (value) WHERE deleted_at IS NULL do nothing',
bindings: ['foo', 'bar'],
},
}
);
});

it('insert ignore with composite unique keys', () => {
testsql(
qb()
Expand Down
4 changes: 4 additions & 0 deletions types/index.d.ts
Original file line number Diff line number Diff line change
Expand Up @@ -979,6 +979,10 @@ export declare namespace Knex {
columns: string[]
): OnConflictQueryBuilder<TRecord, TResult>;

onConflict(
raw: Raw
): OnConflictQueryBuilder<TRecord, TResult>;

onConflict(): OnConflictQueryBuilder<TRecord, TResult>;

del(
Expand Down

0 comments on commit 6ee3f94

Please sign in to comment.