mssql limit and offset for sql2012

This commit is contained in:
Sky Morey 2015-12-15 14:56:56 -06:00
parent fbbda0731b
commit ae256f2943
4 changed files with 43 additions and 29 deletions

View File

@ -67,10 +67,10 @@ assign(QueryCompiler_MSSQL.prototype, {
var join = this.join();
var where = this.where();
var order = this.order();
var limit = this.limit_();
var top = this.top();
var returning = this.single.returning;
return {
sql: 'update ' + (limit ? limit + ' ' : '') + this.tableName + (join ? ' ' + join : '') + ' set ' + updates.join(', ') + (returning ? ' ' + this._returning('update', returning) : '') + (where ? ' ' + where : '') + (order ? ' ' + order : '') + (!returning ? this._returning('rowcount', '@@rowcount') : ''),
sql: 'update ' + (top ? top + ' ' : '') + this.tableName + (join ? ' ' + join : '') + ' set ' + updates.join(', ') + (returning ? ' ' + this._returning('update', returning) : '') + (where ? ' ' + where : '') + (order ? ' ' + order : '') + (!returning ? this._returning('rowcount', '@@rowcount') : ''),
returning: returning || '@@rowcount'
};
},
@ -106,8 +106,8 @@ assign(QueryCompiler_MSSQL.prototype, {
}
}
if (sql.length === 0) sql = ['*'];
var limit = this.limit_();
return 'select ' + (distinct ? 'distinct ' : '') + (limit ? limit + ' ' : '') + sql.join(', ') + (this.tableName ? ' from ' + this.tableName : '');
var top = this.top();
return 'select ' + (distinct ? 'distinct ' : '') + (top ? top + ' ' : '') + sql.join(', ') + (this.tableName ? ' from ' + this.tableName : '');
},
_returning: function _returning(method, value) {
@ -156,10 +156,11 @@ assign(QueryCompiler_MSSQL.prototype, {
};
},
limit_: function limit_() {
top: function top() {
var noLimit = !this.single.limit && this.single.limit !== 0;
if (noLimit) return '';
return 'top (' + this.formatter.parameter(this.single.limit) + ')';
var noOffset = !this.single.offset;
if (noLimit || !noOffset) return '';
return 'top ' + this.formatter.parameter(this.single.limit);
},
limit: function limit() {
@ -167,8 +168,14 @@ assign(QueryCompiler_MSSQL.prototype, {
},
offset: function offset() {
if (!this.single.offset) return '';
return 'offset ' + this.formatter.parameter(this.single.offset) + ' rows';
var noLimit = !this.single.limit && this.single.limit !== 0;
var noOffset = !this.single.offset;
if (noOffset) return '';
var offset = 'offset ' + (noOffset ? '0' : this.formatter.parameter(this.single.offset)) + ' rows';
if (!noLimit) {
offset += ' fetch next ' + this.formatter.parameter(this.single.limit) + ' rows only';
}
return offset;
}
});

View File

@ -65,10 +65,10 @@ assign(QueryCompiler_MSSQL.prototype, {
var join = this.join();
var where = this.where();
var order = this.order();
var limit = this.limit_();
var top = this.top();
var returning = this.single.returning;
return {
sql: 'update ' + (limit ? limit + ' ' : '') + this.tableName +
sql: 'update ' + (top ? top + ' ' : '') + this.tableName +
(join ? ' ' + join : '') +
' set ' + updates.join(', ') +
(returning ? ' ' + this._returning('update', returning) : '') +
@ -114,9 +114,9 @@ assign(QueryCompiler_MSSQL.prototype, {
}
}
if (sql.length === 0) sql = ['*'];
var limit = this.limit_();
var top = this.top();
return 'select ' + (distinct ? 'distinct ' : '') +
(limit ? limit + ' ' : '') +
(top ? top + ' ' : '') +
sql.join(', ') + (this.tableName ? ' from ' + this.tableName : '');
},
@ -163,10 +163,11 @@ assign(QueryCompiler_MSSQL.prototype, {
};
},
limit_: function() {
top: function() {
var noLimit = !this.single.limit && this.single.limit !== 0;
if (noLimit) return '';
return 'top (' + this.formatter.parameter(this.single.limit) + ')';
var noOffset = !this.single.offset;
if (noLimit || !noOffset) return '';
return 'top ' + this.formatter.parameter(this.single.limit);
},
limit: function() {
@ -174,10 +175,16 @@ assign(QueryCompiler_MSSQL.prototype, {
},
offset: function() {
if (!this.single.offset) return '';
return 'offset ' + this.formatter.parameter(this.single.offset) + ' rows';
var noLimit = !this.single.limit && this.single.limit !== 0;
var noOffset = !this.single.offset;
if (noOffset) return '';
var offset = 'offset ' + (noOffset ? '0' : this.formatter.parameter(this.single.offset)) + ' rows';
if (!noLimit) {
offset += ' fetch next ' + this.formatter.parameter(this.single.limit) + ' rows only';
}
return offset;
},
})
// Set the QueryBuilder & QueryCompiler on the client object,

View File

@ -115,7 +115,7 @@ module.exports = function(knex) {
);
tester(
'mssql',
'select top (?) [id], [first_name] from [accounts] order by [id] asc',
'select top ? [id], [first_name] from [accounts] order by [id] asc',
[1],
{ id: '1', first_name: 'Test' }
);

View File

@ -938,7 +938,7 @@ describe("QueryBuilder", function() {
bindings: [25, 3]
},
mssql: {
sql: 'select * from [users] where [id] in (select top (?) [id] from [users] where [age] > ?)',
sql: 'select * from [users] where [id] in (select top ? [id] from [users] where [age] > ?)',
bindings: [3, 25]
},
default: {
@ -1244,7 +1244,7 @@ describe("QueryBuilder", function() {
bindings: [10]
},
mssql: {
sql: 'select top (?) * from [users]',
sql: 'select top ? * from [users]',
bindings: [10]
},
default: {
@ -1265,7 +1265,7 @@ describe("QueryBuilder", function() {
bindings: [0]
},
mssql: {
sql: 'select top (?) * from [users]',
sql: 'select top ? * from [users]',
bindings: [0]
},
default: {
@ -1286,8 +1286,8 @@ describe("QueryBuilder", function() {
bindings: [15, 5]
},
mssql: {
sql: 'select top (?) * from [users] offset ? rows',
bindings: [10, 5]
sql: 'select * from [users] offset ? rows fetch next ? rows only',
bindings: [5, 10]
},
default: {
sql: 'select * from "users" limit ? offset ?',
@ -1307,7 +1307,7 @@ describe("QueryBuilder", function() {
bindings: [1]
},
mssql: {
sql: 'select top (?) * from [users]',
sql: 'select top ? * from [users]',
bindings: [1]
},
default: {
@ -2154,7 +2154,7 @@ describe("QueryBuilder", function() {
bindings: ['foo', 'bar', 1, 5]
},
mssql: {
sql: 'update top (?) [users] set [email] = ?, [name] = ? where [id] = ? order by [foo] desc;select @@rowcount',
sql: 'update top ? [users] set [email] = ?, [name] = ? where [id] = ? order by [foo] desc;select @@rowcount',
bindings: ['foo', 'bar', 1, 5]
},
default: {
@ -2189,7 +2189,7 @@ describe("QueryBuilder", function() {
bindings: ['foo', 'bar', 1, 1]
},
mssql: {
sql: 'update top (?) [users] set [email] = ?, [name] = ? where [users].[id] = ?;select @@rowcount',
sql: 'update top ? [users] set [email] = ?, [name] = ? where [users].[id] = ?;select @@rowcount',
bindings: ['foo', 'bar', 1, 1]
},
default: {
@ -2337,7 +2337,7 @@ describe("QueryBuilder", function() {
// it("sql server limits and offsets", function() {
// $builder = $this.getSqlServerBuilder();
// $builder.select('*').from('users').limit(10).toSQL();
// expect(chain.sql).to.equal('select top (10) * from [users]');
// expect(chain.sql).to.equal('select top 10 * from [users]');
// $builder = $this.getSqlServerBuilder();
// $builder.select('*').from('users').offset(10).toSQL();