Skip to content

Commit

Permalink
feat(postgres, sqlite): add conflictWhere option to upsert (#15786)
Browse files Browse the repository at this point in the history
  • Loading branch information
wbourne0 committed Mar 22, 2023
1 parent 5bda2ce commit 1e68681
Show file tree
Hide file tree
Showing 9 changed files with 272 additions and 5 deletions.
1 change: 1 addition & 0 deletions src/dialects/abstract/index.d.ts
Expand Up @@ -41,6 +41,7 @@ export declare type DialectSupports = {
ignoreDuplicates: string;
updateOnDuplicate: boolean | string;
onConflictDoNothing: string;
onConflictWhere: boolean,
conflictFields: boolean;
};
constraints: {
Expand Down
1 change: 1 addition & 0 deletions src/dialects/abstract/index.js
Expand Up @@ -50,6 +50,7 @@ AbstractDialect.prototype.supports = {
ignoreDuplicates: '', /* dialect specific words for INSERT IGNORE or DO NOTHING */
updateOnDuplicate: false, /* whether dialect supports ON DUPLICATE KEY UPDATE */
onConflictDoNothing: '', /* dialect specific words for ON CONFLICT DO NOTHING */
onConflictWhere: false, /* whether dialect supports ON CONFLICT WHERE */
conflictFields: false /* whether the dialect supports specifying conflict fields or not */
},
constraints: {
Expand Down
29 changes: 27 additions & 2 deletions src/dialects/abstract/query-generator.js
Expand Up @@ -198,6 +198,13 @@ class QueryGenerator {

let onDuplicateKeyUpdate = '';

if (
!_.isEmpty(options.conflictWhere)
&& !this._dialect.supports.inserts.onConflictWhere
) {
throw new Error('missing dialect support for conflictWhere option');
}

// `options.updateOnDuplicate` is the list of field names to update if a duplicate key is hit during the insert. It
// contains just the field names. This option is _usually_ explicitly set by the corresponding query-interface
// upsert function.
Expand All @@ -206,10 +213,28 @@ class QueryGenerator {
// If no conflict target columns were specified, use the primary key names from options.upsertKeys
const conflictKeys = options.upsertKeys.map(attr => this.quoteIdentifier(attr));
const updateKeys = options.updateOnDuplicate.map(attr => `${this.quoteIdentifier(attr)}=EXCLUDED.${this.quoteIdentifier(attr)}`);
onDuplicateKeyUpdate = ` ON CONFLICT (${conflictKeys.join(',')})`;

const fragments = [
'ON CONFLICT',
'(',
conflictKeys.join(','),
')'
];

if (!_.isEmpty(options.conflictWhere)) {
fragments.push(this.whereQuery(options.conflictWhere, options));
}

// if update keys are provided, then apply them here. if there are no updateKeys provided, then do not try to
// do an update. Instead, fall back to DO NOTHING.
onDuplicateKeyUpdate += _.isEmpty(updateKeys) ? ' DO NOTHING ' : ` DO UPDATE SET ${updateKeys.join(',')}`;
if (_.isEmpty(updateKeys)) {
fragments.push('DO NOTHING');
} else {
fragments.push('DO UPDATE SET', updateKeys.join(','));
}

onDuplicateKeyUpdate = ` ${Utils.joinSQLFragments(fragments)}`;

} else {
const valueKeys = options.updateOnDuplicate.map(attr => `${this.quoteIdentifier(attr)}=VALUES(${this.quoteIdentifier(attr)})`);
// the rough equivalent to ON CONFLICT DO NOTHING in mysql, etc is ON DUPLICATE KEY UPDATE id = id
Expand Down
3 changes: 2 additions & 1 deletion src/dialects/postgres/index.js
Expand Up @@ -60,7 +60,8 @@ PostgresDialect.prototype.supports = _.merge(
inserts: {
onConflictDoNothing: ' ON CONFLICT DO NOTHING',
updateOnDuplicate: ' ON CONFLICT DO UPDATE SET',
conflictFields: true
conflictFields: true,
onConflictWhere: true
},
NUMERIC: true,
ARRAY: true,
Expand Down
3 changes: 2 additions & 1 deletion src/dialects/sqlite/index.js
Expand Up @@ -35,7 +35,8 @@ SqliteDialect.prototype.supports = _.merge(
inserts: {
ignoreDuplicates: ' OR IGNORE',
updateOnDuplicate: ' ON CONFLICT DO UPDATE SET',
conflictFields: true
conflictFields: true,
onConflictWhere: true
},
index: {
using: false,
Expand Down
6 changes: 6 additions & 0 deletions src/model.d.ts
Expand Up @@ -1022,6 +1022,12 @@ export interface UpsertOptions<TAttributes = any> extends Logging, Transactionab
* Run validations before the row is inserted
*/
validate?: boolean;
/**
* An optional parameter that specifies a where clause for the `ON CONFLICT` part of the query
* (in particular: for applying to partial unique indexes).
* Only supported in Postgres >= 9.5 and SQLite >= 3.24.0
*/
conflictWhere?: WhereOptions<TAttributes>;
/**
* Optional override for the conflict fields in the ON CONFLICT part of the query.
* Only supported in Postgres >= 9.5 and SQLite >= 3.24.0
Expand Down
161 changes: 161 additions & 0 deletions test/integration/model/upsert.test.js
Expand Up @@ -760,6 +760,167 @@ describe(Support.getTestDialectTeaser('Model'), () => {
expect(otherMembership.id).to.not.eq(originalMembership.id);
});
});

if (current.dialect.supports.inserts.onConflictWhere) {
describe('conflictWhere', () => {
const Users = current.define(
'users',
{
name: DataTypes.STRING,
bio: DataTypes.STRING,
isUnique: DataTypes.BOOLEAN
},
{
indexes: [
{
unique: true,
fields: ['name'],
where: { isUnique: true }
}
]
}
);

beforeEach(() => Users.sync({ force: true }));

it('should insert with no other rows', async () => {
const [newRow] = await Users.upsert(
{
name: 'John',
isUnique: true
},
{
conflictWhere: {
isUnique: true
}
}
);

expect(newRow).to.not.eq(null);
expect(newRow.name).to.eq('John');
});

it('should update with another unique user', async () => {
let [newRow] = await Users.upsert(
{
name: 'John',
isUnique: true,
bio: 'before'
},
{
conflictWhere: {
isUnique: true
}
}
);

expect(newRow).to.not.eq(null);
expect(newRow.name).to.eq('John');
expect(newRow.bio).to.eq('before');

[newRow] = await Users.upsert(
{
name: 'John',
isUnique: true,
bio: 'after'
},
{
conflictWhere: {
isUnique: true
}
}
);

expect(newRow).to.not.eq(null);
expect(newRow.name).to.eq('John');
expect(newRow.bio).to.eq('after');

const rowCount = await Users.count();

expect(rowCount).to.eq(1);
});

it('allows both unique and non-unique users with the same name', async () => {
let [newRow] = await Users.upsert(
{
name: 'John',
isUnique: true,
bio: 'first'
},
{
conflictWhere: {
isUnique: true
}
}
);

expect(newRow).to.not.eq(null);
expect(newRow.name).to.eq('John');
expect(newRow.bio).to.eq('first');

[newRow] = await Users.upsert(
{
name: 'John',
isUnique: false,
bio: 'second'
},
{
conflictWhere: {
isUnique: true
}
}
);

expect(newRow).to.not.eq(null);
expect(newRow.name).to.eq('John');
expect(newRow.bio).to.eq('second');

const rowCount = await Users.count();

expect(rowCount).to.eq(2);
});

it('allows for multiple unique users with different names', async () => {
let [newRow] = await Users.upsert(
{
name: 'John',
isUnique: true,
bio: 'first'
},
{
conflictWhere: {
isUnique: true
}
}
);

expect(newRow).to.not.eq(null);
expect(newRow.name).to.eq('John');
expect(newRow.bio).to.eq('first');

[newRow] = await Users.upsert(
{
name: 'Bob',
isUnique: false,
bio: 'second'
},
{
conflictWhere: {
isUnique: true
}
}
);

expect(newRow).to.not.eq(null);
expect(newRow.name).to.eq('Bob');
expect(newRow.bio).to.eq('second');

const rowCount = await Users.count();

expect(rowCount).to.eq(2);
});
});
}
}
});
}
Expand Down
7 changes: 7 additions & 0 deletions test/types/upsert.ts
Expand Up @@ -43,4 +43,11 @@ sequelize.transaction(async trx => {
validate: true,
conflictFields: ['foo', 'bar']
});

const res4: [TestModel, boolean | null] = await TestModel.upsert<TestModel>({}, {
conflictWhere: {
foo: 'abc',
bar: 'def',
},
});
})
66 changes: 65 additions & 1 deletion test/unit/sql/insert.test.js
Expand Up @@ -33,7 +33,7 @@ describe(Support.getTestDialectTeaser('SQL'), () => {
db2: 'SELECT * FROM FINAL TABLE(INSERT INTO "users" ("user_name") VALUES ($1));',
snowflake: 'INSERT INTO "users" ("user_name") VALUES ($1);',
oracle: 'INSERT INTO "users" ("user_name") VALUES (:1) RETURNING "id","user_name" INTO :2,:3;',
default: 'INSERT INTO `users` (`user_name`) VALUES ($1);'
default: 'INSERT INTO `users` (`user_name`) VALUES ($1);'
},
bind: ['triggertest']
});
Expand Down Expand Up @@ -64,6 +64,70 @@ describe(Support.getTestDialectTeaser('SQL'), () => {
});
});

it(
current.dialect.supports.inserts.onConflictWhere
? 'adds conflictWhere clause to generated queries'
: 'throws error if conflictWhere is provided',
() => {
const User = Support.sequelize.define(
'user',
{
username: {
type: DataTypes.STRING,
field: 'user_name',
primaryKey: true
},
password: {
type: DataTypes.STRING,
field: 'pass_word'
},
createdAt: {
type: DataTypes.DATE,
field: 'created_at'
},
updatedAt: {
type: DataTypes.DATE,
field: 'updated_at'
}
},
{
timestamps: true
}
);

const upsertKeys = ['user_name'];

let result;

try {
result = sql.insertQuery(
User.tableName,
{ user_name: 'testuser', pass_word: '12345' },
User.fieldRawAttributesMap,
{
updateOnDuplicate: ['user_name', 'pass_word', 'updated_at'],
conflictWhere: {
user_name: 'test where value'
},
upsertKeys
}
);
} catch (error) {
result = error;
}

expectsql(result, {
default: new Error(
'missing dialect support for conflictWhere option'
),
postgres:
'INSERT INTO "users" ("user_name","pass_word") VALUES ($1,$2) ON CONFLICT ("user_name") WHERE "user_name" = \'test where value\' DO UPDATE SET "user_name"=EXCLUDED."user_name","pass_word"=EXCLUDED."pass_word","updated_at"=EXCLUDED."updated_at";',
sqlite:
'INSERT INTO `users` (`user_name`,`pass_word`) VALUES ($1,$2) ON CONFLICT (`user_name`) WHERE `user_name` = \'test where value\' DO UPDATE SET `user_name`=EXCLUDED.`user_name`,`pass_word`=EXCLUDED.`pass_word`,`updated_at`=EXCLUDED.`updated_at`;'
});
}
);

describe('dates', () => {
it('formats the date correctly when inserting', () => {
const timezoneSequelize = Support.createSequelizeInstance({
Expand Down

0 comments on commit 1e68681

Please sign in to comment.