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

Commit fc93889d by shakib bawa

adds support for table triggers in mssql dialect

- closes https://github.com/sequelize/sequelize/issues/3284
- closes https://github.com/sequelize/sequelize/issues/3967
- adds a temp table to get the output rows of insert,update and delete queries when there is a trigger on a table.
- Sits behind a flag called hasTrigger on the model
- Added tests that cover insert,update and delete queries
- using dialect support for temp tables to handle triggers
- increases enum column size in mssql to 255
1 parent 938aaf50
...@@ -173,16 +173,24 @@ var QueryGenerator = { ...@@ -173,16 +173,24 @@ var QueryGenerator = {
insertQuery: function(table, valueHash, modelAttributes, options) { insertQuery: function(table, valueHash, modelAttributes, options) {
options = options || {}; options = options || {};
var query var query
, valueQuery = 'INSERT<%= ignore %> INTO <%= table %> (<%= attributes %>)<%= output %> VALUES (<%= values %>)' , valueQuery = '<%= tmpTable %>INSERT<%= ignore %> INTO <%= table %> (<%= attributes %>)<%= output %> VALUES (<%= values %>)'
, emptyQuery = 'INSERT<%= ignore %> INTO <%= table %><%= output %>' , emptyQuery = '<%= tmpTable %>INSERT<%= ignore %> INTO <%= table %><%= output %>'
, outputFragment , outputFragment
, fields = [] , fields = []
, values = [] , values = []
, key , key
, value , value
, identityWrapperRequired = false , identityWrapperRequired = false
, modelAttributeMap = {}; , modelAttributeMap = {}
, tmpTable = '' //tmpTable declaration for trigger
, selectFromTmp = '' //Select statement for trigger
, tmpColumns = '' //Columns for temp table for trigger
, outputColumns = '' //Columns to capture into temp table for trigger
, attribute //Model attribute holder
, modelKey; //key for model
if (modelAttributes) { if (modelAttributes) {
Utils._.each(modelAttributes, function(attribute, key) { Utils._.each(modelAttributes, function(attribute, key) {
...@@ -205,6 +213,35 @@ var QueryGenerator = { ...@@ -205,6 +213,35 @@ var QueryGenerator = {
emptyQuery += ' RETURNING *'; emptyQuery += ' RETURNING *';
} else if (!!this._dialect.supports.returnValues.output) { } else if (!!this._dialect.supports.returnValues.output) {
outputFragment = ' OUTPUT INSERTED.*'; outputFragment = ' OUTPUT INSERTED.*';
//To capture output rows when there is a trigger on MSSQL DB
if (modelAttributes && options.hasTrigger && this._dialect.supports.tmpTableTrigger) {
tmpTable = 'declare @tmp table (<%= columns %>); ';
for (modelKey in modelAttributes){
attribute = modelAttributes[modelKey];
if(!(attribute.type instanceof DataTypes.VIRTUAL)){
if (tmpColumns.length > 0){
tmpColumns += ',';
outputColumns += ',';
}
tmpColumns += this.quoteIdentifier(attribute.field) + ' ' + attribute.type.toSql();
outputColumns += 'INSERTED.' + this.quoteIdentifier(attribute.field);
}
}
var replacement ={
columns : tmpColumns
};
tmpTable = Utils._.template(tmpTable)(replacement).trim();
outputFragment = ' OUTPUT ' + outputColumns + ' into @tmp';
selectFromTmp = ';select * from @tmp';
valueQuery += selectFromTmp;
emptyQuery += selectFromTmp;
}
} }
} }
...@@ -261,7 +298,8 @@ var QueryGenerator = { ...@@ -261,7 +298,8 @@ var QueryGenerator = {
table: this.quoteTable(table), table: this.quoteTable(table),
attributes: fields.join(','), attributes: fields.join(','),
output: outputFragment, output: outputFragment,
values: values.join(',') values: values.join(','),
tmpTable: tmpTable
}; };
query = (replacements.attributes.length ? valueQuery : emptyQuery) + ';'; query = (replacements.attributes.length ? valueQuery : emptyQuery) + ';';
...@@ -303,9 +341,15 @@ var QueryGenerator = { ...@@ -303,9 +341,15 @@ var QueryGenerator = {
var query var query
, values = [] , values = []
, outputFragment , outputFragment
, modelAttributeMap = {}; , modelAttributeMap = {}
, tmpTable = '' //tmpTable declaration for trigger
, selectFromTmp = '' //Select statement for trigger
, tmpColumns = '' //Columns for temp table for trigger
, outputColumns = '' //Columns to capture into temp table for trigger
, attribute //Model attribute holder
, modelKey; //key for model
query = 'UPDATE <%= table %> SET <%= values %><%= output %> <%= where %>'; query = '<%= tmpTable %>UPDATE <%= table %> SET <%= values %><%= output %> <%= where %>';
if (this._dialect.supports['LIMIT ON UPDATE'] && options.limit) { if (this._dialect.supports['LIMIT ON UPDATE'] && options.limit) {
query += ' LIMIT ' + this.escape(options.limit) + ' '; query += ' LIMIT ' + this.escape(options.limit) + ' ';
...@@ -315,6 +359,34 @@ var QueryGenerator = { ...@@ -315,6 +359,34 @@ var QueryGenerator = {
if (!!this._dialect.supports.returnValues.output) { if (!!this._dialect.supports.returnValues.output) {
// we always need this for mssql // we always need this for mssql
outputFragment = ' OUTPUT INSERTED.*'; outputFragment = ' OUTPUT INSERTED.*';
//To capture output rows when there is a trigger on MSSQL DB
if (attributes && options.hasTrigger && this._dialect.supports.tmpTableTrigger) {
tmpTable = 'declare @tmp table (<%= columns %>); ';
for (modelKey in attributes){
attribute = attributes[modelKey];
if(!(attribute.type instanceof DataTypes.VIRTUAL)){
if (tmpColumns.length > 0){
tmpColumns += ',';
outputColumns += ',';
}
tmpColumns += this.quoteIdentifier(attribute.field) + ' ' + attribute.type.toSql();
outputColumns += 'INSERTED.' + this.quoteIdentifier(attribute.field);
}
}
var replacement ={
columns : tmpColumns
};
tmpTable = Utils._.template(tmpTable)(replacement).trim();
outputFragment = ' OUTPUT ' + outputColumns + ' into @tmp';
selectFromTmp = ';select * from @tmp';
query += selectFromTmp;
}
} else if (this._dialect.supports.returnValues && options.returning) { } else if (this._dialect.supports.returnValues && options.returning) {
query += ' RETURNING *'; query += ' RETURNING *';
} }
...@@ -345,7 +417,8 @@ var QueryGenerator = { ...@@ -345,7 +417,8 @@ var QueryGenerator = {
table: this.quoteTable(tableName), table: this.quoteTable(tableName),
values: values.join(','), values: values.join(','),
output: outputFragment, output: outputFragment,
where: this.whereQuery(where) where: this.whereQuery(where),
tmpTable: tmpTable
}; };
if (values.length === 0) { if (values.length === 0) {
......
...@@ -153,6 +153,10 @@ var FLOAT = function() { ...@@ -153,6 +153,10 @@ var FLOAT = function() {
}; };
util.inherits(FLOAT, BaseTypes.FLOAT); util.inherits(FLOAT, BaseTypes.FLOAT);
BaseTypes.ENUM.prototype.toSql = function() {
return 'VARCHAR(255)';
};
module.exports = { module.exports = {
BOOLEAN: BOOLEAN, BOOLEAN: BOOLEAN,
STRING: STRING, STRING: STRING,
...@@ -172,4 +176,4 @@ _.forIn(module.exports, function (DataType, key) { ...@@ -172,4 +176,4 @@ _.forIn(module.exports, function (DataType, key) {
return new DataType(oldType.options); return new DataType(oldType.options);
}; };
} }
}); });
\ No newline at end of file
...@@ -46,7 +46,8 @@ MssqlDialect.prototype.supports = _.merge(_.cloneDeep(Abstract.prototype.support ...@@ -46,7 +46,8 @@ MssqlDialect.prototype.supports = _.merge(_.cloneDeep(Abstract.prototype.support
type: true, type: true,
using: false, using: false,
}, },
NUMERIC: true NUMERIC: true,
tmpTableTrigger: true
}); });
MssqlDialect.prototype.Query = Query; MssqlDialect.prototype.Query = Query;
......
...@@ -354,7 +354,7 @@ var QueryGenerator = { ...@@ -354,7 +354,7 @@ var QueryGenerator = {
if (attribute.type.values && !attribute.values) attribute.values = attribute.type.values; if (attribute.type.values && !attribute.values) attribute.values = attribute.type.values;
// enums are a special case // enums are a special case
template = 'VARCHAR(10) NULL' /* + (attribute.allowNull ? 'NULL' : 'NOT NULL') */; template = attribute.type.toSql();
template += ' CHECK (' + attribute.field + ' IN(' + Utils._.map(attribute.values, function(value) { template += ' CHECK (' + attribute.field + ' IN(' + Utils._.map(attribute.values, function(value) {
return this.escape(value); return this.escape(value);
}.bind(this)).join(', ') + '))'; }.bind(this)).join(', ') + '))';
......
...@@ -497,10 +497,13 @@ QueryInterface.prototype.removeIndex = function(tableName, indexNameOrAttributes ...@@ -497,10 +497,13 @@ QueryInterface.prototype.removeIndex = function(tableName, indexNameOrAttributes
}; };
QueryInterface.prototype.insert = function(instance, tableName, values, options) { QueryInterface.prototype.insert = function(instance, tableName, values, options) {
options = options || {};
options.hasTrigger = instance && instance.Model.options.hasTrigger;
var sql = this.QueryGenerator.insertQuery(tableName, values, instance && instance.Model.rawAttributes, options); var sql = this.QueryGenerator.insertQuery(tableName, values, instance && instance.Model.rawAttributes, options);
options.type = QueryTypes.INSERT; options.type = QueryTypes.INSERT;
options.instance = instance; options.instance = instance;
return this.sequelize.query(sql, options).then(function(result) { return this.sequelize.query(sql, options).then(function(result) {
if (instance) result.isNewRecord = false; if (instance) result.isNewRecord = false;
return result; return result;
...@@ -589,11 +592,15 @@ QueryInterface.prototype.bulkInsert = function(tableName, records, options, attr ...@@ -589,11 +592,15 @@ QueryInterface.prototype.bulkInsert = function(tableName, records, options, attr
}; };
QueryInterface.prototype.update = function(instance, tableName, values, identifier, options) { QueryInterface.prototype.update = function(instance, tableName, values, identifier, options) {
options = options || {};
options.hasTrigger = !!(instance && instance.__options && instance.__options.hasTrigger);
var self = this var self = this
, restrict = false , restrict = false
, sql = self.QueryGenerator.updateQuery(tableName, values, identifier, options, instance.Model.rawAttributes); , sql = self.QueryGenerator.updateQuery(tableName, values, identifier, options, instance.Model.rawAttributes);
options = options || {};
options.type = QueryTypes.UPDATE; options.type = QueryTypes.UPDATE;
// Check for a restrict field // Check for a restrict field
......
'use strict';
var chai = require('chai')
, Sequelize = require('../../index')
, expect = chai.expect
, Support = require(__dirname + '/../support')
, current = Support.sequelize;
if (current.dialect.supports.tmpTableTrigger) {
describe(Support.getTestDialectTeaser('Model'), function() {
describe('trigger', function() {
var User;
var triggerQuery = 'create trigger User_ChangeTracking on [users] for insert,update, delete \n' +
'as\n' +
'SET NOCOUNT ON\n' +
'if exists(select 1 from inserted)\n' +
'begin\n' +
'select * from inserted\n' +
'end\n' +
'if exists(select 1 from deleted)\n' +
'begin\n' +
'select * from deleted\n' +
'end\n';
beforeEach(function () {
User = this.sequelize.define('user', {
username: {
type: Sequelize.STRING,
field:'user_name'
}
},{
hasTrigger:true
});
});
it('should return output rows after insert', function() {
return User.sync({force: true}).bind(this).then(function () {
return this.sequelize.query(triggerQuery,{type:this.sequelize.QueryTypes.RAW});
}).then(function(){
return User.create({
username: 'triggertest'
});
}).then(function () {
return User.find({username: 'triggertest'}).then(function(user) {
expect(user.username).to.equal('triggertest');
});
});
});
it('should return output rows after bulk insert', function() {
return User.sync({force: true}).bind(this).then(function () {
return this.sequelize.query(triggerQuery,{type:this.sequelize.QueryTypes.RAW});
}).then(function(){
return User.bulkCreate([
{username: 'shak'},
{username: 'mike'},
{username: 'blah'},
{username: 'argh'}]);
}).then(function () {
return User.findAll().then(function(users) {
expect(users.length).to.equal(4);
});
});
});
it('should return output rows after update', function() {
return User.sync({force: true}).bind(this).then(function () {
return this.sequelize.query(triggerQuery,{type:this.sequelize.QueryTypes.RAW});
}).then(function(){
return User.create({
username: 'triggertest'
});
})
.then(function(user){
user.username = 'usernamechanged';
return user.save();
})
.then(function (user) {
return User.find({username: 'usernamechanged'}).then(function(user) {
expect(user.username).to.equal('usernamechanged');
});
});
});
it('should successfully delete with a trigger on the table', function() {
return User.sync({force: true}).bind(this).then(function () {
return this.sequelize.query(triggerQuery,{type:this.sequelize.QueryTypes.RAW});
}).then(function(){
return User.create({
username: 'triggertest'
});
})
.then(function(user){
return user.destroy();
})
.then(function (user) {
return User.find({username: 'triggertest'}).then(function(user) {
/* jshint expr:true */
expect(user).to.be.null;
});
});
});
});
});
}
'use strict';
/* jshint -W110 */
var Support = require(__dirname + '/../support')
, DataTypes = require(__dirname + '/../../../lib/data-types')
, expectsql = Support.expectsql
, current = Support.sequelize
, sql = current.dialect.QueryGenerator;
// Notice: [] will be replaced by dialect specific tick/quote character when there is not dialect specific expectation but only a default expectation
describe(Support.getTestDialectTeaser('SQL'), function() {
describe('insert', function () {
it('with temp table for trigger', function () {
var User = Support.sequelize.define('user', {
username: {
type: DataTypes.STRING,
field:'user_name'
}
},{
timestamps:false,
hasTrigger:true
});
var options = {
returning : true,
hasTrigger : true
};
expectsql(sql.insertQuery(User.tableName,{user_name: 'triggertest'},User.rawAttributes,options),
{
mssql:'declare @tmp table ([id] INTEGER,[user_name] NVARCHAR(255));INSERT INTO [users] ([user_name]) OUTPUT INSERTED.[id],INSERTED.[user_name] into @tmp VALUES (\'triggertest\');select * from @tmp;',
postgres: 'INSERT INTO "users" ("user_name") VALUES (\'triggertest\') RETURNING *;',
default: "INSERT INTO `users` (`user_name`) VALUES ('triggertest');",
});
});
});
});
'use strict';
/* jshint -W110 */
var Support = require(__dirname + '/../support')
, DataTypes = require(__dirname + '/../../../lib/data-types')
, expectsql = Support.expectsql
, current = Support.sequelize
, sql = current.dialect.QueryGenerator;
// Notice: [] will be replaced by dialect specific tick/quote character when there is not dialect specific expectation but only a default expectation
describe(Support.getTestDialectTeaser('SQL'), function() {
describe('update', function () {
it('with temp table for trigger', function () {
var User = Support.sequelize.define('user', {
username: {
type: DataTypes.STRING,
field:'user_name'
}
},{
timestamps:false,
hasTrigger:true
});
var options = {
returning : true,
hasTrigger : true
};
expectsql(sql.updateQuery(User.tableName,{user_name: 'triggertest'},{id:2},options,User.rawAttributes),
{
mssql: 'declare @tmp table ([id] INTEGER,[user_name] NVARCHAR(255));UPDATE [users] SET [user_name]=\'triggertest\' OUTPUT INSERTED.[id],INSERTED.[user_name] into @tmp WHERE [id] = 2;select * from @tmp',
postgres:'UPDATE "users" SET "user_name"=\'triggertest\' WHERE "id" = 2 RETURNING *',
default: "UPDATE `users` SET `user_name`=\'triggertest\' WHERE `id` = 2",
});
});
});
});
Markdown is supported
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!