mirror of
https://github.com/knex/knex.git
synced 2025-12-26 06:28:37 +00:00
Add raw support in onConflict clause (#4960)
This commit is contained in:
parent
63980987a6
commit
6ee3f94d1a
@ -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) =>
|
||||
|
||||
@ -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) =>
|
||||
|
||||
@ -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;
|
||||
|
||||
@ -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;
|
||||
|
||||
@ -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()
|
||||
|
||||
4
types/index.d.ts
vendored
4
types/index.d.ts
vendored
@ -979,6 +979,10 @@ export declare namespace Knex {
|
||||
columns: string[]
|
||||
): OnConflictQueryBuilder<TRecord, TResult>;
|
||||
|
||||
onConflict(
|
||||
raw: Raw
|
||||
): OnConflictQueryBuilder<TRecord, TResult>;
|
||||
|
||||
onConflict(): OnConflictQueryBuilder<TRecord, TResult>;
|
||||
|
||||
del(
|
||||
|
||||
Loading…
x
Reference in New Issue
Block a user