不要怂,就是干,撸起袖子干!

Commit 4d9165b6 by Sushant Committed by GitHub

feat(postgres): native upsert (#12301)

1 parent 8244a34e
...@@ -7,7 +7,6 @@ AbstractDialect.prototype.supports = { ...@@ -7,7 +7,6 @@ AbstractDialect.prototype.supports = {
'DEFAULT VALUES': false, 'DEFAULT VALUES': false,
'VALUES ()': false, 'VALUES ()': false,
'LIMIT ON UPDATE': false, 'LIMIT ON UPDATE': false,
'ON DUPLICATE KEY': true,
'ORDER NULLS': false, 'ORDER NULLS': false,
'UNION': true, 'UNION': true,
'UNION ALL': true, 'UNION ALL': true,
......
...@@ -3,7 +3,6 @@ ...@@ -3,7 +3,6 @@
const util = require('util'); const util = require('util');
const _ = require('lodash'); const _ = require('lodash');
const uuidv4 = require('uuid').v4; const uuidv4 = require('uuid').v4;
const semver = require('semver');
const Utils = require('../../utils'); const Utils = require('../../utils');
const deprecations = require('../../utils/deprecations'); const deprecations = require('../../utils/deprecations');
...@@ -179,6 +178,20 @@ class QueryGenerator { ...@@ -179,6 +178,20 @@ class QueryGenerator {
} }
} }
let onDuplicateKeyUpdate = '';
if (this._dialect.supports.inserts.updateOnDuplicate && options.updateOnDuplicate) {
if (this._dialect.supports.inserts.updateOnDuplicate == ' ON CONFLICT DO UPDATE SET') { // postgres / sqlite
// 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(',')}) DO UPDATE SET ${updateKeys.join(',')}`;
} else {
const valueKeys = options.updateOnDuplicate.map(attr => `${this.quoteIdentifier(attr)}=VALUES(${this.quoteIdentifier(attr)})`);
onDuplicateKeyUpdate += `${this._dialect.supports.inserts.updateOnDuplicate} ${valueKeys.join(',')}`;
}
}
const replacements = { const replacements = {
ignoreDuplicates: options.ignoreDuplicates ? this._dialect.supports.inserts.ignoreDuplicates : '', ignoreDuplicates: options.ignoreDuplicates ? this._dialect.supports.inserts.ignoreDuplicates : '',
onConflictDoNothing: options.ignoreDuplicates ? this._dialect.supports.inserts.onConflictDoNothing : '', onConflictDoNothing: options.ignoreDuplicates ? this._dialect.supports.inserts.onConflictDoNothing : '',
...@@ -188,8 +201,8 @@ class QueryGenerator { ...@@ -188,8 +201,8 @@ class QueryGenerator {
tmpTable tmpTable
}; };
valueQuery = `${tmpTable}INSERT${replacements.ignoreDuplicates} INTO ${quotedTable} (${replacements.attributes})${replacements.output} VALUES (${replacements.values})${replacements.onConflictDoNothing}${valueQuery}`; valueQuery = `${tmpTable}INSERT${replacements.ignoreDuplicates} INTO ${quotedTable} (${replacements.attributes})${replacements.output} VALUES (${replacements.values})${onDuplicateKeyUpdate}${replacements.onConflictDoNothing}${valueQuery}`;
emptyQuery = `${tmpTable}INSERT${replacements.ignoreDuplicates} INTO ${quotedTable}${replacements.output}${replacements.onConflictDoNothing}${emptyQuery}`; emptyQuery = `${tmpTable}INSERT${replacements.ignoreDuplicates} INTO ${quotedTable}${replacements.output}${onDuplicateKeyUpdate}${replacements.onConflictDoNothing}${emptyQuery}`;
// Mostly for internal use, so we expect the user to know what he's doing! // Mostly for internal use, so we expect the user to know what he's doing!
// pg_temp functions are private per connection, so we never risk this function interfering with another one. // pg_temp functions are private per connection, so we never risk this function interfering with another one.
...@@ -200,31 +213,16 @@ class QueryGenerator { ...@@ -200,31 +213,16 @@ class QueryGenerator {
returningModelAttributes.push('*'); returningModelAttributes.push('*');
} }
if (semver.gte(this.sequelize.options.databaseVersion, '9.2.0')) {
// >= 9.2 - Use a UUID but prefix with 'func_' (numbers first not allowed)
const delimiter = `$func_${uuidv4().replace(/-/g, '')}$`; const delimiter = `$func_${uuidv4().replace(/-/g, '')}$`;
const selectQuery = `SELECT (testfunc.response).${returningModelAttributes.join(', (testfunc.response).')}, testfunc.sequelize_caught_exception FROM pg_temp.testfunc();`; const selectQuery = `SELECT (testfunc.response).${returningModelAttributes.join(', (testfunc.response).')}, testfunc.sequelize_caught_exception FROM pg_temp.testfunc();`;
options.exception = 'WHEN unique_violation THEN GET STACKED DIAGNOSTICS sequelize_caught_exception = PG_EXCEPTION_DETAIL;'; options.exception = 'WHEN unique_violation THEN GET STACKED DIAGNOSTICS sequelize_caught_exception = PG_EXCEPTION_DETAIL;';
valueQuery = `CREATE OR REPLACE FUNCTION pg_temp.testfunc(OUT response ${quotedTable}, OUT sequelize_caught_exception text) RETURNS RECORD AS ${delimiter valueQuery = `CREATE OR REPLACE FUNCTION pg_temp.testfunc(OUT response ${quotedTable}, OUT sequelize_caught_exception text) RETURNS RECORD AS ${delimiter} BEGIN ${valueQuery} RETURNING * INTO response; EXCEPTION ${options.exception} END ${delimiter} LANGUAGE plpgsql; ${selectQuery} ${dropFunction}`;
} BEGIN ${valueQuery} RETURNING * INTO response; EXCEPTION ${options.exception} END ${delimiter} LANGUAGE plpgsql; ${selectQuery} ${dropFunction}`;
} else {
const selectQuery = `SELECT ${returningModelAttributes.join(', ')} FROM pg_temp.testfunc();`;
options.exception = 'WHEN unique_violation THEN NULL;';
valueQuery = `CREATE OR REPLACE FUNCTION pg_temp.testfunc() RETURNS SETOF ${quotedTable} AS $body$ BEGIN RETURN QUERY ${valueQuery
} RETURNING *; EXCEPTION ${options.exception} END; $body$ LANGUAGE plpgsql; ${selectQuery} ${dropFunction}`;
}
} else { } else {
valueQuery += returningFragment; valueQuery += returningFragment;
emptyQuery += returningFragment; emptyQuery += returningFragment;
} }
if (this._dialect.supports['ON DUPLICATE KEY'] && options.onDuplicate) {
valueQuery += ` ON DUPLICATE KEY ${options.onDuplicate}`;
emptyQuery += ` ON DUPLICATE KEY ${options.onDuplicate}`;
}
query = `${replacements.attributes.length ? valueQuery : emptyQuery};`; query = `${replacements.attributes.length ? valueQuery : emptyQuery};`;
if (identityWrapperRequired && this._dialect.supports.autoIncrement.identityInsert) { if (identityWrapperRequired && this._dialect.supports.autoIncrement.identityInsert) {
query = `SET IDENTITY_INSERT ${quotedTable} ON; ${query} SET IDENTITY_INSERT ${quotedTable} OFF;`; query = `SET IDENTITY_INSERT ${quotedTable} ON; ${query} SET IDENTITY_INSERT ${quotedTable} OFF;`;
......
...@@ -6,7 +6,6 @@ const Utils = require('../../utils'); ...@@ -6,7 +6,6 @@ const Utils = require('../../utils');
const DataTypes = require('../../data-types'); const DataTypes = require('../../data-types');
const Transaction = require('../../transaction'); const Transaction = require('../../transaction');
const QueryTypes = require('../../query-types'); const QueryTypes = require('../../query-types');
const Op = require('../../operators');
/** /**
* The interface that Sequelize uses to talk to all databases * The interface that Sequelize uses to talk to all databases
...@@ -744,72 +743,51 @@ class QueryInterface { ...@@ -744,72 +743,51 @@ class QueryInterface {
* @param {string} tableName table to upsert on * @param {string} tableName table to upsert on
* @param {object} insertValues values to be inserted, mapped to field name * @param {object} insertValues values to be inserted, mapped to field name
* @param {object} updateValues values to be updated, mapped to field name * @param {object} updateValues values to be updated, mapped to field name
* @param {object} where various conditions * @param {object} where where conditions, which can be used for UPDATE part when INSERT fails
* @param {Model} model Model to upsert on
* @param {object} options query options * @param {object} options query options
* *
* @returns {Promise<boolean,?number>} Resolves an array with <created, primaryKey> * @returns {Promise<boolean,?number>} Resolves an array with <created, primaryKey>
*/ */
async upsert(tableName, insertValues, updateValues, where, model, options) { async upsert(tableName, insertValues, updateValues, where, options) {
const wheres = [];
const attributes = Object.keys(insertValues);
let indexes = [];
let indexFields;
options = { ...options }; options = { ...options };
if (!Utils.isWhereEmpty(where)) { const model = options.model;
wheres.push(where); const primaryKeys = Object.values(model.primaryKeys).map(item => item.field);
} const uniqueKeys = Object.values(model.uniqueKeys).filter(c => c.fields.length >= 1).map(c => c.fields);
const indexKeys = Object.values(model._indexes).filter(c => c.unique && c.fields.length >= 1).map(c => c.fields);
// Lets combine unique keys and indexes into one options.type = QueryTypes.UPSERT;
indexes = _.map(model.uniqueKeys, value => { options.updateOnDuplicate = Object.keys(updateValues);
return value.fields; options.upsertKeys = [];
});
model._indexes.forEach(value => { // For fields in updateValues, try to find a constraint or unique index
if (value.unique) { // that includes given field. Only first matching upsert key is used.
// fields in the index may both the strings or objects with an attribute property - lets sanitize that for (const field of options.updateOnDuplicate) {
indexFields = value.fields.map(field => { const uniqueKey = uniqueKeys.find(fields => fields.includes(field));
if (_.isPlainObject(field)) { if (uniqueKey) {
return field.attribute; options.upsertKeys = uniqueKey;
break;
} }
return field;
});
indexes.push(indexFields);
}
});
for (const index of indexes) { const indexKey = indexKeys.find(fields => fields.includes(field));
if (_.intersection(attributes, index).length === index.length) { if (indexKey) {
where = {}; options.upsertKeys = indexKey;
for (const field of index) { break;
where[field] = insertValues[field];
} }
wheres.push(where);
} }
}
where = { [Op.or]: wheres };
options.type = QueryTypes.UPSERT; // Always use PK, if no constraint available OR update data contains PK
options.raw = true; if (
options.upsertKeys.length === 0
const sql = this.queryGenerator.upsertQuery(tableName, insertValues, updateValues, where, model, options); || _.intersection(options.updateOnDuplicate, primaryKeys).length
const result = await this.sequelize.query(sql, options); ) {
return this._convertUpsertResult(result, model); options.upsertKeys = primaryKeys;
} }
/** options.upsertKeys = _.uniq(options.upsertKeys);
* Converts raw upsert result to API contract.
* const sql = this.queryGenerator.insertQuery(tableName, insertValues, model.rawAttributes, options);
* @param {object} result return await this.sequelize.query(sql, options);
* @param {Model} model
* @protected
*/
// eslint-disable-next-line no-unused-vars
_convertUpsertResult(result, model) {
return [result, undefined];
} }
/** /**
......
...@@ -92,10 +92,12 @@ class Query extends AbstractQuery { ...@@ -92,10 +92,12 @@ class Query extends AbstractQuery {
formatResults(data) { formatResults(data) {
let result = this.instance; let result = this.instance;
if (this.isBulkUpdateQuery() || this.isBulkDeleteQuery() if (this.isBulkUpdateQuery() || this.isBulkDeleteQuery()) {
|| this.isUpsertQuery()) {
return data.affectedRows; return data.affectedRows;
} }
if (this.isUpsertQuery()) {
return [null, data.affectedRows === 1];
}
if (this.isInsertQuery(data)) { if (this.isInsertQuery(data)) {
this.handleInsertQuery(data); this.handleInsertQuery(data);
...@@ -116,6 +118,7 @@ class Query extends AbstractQuery { ...@@ -116,6 +118,7 @@ class Query extends AbstractQuery {
} }
return [result, data.affectedRows]; return [result, data.affectedRows];
} }
return [data[this.getInsertIdField()], data.affectedRows]; return [data[this.getInsertIdField()], data.affectedRows];
} }
} }
......
'use strict'; 'use strict';
const _ = require('lodash');
const Utils = require('../../utils');
const QueryTypes = require('../../query-types');
const Op = require('../../operators');
const { QueryInterface } = require('../abstract/query-interface'); const { QueryInterface } = require('../abstract/query-interface');
/** /**
...@@ -42,11 +47,38 @@ class MSSqlQueryInterface extends QueryInterface { ...@@ -42,11 +47,38 @@ class MSSqlQueryInterface extends QueryInterface {
/** /**
* @override * @override
*/ */
_convertUpsertResult(result, model) { async upsert(tableName, insertValues, updateValues, where, options) {
return [ const model = options.model;
result.$action === 'INSERT', const wheres = [];
result[model.primaryKeyField]
]; options = { ...options };
if (!Utils.isWhereEmpty(where)) {
wheres.push(where);
}
// Lets combine unique keys and indexes into one
let indexes = Object.values(model.uniqueKeys).map(item => item.fields);
indexes = indexes.concat(Object.values(model._indexes).filter(item => item.unique).map(item => item.fields));
const attributes = Object.keys(insertValues);
for (const index of indexes) {
if (_.intersection(attributes, index).length === index.length) {
where = {};
for (const field of index) {
where[field] = insertValues[field];
}
wheres.push(where);
}
}
where = { [Op.or]: wheres };
options.type = QueryTypes.UPSERT;
options.raw = true;
const sql = this.queryGenerator.upsertQuery(tableName, insertValues, updateValues, where, model, options);
return await this.sequelize.query(sql, options);
} }
} }
......
...@@ -206,9 +206,6 @@ class Query extends AbstractQuery { ...@@ -206,9 +206,6 @@ class Query extends AbstractQuery {
if (this.isShowIndexesQuery()) { if (this.isShowIndexesQuery()) {
return this.handleShowIndexesQuery(data); return this.handleShowIndexesQuery(data);
} }
if (this.isUpsertQuery()) {
return data[0];
}
if (this.isCallQuery()) { if (this.isCallQuery()) {
return data[0]; return data[0];
} }
...@@ -224,6 +221,9 @@ class Query extends AbstractQuery { ...@@ -224,6 +221,9 @@ class Query extends AbstractQuery {
if (this.isForeignKeysQuery()) { if (this.isForeignKeysQuery()) {
return data; return data;
} }
if (this.isUpsertQuery()) {
return [result, data[0].$action === 'INSERT'];
}
if (this.isInsertQuery() || this.isUpdateQuery()) { if (this.isInsertQuery() || this.isUpdateQuery()) {
return [result, rowCount]; return [result, rowCount];
} }
......
...@@ -293,17 +293,6 @@ class MySQLQueryGenerator extends AbstractQueryGenerator { ...@@ -293,17 +293,6 @@ class MySQLQueryGenerator extends AbstractQueryGenerator {
return value; return value;
} }
upsertQuery(tableName, insertValues, updateValues, where, model, options) {
options.onDuplicate = 'UPDATE ';
options.onDuplicate += Object.keys(updateValues).map(key => {
key = this.quoteIdentifier(key);
return `${key}=VALUES(${key})`;
}).join(', ');
return this.insertQuery(tableName, insertValues, model.rawAttributes, options);
}
truncateTableQuery(tableName) { truncateTableQuery(tableName) {
return `TRUNCATE ${this.quoteTable(tableName)}`; return `TRUNCATE ${this.quoteTable(tableName)}`;
} }
......
...@@ -2,6 +2,7 @@ ...@@ -2,6 +2,7 @@
const sequelizeErrors = require('../../errors'); const sequelizeErrors = require('../../errors');
const { QueryInterface } = require('../abstract/query-interface'); const { QueryInterface } = require('../abstract/query-interface');
const QueryTypes = require('../../query-types');
/** /**
* The interface that Sequelize uses to talk with MySQL/MariaDB database * The interface that Sequelize uses to talk with MySQL/MariaDB database
...@@ -40,6 +41,20 @@ class MySQLQueryInterface extends QueryInterface { ...@@ -40,6 +41,20 @@ class MySQLQueryInterface extends QueryInterface {
/** /**
* @override * @override
*/ */
async upsert(tableName, insertValues, updateValues, where, options) {
options = { ...options };
options.type = QueryTypes.UPSERT;
options.updateOnDuplicate = Object.keys(updateValues);
const model = options.model;
const sql = this.queryGenerator.insertQuery(tableName, insertValues, model.rawAttributes, options);
return await this.sequelize.query(sql, options);
}
/**
* @override
*/
async removeConstraint(tableName, constraintName, options) { async removeConstraint(tableName, constraintName, options) {
const sql = this.queryGenerator.showConstraintsQuery( const sql = this.queryGenerator.showConstraintsQuery(
tableName.tableName ? tableName : { tableName.tableName ? tableName : {
...@@ -69,13 +84,6 @@ class MySQLQueryInterface extends QueryInterface { ...@@ -69,13 +84,6 @@ class MySQLQueryInterface extends QueryInterface {
return await this.sequelize.query(query, options); return await this.sequelize.query(query, options);
} }
/**
* @override
*/
_convertUpsertResult(result) {
return [result === 1, undefined];
}
} }
exports.MySQLQueryInterface = MySQLQueryInterface; exports.MySQLQueryInterface = MySQLQueryInterface;
...@@ -138,7 +138,7 @@ class Query extends AbstractQuery { ...@@ -138,7 +138,7 @@ class Query extends AbstractQuery {
if (this.isCallQuery()) { if (this.isCallQuery()) {
return data[0]; return data[0];
} }
if (this.isBulkUpdateQuery() || this.isBulkDeleteQuery() || this.isUpsertQuery()) { if (this.isBulkUpdateQuery() || this.isBulkDeleteQuery()) {
return data.affectedRows; return data.affectedRows;
} }
if (this.isVersionQuery()) { if (this.isVersionQuery()) {
...@@ -147,6 +147,9 @@ class Query extends AbstractQuery { ...@@ -147,6 +147,9 @@ class Query extends AbstractQuery {
if (this.isForeignKeysQuery()) { if (this.isForeignKeysQuery()) {
return data; return data;
} }
if (this.isUpsertQuery()) {
return [result, data.affectedRows === 1];
}
if (this.isInsertQuery() || this.isUpdateQuery()) { if (this.isInsertQuery() || this.isUpdateQuery()) {
return [result, data.affectedRows]; return [result, data.affectedRows];
} }
......
...@@ -343,26 +343,6 @@ class PostgresQueryGenerator extends AbstractQueryGenerator { ...@@ -343,26 +343,6 @@ class PostgresQueryGenerator extends AbstractQueryGenerator {
return this.fn(fnName, tableName, parameters, body, returns, language); return this.fn(fnName, tableName, parameters, body, returns, language);
} }
upsertQuery(tableName, insertValues, updateValues, where, model, options) {
const primaryField = this.quoteIdentifier(model.primaryKeyField);
const upsertOptions = { ...options, bindParam: false, returning: ['*'] };
const insert = this.insertQuery(tableName, insertValues, model.rawAttributes, upsertOptions);
const update = this.updateQuery(tableName, updateValues, where, upsertOptions, model.rawAttributes);
const returningRegex = /RETURNING \*(?![\s\S]*RETURNING \*)/;
insert.query = insert.query.replace(returningRegex, `RETURNING ${primaryField} INTO primary_key`);
update.query = update.query.replace(returningRegex, `RETURNING ${primaryField} INTO primary_key`);
return this.exceptionFn(
'sequelize_upsert',
tableName,
'OUT created boolean, OUT primary_key text',
`${insert.query} created := true;`,
`${update.query}; created := false`
);
}
truncateTableQuery(tableName, options = {}) { truncateTableQuery(tableName, options = {}) {
return [ return [
`TRUNCATE ${this.quoteTable(tableName)}`, `TRUNCATE ${this.quoteTable(tableName)}`,
......
...@@ -241,13 +241,6 @@ class PostgresQueryInterface extends QueryInterface { ...@@ -241,13 +241,6 @@ class PostgresQueryInterface extends QueryInterface {
await Promise.all(promises); await Promise.all(promises);
} }
/**
* @override
*/
_convertUpsertResult(result) {
return [result.created, result.primary_key];
}
} }
exports.PostgresQueryInterface = PostgresQueryInterface; exports.PostgresQueryInterface = PostgresQueryInterface;
...@@ -262,10 +262,7 @@ class Query extends AbstractQuery { ...@@ -262,10 +262,7 @@ class Query extends AbstractQuery {
if (QueryTypes.BULKDELETE === this.options.type) { if (QueryTypes.BULKDELETE === this.options.type) {
return parseInt(rowCount, 10); return parseInt(rowCount, 10);
} }
if (this.isUpsertQuery()) { if (this.isInsertQuery() || this.isUpdateQuery() || this.isUpsertQuery()) {
return rows[0];
}
if (this.isInsertQuery() || this.isUpdateQuery()) {
if (this.instance && this.instance.dataValues) { if (this.instance && this.instance.dataValues) {
for (const key in rows[0]) { for (const key in rows[0]) {
if (Object.prototype.hasOwnProperty.call(rows[0], key)) { if (Object.prototype.hasOwnProperty.call(rows[0], key)) {
...@@ -278,6 +275,13 @@ class Query extends AbstractQuery { ...@@ -278,6 +275,13 @@ class Query extends AbstractQuery {
} }
} }
if (this.isUpsertQuery()) {
return [
this.instance,
null
];
}
return [ return [
this.instance || rows && (this.options.plain && rows[0] || rows) || undefined, this.instance || rows && (this.options.plain && rows[0] || rows) || undefined,
rowCount rowCount
......
...@@ -179,21 +179,6 @@ class SQLiteQueryGenerator extends MySqlQueryGenerator { ...@@ -179,21 +179,6 @@ class SQLiteQueryGenerator extends MySqlQueryGenerator {
return 'SELECT name FROM `sqlite_master` WHERE type=\'table\' and name!=\'sqlite_sequence\';'; return 'SELECT name FROM `sqlite_master` WHERE type=\'table\' and name!=\'sqlite_sequence\';';
} }
upsertQuery(tableName, insertValues, updateValues, where, model, options) {
options.ignoreDuplicates = true;
const bind = [];
const bindParam = this.bindParam(bind);
const upsertOptions = { ...options, bindParam };
const insert = this.insertQuery(tableName, insertValues, model.rawAttributes, upsertOptions);
const update = this.updateQuery(tableName, updateValues, where, upsertOptions, model.rawAttributes);
const query = `${insert.query} ${update.query}`;
return { query, bind };
}
updateQuery(tableName, attrValueHash, where, options, attributes) { updateQuery(tableName, attrValueHash, where, options, attributes) {
options = options || {}; options = options || {};
_.defaults(options, this.options); _.defaults(options, this.options);
......
...@@ -201,15 +201,15 @@ class Query extends AbstractQuery { ...@@ -201,15 +201,15 @@ class Query extends AbstractQuery {
if ([QueryTypes.BULKUPDATE, QueryTypes.BULKDELETE].includes(this.options.type)) { if ([QueryTypes.BULKUPDATE, QueryTypes.BULKDELETE].includes(this.options.type)) {
return metaData.changes; return metaData.changes;
} }
if (this.options.type === QueryTypes.UPSERT) {
return undefined;
}
if (this.options.type === QueryTypes.VERSION) { if (this.options.type === QueryTypes.VERSION) {
return results[0].version; return results[0].version;
} }
if (this.options.type === QueryTypes.RAW) { if (this.options.type === QueryTypes.RAW) {
return [results, metaData]; return [results, metaData];
} }
if (this.isUpsertQuery()) {
return [result, null];
}
if (this.isUpdateQuery() || this.isInsertQuery()) { if (this.isUpdateQuery() || this.isInsertQuery()) {
return [result, metaData.changes]; return [result, metaData.changes];
} }
...@@ -230,7 +230,6 @@ class Query extends AbstractQuery { ...@@ -230,7 +230,6 @@ class Query extends AbstractQuery {
complete = this._logQuery(sql, debug, parameters); complete = this._logQuery(sql, debug, parameters);
} }
return new Promise((resolve, reject) => conn.serialize(async () => { return new Promise((resolve, reject) => conn.serialize(async () => {
const columnTypes = {}; const columnTypes = {};
const executeSql = () => { const executeSql = () => {
......
...@@ -2395,40 +2395,42 @@ class Model { ...@@ -2395,40 +2395,42 @@ class Model {
* *
* **Implementation details:** * **Implementation details:**
* *
* * MySQL - Implemented as a single query `INSERT values ON DUPLICATE KEY UPDATE values` * * MySQL - Implemented with ON DUPLICATE KEY UPDATE`
* * PostgreSQL - Implemented as a temporary function with exception handling: INSERT EXCEPTION WHEN unique_constraint UPDATE * * PostgreSQL - Implemented with ON CONFLICT DO UPDATE. If update data contains PK field, then PK is selected as the default conflict key. Otherwise first unique constraint/index will be selected, which can satisfy conflict key requirements.
* * SQLite - Implemented as two queries `INSERT; UPDATE`. This means that the update is executed regardless of whether the row already existed or not * * SQLite - Implemented with ON CONFLICT DO UPDATE
* * MSSQL - Implemented as a single query using `MERGE` and `WHEN (NOT) MATCHED THEN` * * MSSQL - Implemented as a single query using `MERGE` and `WHEN (NOT) MATCHED THEN`
* **Note** that SQLite returns undefined for created, no matter if the row was created or updated. This is because SQLite always runs INSERT OR IGNORE + UPDATE, in a single query, so there is no way to know whether the row was inserted or not. *
* **Note** that Postgres/SQLite returns null for created, no matter if the row was created or updated
* *
* @param {object} values hash of values to upsert * @param {object} values hash of values to upsert
* @param {object} [options] upsert options * @param {object} [options] upsert options
* @param {boolean} [options.validate=true] Run validations before the row is inserted * @param {boolean} [options.validate=true] Run validations before the row is inserted
* @param {Array} [options.fields=Object.keys(this.attributes)] The fields to insert / update. Defaults to all changed fields * @param {Array} [options.fields=Object.keys(this.attributes)] The fields to insert / update. Defaults to all changed fields
* @param {boolean} [options.hooks=true] Run before / after upsert hooks? * @param {boolean} [options.hooks=true] Run before / after upsert hooks?
* @param {boolean} [options.returning=false] If true, fetches back auto generated values (Postgres only) * @param {boolean} [options.returning=true] If true, fetches back auto generated values
* @param {Transaction} [options.transaction] Transaction to run query under * @param {Transaction} [options.transaction] Transaction to run query under
* @param {Function} [options.logging=false] A function that gets executed while running the query to log the sql. * @param {Function} [options.logging=false] A function that gets executed while running the query to log the sql.
* @param {boolean} [options.benchmark=false] Pass query execution time in milliseconds as second argument to logging function (options.logging). * @param {boolean} [options.benchmark=false] Pass query execution time in milliseconds as second argument to logging function (options.logging).
* @param {string} [options.searchPath=DEFAULT] An optional parameter to specify the schema search_path (Postgres only) * @param {string} [options.searchPath=DEFAULT] An optional parameter to specify the schema search_path (Postgres only)
* *
* @returns {Promise<boolean>} Returns a boolean indicating whether the row was created or updated. For MySQL/MariaDB, it returns `true` when inserted and `false` when updated. For Postgres/MSSQL with `options.returning` true, it returns record and created boolean with signature `<Model, created>`. * @returns {Promise<Model,boolean | null>} returns record and whether row was created or updated as boolean. For Postgres/SQLite dialects boolean value is always null`.
*/ */
static async upsert(values, options) { static async upsert(values, options) {
options = { options = {
hooks: true, hooks: true,
returning: false, returning: true,
validate: true, validate: true,
...Utils.cloneDeep(options) ...Utils.cloneDeep(options)
}; };
options.model = this;
const createdAtAttr = this._timestampAttributes.createdAt; const createdAtAttr = this._timestampAttributes.createdAt;
const updatedAtAttr = this._timestampAttributes.updatedAt; const updatedAtAttr = this._timestampAttributes.updatedAt;
const hasPrimary = this.primaryKeyField in values || this.primaryKeyAttribute in values; const hasPrimary = this.primaryKeyField in values || this.primaryKeyAttribute in values;
const instance = this.build(values); const instance = this.build(values);
options.model = this;
options.instance = instance;
const changed = Array.from(instance._changed); const changed = Array.from(instance._changed);
if (!options.fields) { if (!options.fields) {
options.fields = changed; options.fields = changed;
...@@ -2463,14 +2465,7 @@ class Model { ...@@ -2463,14 +2465,7 @@ class Model {
if (options.hooks) { if (options.hooks) {
await this.runHooks('beforeUpsert', values, options); await this.runHooks('beforeUpsert', values, options);
} }
const [created, primaryKey] = await this.queryInterface.upsert(this.getTableName(options), insertValues, updateValues, instance.where(), this, options); const result = await this.queryInterface.upsert(this.getTableName(options), insertValues, updateValues, instance.where(), options);
let result;
if (options.returning === true && primaryKey) {
const record = await this.findByPk(primaryKey, options);
result = [record, created];
} else {
result = created;
}
if (options.hooks) { if (options.hooks) {
await this.runHooks('afterUpsert', result, options); await this.runHooks('afterUpsert', result, options);
......
...@@ -31,6 +31,7 @@ module.exports = { ...@@ -31,6 +31,7 @@ module.exports = {
port: env.SEQ_MSSQL_PORT || env.SEQ_PORT || 1433, port: env.SEQ_MSSQL_PORT || env.SEQ_PORT || 1433,
dialectOptions: { dialectOptions: {
options: { options: {
encrypt: false,
requestTimeout: 60000 requestTimeout: 60000
} }
}, },
......
...@@ -60,19 +60,19 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -60,19 +60,19 @@ describe(Support.getTestDialectTeaser('Model'), () => {
if (current.dialect.supports.upserts) { if (current.dialect.supports.upserts) {
describe('upsert', () => { describe('upsert', () => {
it('works with upsert on id', async function() { it('works with upsert on id', async function() {
const created0 = await this.User.upsert({ id: 42, username: 'john' }); const [, created0] = await this.User.upsert({ id: 42, username: 'john' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created0).to.be.undefined; expect(created0).to.be.null;
} else { } else {
expect(created0).to.be.ok; expect(created0).to.be.true;
} }
this.clock.tick(1000); this.clock.tick(1000);
const created = await this.User.upsert({ id: 42, username: 'doe' }); const [, created] = await this.User.upsert({ id: 42, username: 'doe' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.undefined; expect(created).to.be.null;
} else { } else {
expect(created).not.to.be.ok; expect(created).to.be.false;
} }
const user = await this.User.findByPk(42); const user = await this.User.findByPk(42);
...@@ -82,19 +82,19 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -82,19 +82,19 @@ describe(Support.getTestDialectTeaser('Model'), () => {
}); });
it('works with upsert on a composite key', async function() { it('works with upsert on a composite key', async function() {
const created0 = await this.User.upsert({ foo: 'baz', bar: 19, username: 'john' }); const [, created0] = await this.User.upsert({ foo: 'baz', bar: 19, username: 'john' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created0).to.be.undefined; expect(created0).to.be.null;
} else { } else {
expect(created0).to.be.ok; expect(created0).to.be.true;
} }
this.clock.tick(1000); this.clock.tick(1000);
const created = await this.User.upsert({ foo: 'baz', bar: 19, username: 'doe' }); const [, created] = await this.User.upsert({ foo: 'baz', bar: 19, username: 'doe' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.undefined; expect(created).to.be.null;
} else { } else {
expect(created).not.to.be.ok; expect(created).to.be.false;
} }
const user = await this.User.findOne({ where: { foo: 'baz', bar: 19 } }); const user = await this.User.findOne({ where: { foo: 'baz', bar: 19 } });
...@@ -112,14 +112,12 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -112,14 +112,12 @@ describe(Support.getTestDialectTeaser('Model'), () => {
type: Sequelize.UUID, type: Sequelize.UUID,
defaultValue: Sequelize.UUIDV4 defaultValue: Sequelize.UUIDV4
}, },
name: { name: {
type: Sequelize.STRING type: Sequelize.STRING
} }
}); });
await User.sync({ force: true }); await User.sync({ force: true });
await User.upsert({ name: 'John Doe' }); await User.upsert({ name: 'John Doe' });
}); });
...@@ -144,21 +142,21 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -144,21 +142,21 @@ describe(Support.getTestDialectTeaser('Model'), () => {
User.upsert({ a: 'a', b: 'a', username: 'curt' }) User.upsert({ a: 'a', b: 'a', username: 'curt' })
]); ]);
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created1).to.be.undefined; expect(created1[1]).to.be.null;
expect(created2).to.be.undefined; expect(created2[1]).to.be.null;
} else { } else {
expect(created1).to.be.ok; expect(created1[1]).to.be.true;
expect(created2).to.be.ok; expect(created2[1]).to.be.true;
} }
this.clock.tick(1000); this.clock.tick(1000);
// Update the first one // Update the first one
const created = await User.upsert({ a: 'a', b: 'b', username: 'doe' }); const [, created] = await User.upsert({ a: 'a', b: 'b', username: 'doe' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.undefined; expect(created).to.be.null;
} else { } else {
expect(created).not.to.be.ok; expect(created).to.be.false;
} }
const user1 = await User.findOne({ where: { a: 'a', b: 'b' } }); const user1 = await User.findOne({ where: { a: 'a', b: 'b' } });
...@@ -199,28 +197,28 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -199,28 +197,28 @@ describe(Support.getTestDialectTeaser('Model'), () => {
const options = { validate: false }; const options = { validate: false };
await User.sync({ force: true }); await User.sync({ force: true });
const created = await User.upsert({ id: 1, email: 'notanemail' }, options); const [, created] = await User.upsert({ id: 1, email: 'notanemail' }, options);
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.undefined; expect(created).to.be.null;
} else { } else {
expect(created).to.be.ok; expect(created).to.be.true;
} }
}); });
it('works with BLOBs', async function() { it('works with BLOBs', async function() {
const created0 = await this.User.upsert({ id: 42, username: 'john', blob: Buffer.from('kaj') }); const [, created0] = await this.User.upsert({ id: 42, username: 'john', blob: Buffer.from('kaj') });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created0).to.be.undefined; expect(created0).to.be.null;
} else { } else {
expect(created0).to.be.ok; expect(created0).to.be.ok;
} }
this.clock.tick(1000); this.clock.tick(1000);
const created = await this.User.upsert({ id: 42, username: 'doe', blob: Buffer.from('andrea') }); const [, created] = await this.User.upsert({ id: 42, username: 'doe', blob: Buffer.from('andrea') });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.undefined; expect(created).to.be.null;
} else { } else {
expect(created).not.to.be.ok; expect(created).to.be.false;
} }
const user = await this.User.findByPk(42); const user = await this.User.findByPk(42);
...@@ -231,18 +229,18 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -231,18 +229,18 @@ describe(Support.getTestDialectTeaser('Model'), () => {
}); });
it('works with .field', async function() { it('works with .field', async function() {
const created0 = await this.User.upsert({ id: 42, baz: 'foo' }); const [, created0] = await this.User.upsert({ id: 42, baz: 'foo' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created0).to.be.undefined; expect(created0).to.be.null;
} else { } else {
expect(created0).to.be.ok; expect(created0).to.be.ok;
} }
const created = await this.User.upsert({ id: 42, baz: 'oof' }); const [, created] = await this.User.upsert({ id: 42, baz: 'oof' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.undefined; expect(created).to.be.null;
} else { } else {
expect(created).not.to.be.ok; expect(created).to.be.false;
} }
const user = await this.User.findByPk(42); const user = await this.User.findByPk(42);
...@@ -250,19 +248,19 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -250,19 +248,19 @@ describe(Support.getTestDialectTeaser('Model'), () => {
}); });
it('works with primary key using .field', async function() { it('works with primary key using .field', async function() {
const created0 = await this.ModelWithFieldPK.upsert({ userId: 42, foo: 'first' }); const [, created0] = await this.ModelWithFieldPK.upsert({ userId: 42, foo: 'first' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created0).to.be.undefined; expect(created0).to.be.null;
} else { } else {
expect(created0).to.be.ok; expect(created0).to.be.ok;
} }
this.clock.tick(1000); this.clock.tick(1000);
const created = await this.ModelWithFieldPK.upsert({ userId: 42, foo: 'second' }); const [, created] = await this.ModelWithFieldPK.upsert({ userId: 42, foo: 'second' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.undefined; expect(created).to.be.null;
} else { } else {
expect(created).not.to.be.ok; expect(created).to.be.false;
} }
const instance = await this.ModelWithFieldPK.findOne({ where: { userId: 42 } }); const instance = await this.ModelWithFieldPK.findOne({ where: { userId: 42 } });
...@@ -270,19 +268,19 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -270,19 +268,19 @@ describe(Support.getTestDialectTeaser('Model'), () => {
}); });
it('works with database functions', async function() { it('works with database functions', async function() {
const created0 = await this.User.upsert({ id: 42, username: 'john', foo: this.sequelize.fn('upper', 'mixedCase1') }); const [, created0] = await this.User.upsert({ id: 42, username: 'john', foo: this.sequelize.fn('upper', 'mixedCase1') });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created0).to.be.undefined; expect(created0).to.be.null;
} else { } else {
expect(created0).to.be.ok; expect(created0).to.be.ok;
} }
this.clock.tick(1000); this.clock.tick(1000);
const created = await this.User.upsert({ id: 42, username: 'doe', foo: this.sequelize.fn('upper', 'mixedCase2') }); const [, created] = await this.User.upsert({ id: 42, username: 'doe', foo: this.sequelize.fn('upper', 'mixedCase2') });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.undefined; expect(created).to.be.null;
} else { } else {
expect(created).not.to.be.ok; expect(created).to.be.false;
} }
const user = await this.User.findByPk(42); const user = await this.User.findByPk(42);
expect(user.createdAt).to.be.ok; expect(user.createdAt).to.be.ok;
...@@ -322,9 +320,9 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -322,9 +320,9 @@ describe(Support.getTestDialectTeaser('Model'), () => {
it('does not update when setting current values', async function() { it('does not update when setting current values', async function() {
await this.User.create({ id: 42, username: 'john' }); await this.User.create({ id: 42, username: 'john' });
const user = await this.User.findByPk(42); const user = await this.User.findByPk(42);
const created = await this.User.upsert({ id: user.id, username: user.username }); const [, created] = await this.User.upsert({ id: user.id, username: user.username });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.undefined; expect(created).to.be.null;
} else { } else {
// After set node-mysql flags = '-FOUND_ROWS' / foundRows=false // After set node-mysql flags = '-FOUND_ROWS' / foundRows=false
// result from upsert should be false when upsert a row to its current value // result from upsert should be false when upsert a row to its current value
...@@ -349,18 +347,18 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -349,18 +347,18 @@ describe(Support.getTestDialectTeaser('Model'), () => {
}); });
const clock = sinon.useFakeTimers(); const clock = sinon.useFakeTimers();
await User.sync({ force: true }); await User.sync({ force: true });
const created0 = await User.upsert({ username: 'user1', email: 'user1@domain.ext', city: 'City' }); const [, created0] = await User.upsert({ username: 'user1', email: 'user1@domain.ext', city: 'City' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created0).to.be.undefined; expect(created0).to.be.null;
} else { } else {
expect(created0).to.be.ok; expect(created0).to.be.ok;
} }
clock.tick(1000); clock.tick(1000);
const created = await User.upsert({ username: 'user1', email: 'user1@domain.ext', city: 'New City' }); const [, created] = await User.upsert({ username: 'user1', email: 'user1@domain.ext', city: 'New City' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.undefined; expect(created).to.be.null;
} else { } else {
expect(created).not.to.be.ok; expect(created).to.be.false;
} }
clock.tick(1000); clock.tick(1000);
const user = await User.findOne({ where: { username: 'user1', email: 'user1@domain.ext' } }); const user = await User.findOne({ where: { username: 'user1', email: 'user1@domain.ext' } });
...@@ -385,17 +383,17 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -385,17 +383,17 @@ describe(Support.getTestDialectTeaser('Model'), () => {
}); });
await User.sync({ force: true }); await User.sync({ force: true });
const created0 = await User.upsert({ username: 'user1', email: 'user1@domain.ext', city: 'City' }); const [, created0] = await User.upsert({ username: 'user1', email: 'user1@domain.ext', city: 'City' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created0).to.be.undefined; expect(created0).to.be.null;
} else { } else {
expect(created0).to.be.ok; expect(created0).to.be.ok;
} }
const created = await User.upsert({ username: 'user1', email: 'user1@domain.ext', city: 'New City' }); const [, created] = await User.upsert({ username: 'user1', email: 'user1@domain.ext', city: 'New City' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.undefined; expect(created).to.be.null;
} else { } else {
expect(created).not.to.be.ok; expect(created).to.be.false;
} }
const user = await User.findOne({ where: { username: 'user1', email: 'user1@domain.ext' } }); const user = await User.findOne({ where: { username: 'user1', email: 'user1@domain.ext' } });
expect(user.createdAt).to.be.ok; expect(user.createdAt).to.be.ok;
...@@ -415,15 +413,15 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -415,15 +413,15 @@ describe(Support.getTestDialectTeaser('Model'), () => {
}); });
await User.sync({ force: true }); await User.sync({ force: true });
const created0 = await User.upsert({ name: 'user1', address: 'address', city: 'City' }); const [, created0] = await User.upsert({ name: 'user1', address: 'address', city: 'City' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created0).to.be.undefined; expect(created0).to.be.null;
} else { } else {
expect(created0).to.be.ok; expect(created0).to.be.ok;
} }
const created = await User.upsert({ name: 'user1', address: 'address', city: 'New City' }); const [, created] = await User.upsert({ name: 'user1', address: 'address', city: 'New City' });
if (dialect === 'sqlite') { if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.undefined; expect(created).to.be.null;
} else { } else {
expect(created).not.to.be.ok; expect(created).not.to.be.ok;
} }
...@@ -498,12 +496,20 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -498,12 +496,20 @@ describe(Support.getTestDialectTeaser('Model'), () => {
const [user0, created0] = await this.User.upsert({ id: 42, username: 'john' }, { returning: true }); const [user0, created0] = await this.User.upsert({ id: 42, username: 'john' }, { returning: true });
expect(user0.get('id')).to.equal(42); expect(user0.get('id')).to.equal(42);
expect(user0.get('username')).to.equal('john'); expect(user0.get('username')).to.equal('john');
if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created0).to.be.null;
} else {
expect(created0).to.be.true; expect(created0).to.be.true;
}
const [user, created] = await this.User.upsert({ id: 42, username: 'doe' }, { returning: true }); const [user, created] = await this.User.upsert({ id: 42, username: 'doe' }, { returning: true });
expect(user.get('id')).to.equal(42); expect(user.get('id')).to.equal(42);
expect(user.get('username')).to.equal('doe'); expect(user.get('username')).to.equal('doe');
if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.null;
} else {
expect(created).to.be.false; expect(created).to.be.false;
}
}); });
it('works for table with custom primary key field', async function() { it('works for table with custom primary key field', async function() {
...@@ -523,12 +529,20 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -523,12 +529,20 @@ describe(Support.getTestDialectTeaser('Model'), () => {
const [user0, created0] = await User.upsert({ id: 42, username: 'john' }, { returning: true }); const [user0, created0] = await User.upsert({ id: 42, username: 'john' }, { returning: true });
expect(user0.get('id')).to.equal(42); expect(user0.get('id')).to.equal(42);
expect(user0.get('username')).to.equal('john'); expect(user0.get('username')).to.equal('john');
if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created0).to.be.null;
} else {
expect(created0).to.be.true; expect(created0).to.be.true;
}
const [user, created] = await User.upsert({ id: 42, username: 'doe' }, { returning: true }); const [user, created] = await User.upsert({ id: 42, username: 'doe' }, { returning: true });
expect(user.get('id')).to.equal(42); expect(user.get('id')).to.equal(42);
expect(user.get('username')).to.equal('doe'); expect(user.get('username')).to.equal('doe');
if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.null;
} else {
expect(created).to.be.false; expect(created).to.be.false;
}
}); });
it('works for non incrementing primaryKey', async function() { it('works for non incrementing primaryKey', async function() {
...@@ -547,12 +561,20 @@ describe(Support.getTestDialectTeaser('Model'), () => { ...@@ -547,12 +561,20 @@ describe(Support.getTestDialectTeaser('Model'), () => {
const [user0, created0] = await User.upsert({ id: 'surya', username: 'john' }, { returning: true }); const [user0, created0] = await User.upsert({ id: 'surya', username: 'john' }, { returning: true });
expect(user0.get('id')).to.equal('surya'); expect(user0.get('id')).to.equal('surya');
expect(user0.get('username')).to.equal('john'); expect(user0.get('username')).to.equal('john');
if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created0).to.be.null;
} else {
expect(created0).to.be.true; expect(created0).to.be.true;
}
const [user, created] = await User.upsert({ id: 'surya', username: 'doe' }, { returning: true }); const [user, created] = await User.upsert({ id: 'surya', username: 'doe' }, { returning: true });
expect(user.get('id')).to.equal('surya'); expect(user.get('id')).to.equal('surya');
expect(user.get('username')).to.equal('doe'); expect(user.get('username')).to.equal('doe');
if (dialect === 'sqlite' || dialect === 'postgres') {
expect(created).to.be.null;
} else {
expect(created).to.be.false; expect(created).to.be.false;
}
}); });
}); });
} }
......
...@@ -1094,29 +1094,6 @@ if (dialect.startsWith('postgres')) { ...@@ -1094,29 +1094,6 @@ if (dialect.startsWith('postgres')) {
} }
], ],
upsertQuery: [
{
arguments: [
'myTable',
{ name: 'foo' },
{ name: 'foo' },
{ id: 2 },
{ primaryKeyField: 'id' }
],
expectation: 'CREATE OR REPLACE FUNCTION pg_temp.sequelize_upsert(OUT created boolean, OUT primary_key text) AS $func$ BEGIN INSERT INTO "myTable" ("name") VALUES (\'foo\') RETURNING "id" INTO primary_key; created := true; EXCEPTION WHEN unique_violation THEN UPDATE "myTable" SET "name"=\'foo\' WHERE "id" = 2 RETURNING "id" INTO primary_key; created := false; END; $func$ LANGUAGE plpgsql; SELECT * FROM pg_temp.sequelize_upsert();'
},
{
arguments: [
'myTable',
{ name: 'RETURNING *', json: '{"foo":"RETURNING *"}' },
{ name: 'RETURNING *', json: '{"foo":"RETURNING *"}' },
{ id: 2 },
{ primaryKeyField: 'id' }
],
expectation: 'CREATE OR REPLACE FUNCTION pg_temp.sequelize_upsert(OUT created boolean, OUT primary_key text) AS $func$ BEGIN INSERT INTO "myTable" ("name","json") VALUES (\'RETURNING *\',\'{"foo":"RETURNING *"}\') RETURNING "id" INTO primary_key; created := true; EXCEPTION WHEN unique_violation THEN UPDATE "myTable" SET "name"=\'RETURNING *\',"json"=\'{"foo":"RETURNING *"}\' WHERE "id" = 2 RETURNING "id" INTO primary_key; created := false; END; $func$ LANGUAGE plpgsql; SELECT * FROM pg_temp.sequelize_upsert();'
}
],
removeIndexQuery: [ removeIndexQuery: [
{ {
arguments: ['User', 'user_foo_bar'], arguments: ['User', 'user_foo_bar'],
......
...@@ -705,7 +705,7 @@ export interface UpsertOptions extends Logging, Transactionable, SearchPathable, ...@@ -705,7 +705,7 @@ export interface UpsertOptions extends Logging, Transactionable, SearchPathable,
fields?: string[]; fields?: string[];
/** /**
* Return the affected rows (only for postgres) * Return the affected rows
*/ */
returning?: boolean; returning?: boolean;
...@@ -1959,28 +1959,18 @@ export abstract class Model<T = any, T2 = any> extends Hooks { ...@@ -1959,28 +1959,18 @@ export abstract class Model<T = any, T2 = any> extends Hooks {
* *
* **Implementation details:** * **Implementation details:**
* *
* * MySQL - Implemented as a single query `INSERT values ON DUPLICATE KEY UPDATE values` * * MySQL - Implemented with ON DUPLICATE KEY UPDATE
* * PostgreSQL - Implemented as a temporary function with exception handling: INSERT EXCEPTION WHEN * * PostgreSQL - Implemented with ON CONFLICT DO UPDATE
* unique_constraint UPDATE * * SQLite - Implemented with ON CONFLICT DO UPDATE
* * SQLite - Implemented as two queries `INSERT; UPDATE`. This means that the update is executed * * MSSQL - Implemented with MERGE statement
* regardless
* of whether the row already existed or not
* *
* **Note** that SQLite returns undefined for created, no matter if the row was created or updated. This is * **Note** that PostgreSQL/SQLite returns null for created, no matter if the row was created or updated.
* because SQLite always runs INSERT OR IGNORE + UPDATE, in a single query, so there is no way to know
* whether the row was inserted or not.
*/ */
public static upsert<M extends Model>( public static upsert<M extends Model>(
this: { new(): M } & typeof Model, this: { new(): M } & typeof Model,
values: object, values: object,
options?: UpsertOptions & { returning?: false | undefined } options?: UpsertOptions
): Promise<boolean>; ): Promise<[M, boolean | null]>;
public static upsert<M extends Model>(
this: { new(): M } & typeof Model,
values: object,
options?: UpsertOptions & { returning: true }
): Promise<[M, boolean]>;
/** /**
* Create and insert multiple instances in bulk. * Create and insert multiple instances in bulk.
......
...@@ -7,7 +7,7 @@ class TestModel extends Model { ...@@ -7,7 +7,7 @@ class TestModel extends Model {
TestModel.init({}, {sequelize}) TestModel.init({}, {sequelize})
sequelize.transaction(async trx => { sequelize.transaction(async trx => {
const res: [TestModel, boolean] = await TestModel.upsert<TestModel>({}, { const res1: [TestModel, boolean | null] = await TestModel.upsert<TestModel>({}, {
benchmark: true, benchmark: true,
fields: ['testField'], fields: ['testField'],
hooks: true, hooks: true,
...@@ -18,7 +18,7 @@ sequelize.transaction(async trx => { ...@@ -18,7 +18,7 @@ sequelize.transaction(async trx => {
validate: true, validate: true,
}); });
let created: boolean = await TestModel.upsert<TestModel>({}, { const res2: [TestModel, boolean | null] = await TestModel.upsert<TestModel>({}, {
benchmark: true, benchmark: true,
fields: ['testField'], fields: ['testField'],
hooks: true, hooks: true,
...@@ -29,7 +29,7 @@ sequelize.transaction(async trx => { ...@@ -29,7 +29,7 @@ sequelize.transaction(async trx => {
validate: true, validate: true,
}); });
created = await TestModel.upsert<TestModel>({}, { const res3: [TestModel, boolean | null] = await TestModel.upsert<TestModel>({}, {
benchmark: true, benchmark: true,
fields: ['testField'], fields: ['testField'],
hooks: true, hooks: true,
......
Markdown is supported
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!