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: MSSQL onConflict/merge support #6050

Open
wants to merge 1 commit into
base: master
Choose a base branch
from
Open
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
112 changes: 107 additions & 5 deletions lib/dialects/mssql/query/mssql-querycompiler.js
Expand Up @@ -28,11 +28,6 @@ class QueryCompiler_MSSQL extends QueryCompiler {
constructor(client, builder, formatter) {
super(client, builder, formatter);

const { onConflict } = this.single;
if (onConflict) {
throw new Error('.onConflict() is not supported for mssql.');
}

this._emptyInsertValue = 'default values';
}

Expand Down Expand Up @@ -70,6 +65,9 @@ class QueryCompiler_MSSQL extends QueryCompiler {
// Compiles an "insert" query, allowing for multiple
// inserts using a single query statement.
insert() {
if (this.single.onConflict) {
return this._insertWithMerge();
}
if (
this.single.options &&
this.single.options.includeTriggerModifications
Expand All @@ -80,6 +78,110 @@ class QueryCompiler_MSSQL extends QueryCompiler {
}
}

_mergeAnd() {
const wheres = this.where();

if (!wheres) {
return '';
}
return `and ${wheres.slice(6)} `;
}

_mergeWhenMatched(columns, updates) {
let columnsData = [];

if (!updates || Array.isArray(updates)) {
columnsData = columns
.map((column) => `${this.formatter.columnize(column)}=tsource.${this.formatter.columnize(column)}`)
.join(', ');
}

if (typeof updates === 'string') {
columnsData = `${this.formatter.columnize(updates)}=tsource.${this.formatter.columnize(updates)}`;
}

if (!Array.isArray(updates) && typeof updates === 'object') {
columnsData = Object.entries(updates)
.map(([key, value]) => `${this.tableName}.${this.formatter.columnize(key)}=(${this._getParameters([value])})`);
}

const sql = ` when matched ${this._mergeAnd()}then update set ${columnsData}`;

return sql;
}

_mergeWhenNotMatched(columns) {
const destinationColumns = this.formatter.columnize(columns);
const sourceColumns = this.formatter.columnizeWithPrefix('tsource.',columns);

const sql = ` when not matched then insert (${destinationColumns}) values (${sourceColumns})`;

return sql;
}

_getParameters(params) {
const sql = this.client.parameterize(
params,
this.client.valueForUndefined,
this.builder,
this.bindingsHolder,
);

return sql
}

_mergeInsertIsEmpty(insert) {
return (Array.isArray(insert) && insert.length === 0)
|| (typeof insert === 'object' && isEmpty(insert))
}

_mergeOn(conflict) {
let sql = 'on 1=1';

if (Array.isArray(conflict)) {
const conflictColumn = this.formatter.columnize(conflict[0]);
sql = `on ${this.tableName}.${conflictColumn} = tsource.${conflictColumn}`;
}

return sql;
}

_insertWithMerge() {

const { insert = [], onConflict, ignore, merge, returning, options = {} } = this.single;
if (this._mergeInsertIsEmpty(insert)) {
return '';
}

const insertData = this._prepInsert(insert);
const insertParameters = insertData.values.map((value) => `(${this._getParameters(value)})`).join(', ');
const sourceColumns = this.formatter.columnize(insertData.columns);

const returningSql = returning
? ` ${this._returning('insert', returning, options.includeTriggerModifications)}`
: ''

let sql = `merge into ${this.tableName} using (values ${insertParameters}) as tsource(${sourceColumns}) `;

sql += this._mergeOn(onConflict);

sql += this._mergeWhenNotMatched(insertData.columns);

if (!ignore) {
sql += this._mergeWhenMatched(insertData.columns, merge.updates);
}

sql += returningSql;

if (options.includeTriggerModifications) {
sql = this._buildTempTable(returning) + sql + this._buildReturningSelect(returning);
}

sql = this.with() + sql + ';';

return sql;
}

insertWithTriggers() {
const insertValues = this.single.insert || [];
const { returning } = this.single;
Expand Down
72 changes: 61 additions & 11 deletions test/integration2/query/insert/inserts.spec.js
Expand Up @@ -1388,9 +1388,14 @@ describe('Inserts', function () {
'insert into `upsert_tests` (`email`, `name`) values (?, ?) on conflict (`email`) do nothing returning `email`',
['ignoretest1@example.com', 'AFTER']
);
tester(
'mssql',
'merge into [upsert_tests] using (values (?, ?)) as tsource([email], [name]) on [upsert_tests].[email] = tsource.[email] when not matched then insert ([email], [name]) values (tsource.[email], tsource.[name]) output inserted.[email];',
['ignoretest1@example.com', 'AFTER']
);
});
} catch (err) {
if (isOracle(knex) || isMssql(knex)) {
if (isOracle(knex)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
Expand Down Expand Up @@ -1450,9 +1455,14 @@ describe('Inserts', function () {
'insert into `upsert_tests` (`email`, `name`) values (?, ?) on conflict do nothing returning `email`',
['ignoretest1@example.com', 'AFTER']
);
tester(
'mssql',
'merge into [upsert_tests] using (values (?, ?)) as tsource([email], [name]) on 1=1 when not matched then insert ([email], [name]) values (tsource.[email], tsource.[name]) output inserted.[email];',
['ignoretest1@example.com', 'AFTER']
);
});
} catch (err) {
if (isOracle(knex) || isMssql(knex)) {
if (isOracle(knex)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
Expand Down Expand Up @@ -1518,9 +1528,14 @@ describe('Inserts', function () {
'insert into `upsert_composite_key_tests` (`email`, `name`, `org`) values (?, ?, ?) on conflict (`org`, `email`) do nothing returning `email`',
['ignoretest1@example.com', 'AFTER', 'acme-inc']
);
tester(
'mssql',
'merge into [upsert_composite_key_tests] using (values (?, ?, ?)) as tsource([email], [name], [org]) on [upsert_composite_key_tests].[org] = tsource.[org] when not matched then insert ([email], [name], [org]) values (tsource.[email], tsource.[name], tsource.[org]) output inserted.[email];',
['ignoretest1@example.com', 'AFTER', 'acme-inc']
);
});
} catch (err) {
if (isOracle(knex) || isMssql(knex)) {
if (isOracle(knex)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
Expand Down Expand Up @@ -1577,9 +1592,14 @@ describe('Inserts', function () {
'insert into `upsert_tests` (`email`, `name`) values (?, ?) on conflict (`email`) do update set `email` = excluded.`email`, `name` = excluded.`name` returning `email`',
['mergetest1@example.com', 'AFTER']
);
tester(
'mssql',
'merge into [upsert_tests] using (values (?, ?)) as tsource([email], [name]) on [upsert_tests].[email] = tsource.[email] when not matched then insert ([email], [name]) values (tsource.[email], tsource.[name]) when matched then update set [email]=tsource.[email], [name]=tsource.[name] output inserted.[email];',
['mergetest1@example.com', 'AFTER']
);
});
} catch (err) {
if (isOracle(knex) || isMssql(knex)) {
if (isOracle(knex)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
Expand Down Expand Up @@ -1634,9 +1654,14 @@ describe('Inserts', function () {
'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`',
['mergetest1@example.com', 'AFTER', 'tester']
);
tester(
'mssql',
'merge into [upsert_tests] using (values (?, ?)) as tsource([email], [name]) on [upsert_tests].[email] = tsource.[email] when not matched then insert ([email], [name]) values (tsource.[email], tsource.[name]) when matched and [upsert_tests].[role] = ? then update set [email]=tsource.[email], [name]=tsource.[name] output inserted.[email];',
['mergetest1@example.com', 'AFTER', 'tester']
);
});
} catch (err) {
if (isOracle(knex) || isMssql(knex)) {
if (isOracle(knex)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
Expand Down Expand Up @@ -1700,9 +1725,14 @@ describe('Inserts', function () {
'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`',
['mergetest1@example.com', 'AFTER', 'fake-role']
);
tester(
'mssql',
'merge into [upsert_tests] using (values (?, ?)) as tsource([email], [name]) on [upsert_tests].[email] = tsource.[email] when not matched then insert ([email], [name]) values (tsource.[email], tsource.[name]) when matched and [upsert_tests].[role] = ? then update set [email]=tsource.[email], [name]=tsource.[name] output inserted.[email];',
['mergetest1@example.com', 'AFTER', 'fake-role']
);
});
} catch (err) {
if (isOracle(knex) || isMssql(knex)) {
if (isOracle(knex)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
Expand Down Expand Up @@ -1776,9 +1806,14 @@ describe('Inserts', function () {
"insert into `upsert_tests` (`email`, `name`) values (?, (SELECT name FROM (SELECT * FROM upsert_tests) AS t WHERE email = 'mergesource@example.com')) on conflict (`email`) do update set `email` = excluded.`email`, `name` = excluded.`name` returning `email`",
['mergedest@example.com']
);
tester(
'mssql',
"merge into [upsert_tests] using (values (?, (SELECT name FROM (SELECT * FROM upsert_tests) AS t WHERE email = 'mergesource@example.com'))) as tsource([email], [name]) on [upsert_tests].[email] = tsource.[email] when not matched then insert ([email], [name]) values (tsource.[email], tsource.[name]) when matched then update set [email]=tsource.[email], [name]=tsource.[name] output inserted.[email];",
['mergedest@example.com']
);
});
} catch (err) {
if (isOracle(knex) || isMssql(knex)) {
if (isOracle(knex)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
Expand Down Expand Up @@ -1844,9 +1879,14 @@ describe('Inserts', function () {
'insert into `upsert_tests` (`email`, `name`) values (?, ?) on conflict (`email`) do update set `name` = (SELECT name FROM upsert_value_source) returning `email`',
['mergedest@example.com', 'SHOULD NOT BE USED']
);
tester(
'mssql',
'merge into [upsert_tests] using (values (?, ?)) as tsource([email], [name]) on [upsert_tests].[email] = tsource.[email] when not matched then insert ([email], [name]) values (tsource.[email], tsource.[name]) when matched then update set [upsert_tests].[name]=((SELECT name FROM upsert_value_source)) output inserted.[email];',
['mergedest@example.com', 'SHOULD NOT BE USED']
);
});
} catch (err) {
if (isOracle(knex) || isMssql(knex)) {
if (isOracle(knex)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
Expand Down Expand Up @@ -1912,9 +1952,14 @@ describe('Inserts', function () {
'insert into `upsert_tests` (`email`, `name`) values (?, ?) on conflict (`email`) do update set `name` = excluded.`name` returning `email`',
['mergedest@example.com', 'SHOULD BE USED']
);
tester(
'mssql',
'merge into [upsert_tests] using (values (?, ?)) as tsource([email], [name]) on [upsert_tests].[email] = tsource.[email] when not matched then insert ([email], [name]) values (tsource.[email], tsource.[name]) when matched then update set [email]=tsource.[email], [name]=tsource.[name] output inserted.[email];',
['mergedest@example.com', 'SHOULD BE USED']
);
});
} catch (err) {
if (isOracle(knex) || isMssql(knex)) {
if (isOracle(knex)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
Expand Down Expand Up @@ -1977,9 +2022,14 @@ describe('Inserts', function () {
'insert into `upsert_tests` (`email`, `name`) select ? as `email`, ? as `name` union all select ? as `email`, ? as `name` where true on conflict (`email`) do update set `email` = excluded.`email`, `name` = excluded.`name` returning `email`',
['two@example.com', 'AFTER', 'three@example.com', 'AFTER']
);
tester(
'mssql',
'merge into [upsert_tests] using (values (?, ?), (?, ?)) as tsource([email], [name]) on [upsert_tests].[email] = tsource.[email] when not matched then insert ([email], [name]) values (tsource.[email], tsource.[name]) when matched then update set [email]=tsource.[email], [name]=tsource.[name] output inserted.[email];',
['two@example.com', 'AFTER', 'three@example.com', 'AFTER']
);
});
} catch (err) {
if (isOracle(knex) || isMssql(knex)) {
if (isOracle(knex)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
Expand Down Expand Up @@ -2071,7 +2121,7 @@ describe('Inserts', function () {
);
});
} catch (err) {
if (isOracle(knex) || isMssql(knex)) {
if (isOracle(knex)) {
expect(err).to.be.an('error');
if (err.message.includes('.onConflict() is not supported for'))
return;
Expand Down