Skip to content

Commit

Permalink
Merge branch 'master' into 0.12-prep
Browse files Browse the repository at this point in the history
* master:
  add With Clause (#1599)
  • Loading branch information
tgriesser committed Sep 13, 2016
2 parents f5bad1a + 69235ae commit 6266037
Show file tree
Hide file tree
Showing 9 changed files with 244 additions and 11 deletions.
17 changes: 17 additions & 0 deletions index.html
Original file line number Diff line number Diff line change
Expand Up @@ -73,6 +73,7 @@
<li><a href="#Builder-column">column</a></li>
<li><a href="#Builder-from">from</a></li>
<li><a href="#Builder-withSchema">withSchema</a></li>
<li><a href="#Builder-with">with</a></li>

<li><b><a href="#Builder-wheres">Where Methods:</a></b></li>
<li>&nbsp;&nbsp;- <a href="#Builder-where">where</a></li>
Expand Down Expand Up @@ -680,6 +681,22 @@ <h2 id="Builder">Knex Query Builder</h2>

<pre class="display">
knex.select('*').from('users')
</pre>

<p id="Builder-with">
<b class="header">with</b><code>.with(alias, callback|raw)</code>
<br />
Add a "with" clause to the query. "With" clauses are supported by PostgreSQL, Oracle, SQLite3 and MSSQL.
</p>

<pre class="display">
knex.with('with_alias', function() {
this.select('*').from('books').where('author', 'Test')
}).select('*').from('with_alias')
</pre>

<pre class="display">
knex.with('with_alias', knex.raw('select * from "books" where "author" = ?', 'Test')).select('*').from('with_alias')
</pre>

<p id="Builder-withSchema">
Expand Down
6 changes: 3 additions & 3 deletions src/dialects/mssql/query/compiler.js
Original file line number Diff line number Diff line change
Expand Up @@ -19,7 +19,7 @@ assign(QueryCompiler_MSSQL.prototype, {
// inserts using a single query statement.
insert() {
const insertValues = this.single.insert || [];
let sql = `insert into ${this.tableName} `;
let sql = this.with() + `insert into ${this.tableName} `;
const { returning } = this.single;
const returningSql = returning
? this._returning('insert', returning) + ' '
Expand Down Expand Up @@ -72,7 +72,7 @@ assign(QueryCompiler_MSSQL.prototype, {
const top = this.top();
const { returning } = this.single;
return {
sql: `update ${top ? top + ' ' : ''}${this.tableName}` +
sql: this.with() + `update ${top ? top + ' ' : ''}${this.tableName}` +
(join ? ` ${join}` : '') +
' set ' + updates.join(', ') +
(returning ? ` ${this._returning('update', returning)}` : '') +
Expand All @@ -90,7 +90,7 @@ assign(QueryCompiler_MSSQL.prototype, {
const wheres = this.where();
const { returning } = this.single;
return {
sql: `delete from ${tableName}` +
sql: this.with() + `delete from ${tableName}` +
(returning ? ` ${this._returning('del', returning)}` : '') +
(wheres ? ` ${wheres}` : '') +
(!returning ? this._returning('rowcount', '@@rowcount') : ''),
Expand Down
3 changes: 2 additions & 1 deletion src/dialects/oracle/query/compiler.js
Original file line number Diff line number Diff line change
Expand Up @@ -164,10 +164,11 @@ assign(QueryCompiler_Oracle.prototype, {
},

select() {
let query = this.with();
const statements = map(components, (component) => {
return this[component]();
});
const query = compact(statements).join(' ');
query += compact(statements).join(' ');
return this._surroundQueryWithLimitAndOffset(query);
},

Expand Down
2 changes: 1 addition & 1 deletion src/dialects/postgres/query/compiler.js
Original file line number Diff line number Diff line change
Expand Up @@ -40,7 +40,7 @@ assign(QueryCompiler_PG.prototype, {
const wheres = this.where();
const { returning } = this.single;
return {
sql: `update ${this.tableName} set ${updateData.join(', ')}` +
sql: this.with() + `update ${this.tableName} set ${updateData.join(', ')}` +
(wheres ? ` ${wheres}` : '') +
this._returning(returning),
returning
Expand Down
2 changes: 1 addition & 1 deletion src/dialects/sqlite3/query/compiler.js
Original file line number Diff line number Diff line change
Expand Up @@ -22,7 +22,7 @@ assign(QueryCompiler_SQLite3.prototype, {
// then join them all together with select unions to complete the queries.
insert() {
const insertValues = this.single.insert || []
let sql = `insert into ${this.tableName} `
let sql = this.with() + `insert into ${this.tableName} `

if (Array.isArray(insertValues)) {
if (insertValues.length === 0) {
Expand Down
40 changes: 40 additions & 0 deletions src/query/builder.js
Original file line number Diff line number Diff line change
Expand Up @@ -68,6 +68,46 @@ assign(Builder.prototype, {
return this;
},

// With
// ------

with(alias, statement, bindings) {
if(typeof alias !== 'string') {
throw new Error('with() first argument must be a string');
}
if (typeof statement === 'function') {
return this.withWrapped(alias, statement);
}
// Allow a raw statement to be passed along to the query.
if (statement instanceof Raw && arguments.length >= 2) {
return this.withRaw(alias, statement, bindings);
}
throw new Error('with() second argument must be a function or a raw');
},

// Adds a raw `with` clause to the query.
withRaw(alias, sql, bindings) {
const raw = (sql instanceof Raw ? sql : this.client.raw(sql, bindings));
this._statements.push({
grouping: 'with',
type: 'withRaw',
alias: alias,
value: raw
});
return this;
},

// Helper for compiling any advanced `with` queries.
withWrapped(alias, callback) {
this._statements.push({
grouping: 'with',
type: 'withWrapped',
alias: alias,
value: callback
});
return this;
},

// Select
// ------

Expand Down
40 changes: 35 additions & 5 deletions src/query/compiler.js
Original file line number Diff line number Diff line change
Expand Up @@ -76,10 +76,13 @@ assign(QueryCompiler.prototype, {
// the component compilers, trimming out the empties, and returning a
// generated query string.
select() {
let sql = this.with();

const statements = components.map(component =>
this[component](this)
);
return compact(statements).join(' ');
sql += compact(statements).join(' ');
return sql;
},

pluck() {
Expand All @@ -93,8 +96,7 @@ assign(QueryCompiler.prototype, {
// inserts using a single query statement.
insert() {
const insertValues = this.single.insert || [];
let sql = `insert into ${this.tableName} `;

let sql = this.with() + `insert into ${this.tableName} `;
if (Array.isArray(insertValues)) {
if (insertValues.length === 0) {
return ''
Expand Down Expand Up @@ -131,7 +133,7 @@ assign(QueryCompiler.prototype, {
const { tableName } = this;
const updateData = this._prepUpdate(this.single.update);
const wheres = this.where();
return `update ${tableName}` +
return this.with() + `update ${tableName}` +
' set ' + updateData.join(', ') +
(wheres ? ` ${wheres}` : '');
},
Expand Down Expand Up @@ -306,7 +308,7 @@ assign(QueryCompiler.prototype, {
// Make sure tableName is processed by the formatter first.
const { tableName } = this;
const wheres = this.where();
return `delete from ${tableName}` +
return this.with() + `delete from ${tableName}` +
(wheres ? ` ${wheres}` : '');
},

Expand Down Expand Up @@ -434,6 +436,34 @@ assign(QueryCompiler.prototype, {
return str;
},


// Compiles all `with` statements on the query.
with() {
if(!this.grouped.with || !this.grouped.with.length) {
return '';
}
const withs = this.grouped.with;
if (!withs) return;
const sql = [];
let i = -1;
while (++i < withs.length) {
const stmt = withs[i]
const val = this[stmt.type](stmt)
sql.push(val);
}
return 'with ' + sql.join(', ') + ' ';
},

withWrapped(statement) {
const val = this.formatter.rawOrFn(statement.value);
return val && this.formatter.columnize(statement.alias) + ' as (' + val + ')' || '';
},

withRaw(statement) {
return this.formatter.columnize(statement.alias) + ' as (' +
this.formatter.unwrapRaw(statement.value) + ')';
},

// Determines whether to add a "not" prefix to the where clause.
_not(statement, str) {
if (statement.not) return `not ${str}`;
Expand Down
1 change: 1 addition & 0 deletions src/query/methods.js
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,7 @@
// All properties we can use to start a query chain
// from the `knex` object, e.g. `knex.select('*').from(...`
export default [
'with',
'select',
'as',
'columns',
Expand Down
144 changes: 144 additions & 0 deletions test/unit/query/builder.js
Original file line number Diff line number Diff line change
Expand Up @@ -3442,7 +3442,151 @@ describe("QueryBuilder", function() {
mysql: 'select * from `users` where `id` = 1 and `jsonColumn` ? \'jsonKey?\'',
postgres: 'select * from "users" where "id" = 1 and "jsonColumn" ? \'jsonKey?\''
});
});

it("wrapped 'with' clause select", function() {
testsql(qb().with('withClause', function() {
this.select('foo').from('users');
}).select('*').from('withClause'), {
mssql: 'with [withClause] as (select [foo] from [users]) select * from [withClause]',
sqlite3: 'with "withClause" as (select "foo" from "users") select * from "withClause"',
postgres: 'with "withClause" as (select "foo" from "users") select * from "withClause"',
oracledb: 'with "withClause" as (select "foo" from "users") select * from "withClause"',
oracle: 'with "withClause" as (select "foo" from "users") select * from "withClause"'
});
});

it("wrapped 'with' clause insert", function() {
testsql(qb().with('withClause', function() {
this.select('foo').from('users');
}).insert(raw('select * from "withClause"')).into('users'), {
mssql: 'with [withClause] as (select [foo] from [users]) insert into [users] select * from "withClause"',
sqlite3: 'with "withClause" as (select "foo" from "users") insert into "users" select * from "withClause"',
postgres: 'with "withClause" as (select "foo" from "users") insert into "users" select * from "withClause"'
});
});

it("wrapped 'with' clause multiple insert", function() {
testsql(qb().with('withClause', function() {
this.select('foo').from('users').where({name: 'bob'});
}).insert([{email: 'thisMail', name: 'sam'}, {email: 'thatMail', name: 'jack'}]).into('users'), {
mssql: {
sql: 'with [withClause] as (select [foo] from [users] where [name] = ?) insert into [users] ([email], [name]) values (?, ?), (?, ?)',
bindings: ['bob', 'thisMail', 'sam', 'thatMail', 'jack']
},
sqlite3: {
sql: 'with "withClause" as (select "foo" from "users" where "name" = ?) insert into "users" ("email", "name") select ? as "email", ? as "name" union all select ? as "email", ? as "name"',
bindings: ['bob', 'thisMail', 'sam', 'thatMail', 'jack']
},
postgres: {
sql: 'with "withClause" as (select "foo" from "users" where "name" = ?) insert into "users" ("email", "name") values (?, ?), (?, ?)',
bindings: ['bob', 'thisMail', 'sam', 'thatMail', 'jack']
}
});
});

it("wrapped 'with' clause update", function() {
testsql(qb().with('withClause', function() {
this.select('foo').from('users');
}).update({foo: 'updatedFoo'}).where('email', '=', 'foo').from('users'), {
mssql: 'with [withClause] as (select [foo] from [users]) update [users] set [foo] = ? where [email] = ?;select @@rowcount',
sqlite3: 'with "withClause" as (select "foo" from "users") update "users" set "foo" = ? where "email" = ?',
postgres: 'with "withClause" as (select "foo" from "users") update "users" set "foo" = ? where "email" = ?'
});
});

it("wrapped 'with' clause delete", function() {
testsql(qb().with('withClause', function() {
this.select('email').from('users');
}).del().where('foo', '=', 'updatedFoo').from('users'), {
mssql: 'with [withClause] as (select [email] from [users]) delete from [users] where [foo] = ?;select @@rowcount',
sqlite3: 'with "withClause" as (select "email" from "users") delete from "users" where "foo" = ?',
postgres: 'with "withClause" as (select "email" from "users") delete from "users" where "foo" = ?'
});
});

it("raw 'with' clause", function() {
testsql(qb().with('withRawClause', raw('select "foo" as "baz" from "users"')).select('*').from('withRawClause'), {
mssql: 'with [withRawClause] as (select "foo" as "baz" from "users") select * from [withRawClause]',
sqlite3: 'with "withRawClause" as (select "foo" as "baz" from "users") select * from "withRawClause"',
postgres: 'with "withRawClause" as (select "foo" as "baz" from "users") select * from "withRawClause"',
oracledb: 'with "withRawClause" as (select "foo" as "baz" from "users") select * from "withRawClause"',
oracle: 'with "withRawClause" as (select "foo" as "baz" from "users") select * from "withRawClause"'
});
});

it("chained wrapped 'with' clause", function() {
testsql(qb().with('firstWithClause', function() {
this.select('foo').from('users');
}).with('secondWithClause', function() {
this.select('bar').from('users');
}).select('*').from('secondWithClause'), {
mssql: 'with [firstWithClause] as (select [foo] from [users]), [secondWithClause] as (select [bar] from [users]) select * from [secondWithClause]',
sqlite3: 'with "firstWithClause" as (select "foo" from "users"), "secondWithClause" as (select "bar" from "users") select * from "secondWithClause"',
postgres: 'with "firstWithClause" as (select "foo" from "users"), "secondWithClause" as (select "bar" from "users") select * from "secondWithClause"',
oracledb: 'with "firstWithClause" as (select "foo" from "users"), "secondWithClause" as (select "bar" from "users") select * from "secondWithClause"',
oracle: 'with "firstWithClause" as (select "foo" from "users"), "secondWithClause" as (select "bar" from "users") select * from "secondWithClause"'
});
});

it("nested 'with' clause", function() {
testsql(qb().with('withClause', function() {
this.with('withSubClause', function() {
this.select('foo').as('baz').from('users');
}).select('*').from('withSubClause');
}).select('*').from('withClause'), {
mssql: 'with [withClause] as (with [withSubClause] as ((select [foo] from [users]) as [baz]) select * from [withSubClause]) select * from [withClause]',
sqlite3: 'with "withClause" as (with "withSubClause" as ((select "foo" from "users") as "baz") select * from "withSubClause") select * from "withClause"',
postgres: 'with "withClause" as (with "withSubClause" as ((select "foo" from "users") as "baz") select * from "withSubClause") select * from "withClause"',
oracledb: 'with "withClause" as (with "withSubClause" as ((select "foo" from "users") "baz") select * from "withSubClause") select * from "withClause"',
oracle: 'with "withClause" as (with "withSubClause" as ((select "foo" from "users") "baz") select * from "withSubClause") select * from "withClause"'
});
});

it("nested 'with' clause with bindings", function() {
testsql(qb().with('withClause', function() {
this.with('withSubClause', raw('select "foo" as "baz" from "users" where "baz" > ? and "baz" < ?',
[1, 20])).select('*').from('withSubClause');
}).select('*').from('withClause').where({id: 10}), {
mssql: {
sql: 'with [withClause] as (with [withSubClause] as (select "foo" as "baz" from "users" where "baz" > ? and "baz" < ?) select * from [withSubClause]) select * from [withClause] where [id] = ?',
bindings: [1, 20, 10]
},
sqlite3: {
sql: 'with "withClause" as (with "withSubClause" as (select "foo" as "baz" from "users" where "baz" > ? and "baz" < ?) select * from "withSubClause") select * from "withClause" where "id" = ?',
bindings: [1, 20, 10]
},
postgres: {
sql: 'with "withClause" as (with "withSubClause" as (select "foo" as "baz" from "users" where "baz" > ? and "baz" < ?) select * from "withSubClause") select * from "withClause" where "id" = ?',
bindings: [1, 20, 10]
},
oracledb: {
sql: 'with "withClause" as (with "withSubClause" as (select "foo" as "baz" from "users" where "baz" > ? and "baz" < ?) select * from "withSubClause") select * from "withClause" where "id" = ?',
bindings: [1, 20, 10]
},
oracle: {
sql: 'with "withClause" as (with "withSubClause" as (select "foo" as "baz" from "users" where "baz" > ? and "baz" < ?) select * from "withSubClause") select * from "withClause" where "id" = ?',
bindings: [1, 20, 10]
}
});
});

it("nested and chained wrapped 'with' clause", function() {
testsql(qb().with('firstWithClause', function() {
this.with('firstWithSubClause', function() {
this.select('foo').as('foz').from('users');
}).select('*').from('firstWithSubClause');
}).with('secondWithClause', function() {
this.with('secondWithSubClause', function() {
this.select('bar').as('baz').from('users');
}).select('*').from('secondWithSubClause');
}).select('*').from('secondWithClause'), {
mssql: 'with [firstWithClause] as (with [firstWithSubClause] as ((select [foo] from [users]) as [foz]) select * from [firstWithSubClause]), [secondWithClause] as (with [secondWithSubClause] as ((select [bar] from [users]) as [baz]) select * from [secondWithSubClause]) select * from [secondWithClause]',
sqlite3: 'with "firstWithClause" as (with "firstWithSubClause" as ((select "foo" from "users") as "foz") select * from "firstWithSubClause"), "secondWithClause" as (with "secondWithSubClause" as ((select "bar" from "users") as "baz") select * from "secondWithSubClause") select * from "secondWithClause"',
postgres: 'with "firstWithClause" as (with "firstWithSubClause" as ((select "foo" from "users") as "foz") select * from "firstWithSubClause"), "secondWithClause" as (with "secondWithSubClause" as ((select "bar" from "users") as "baz") select * from "secondWithSubClause") select * from "secondWithClause"',
oracledb: 'with "firstWithClause" as (with "firstWithSubClause" as ((select "foo" from "users") "foz") select * from "firstWithSubClause"), "secondWithClause" as (with "secondWithSubClause" as ((select "bar" from "users") "baz") select * from "secondWithSubClause") select * from "secondWithClause"',
oracle: 'with "firstWithClause" as (with "firstWithSubClause" as ((select "foo" from "users") "foz") select * from "firstWithSubClause"), "secondWithClause" as (with "secondWithSubClause" as ((select "bar" from "users") "baz") select * from "secondWithSubClause") select * from "secondWithClause"'
});
});

});

0 comments on commit 6266037

Please sign in to comment.