Skip to content

Commit

Permalink
Browse files Browse the repository at this point in the history
Allow raw expressions in query builder aggregate methods (#2257)
The aggregate methods include `count`, `min`, `max`, `sum`, `avg`,
`countDistinct`, `sumDistinct`, and `avgDistinct`, all of which
can now receive raw expressions, e.g.

```js
knex('users').count(knex.raw("data->'active'"));
```

There seems to be some demand for this, and I think it's cleaner than the alternative of

```js
knex('users').select(knex.raw("count(data->'active')"));
```
  • Loading branch information
noodle authored and elhigu committed Oct 14, 2017
1 parent 9658c78 commit b092a27
Show file tree
Hide file tree
Showing 4 changed files with 165 additions and 1 deletion.
3 changes: 3 additions & 0 deletions src/dialects/mssql/query/compiler.js
Expand Up @@ -126,6 +126,9 @@ assign(QueryCompiler_MSSQL.prototype, {
if (stmt.type === 'aggregate') {
sql.push(this.aggregate(stmt))
}
else if (stmt.type === 'aggregateRaw') {
sql.push(this.aggregateRaw(stmt))
}
else if (stmt.value && stmt.value.length > 0) {
sql.push(this.formatter.columnize(stmt.value))
}
Expand Down
2 changes: 1 addition & 1 deletion src/query/builder.js
Expand Up @@ -966,7 +966,7 @@ assign(Builder.prototype, {
_aggregate(method, column, aggregateDistinct) {
this._statements.push({
grouping: 'columns',
type: 'aggregate',
type: column instanceof Raw ? 'aggregateRaw' : 'aggregate',
method,
value: column,
aggregateDistinct: aggregateDistinct || false
Expand Down
8 changes: 8 additions & 0 deletions src/query/compiler.js
Expand Up @@ -166,6 +166,9 @@ assign(QueryCompiler.prototype, {
if (stmt.type === 'aggregate') {
sql.push(this.aggregate(stmt))
}
else if (stmt.type === 'aggregateRaw') {
sql.push(this.aggregateRaw(stmt))
}
else if (stmt.value && stmt.value.length > 0) {
sql.push(this.formatter.columnize(stmt.value))
}
Expand Down Expand Up @@ -194,6 +197,11 @@ assign(QueryCompiler.prototype, {
return `${stmt.method}(${distinct + this.formatter.wrap(val)})`;
},

aggregateRaw(stmt) {
const distinct = stmt.aggregateDistinct ? 'distinct ' : '';
return `${stmt.method}(${distinct + this.formatter.unwrapRaw(stmt.value)})`;
},

// Compiles all each of the `join` clauses on the query,
// including any nested join queries.
join() {
Expand Down
153 changes: 153 additions & 0 deletions test/unit/query/builder.js
Expand Up @@ -2405,6 +2405,40 @@ describe("QueryBuilder", function() {
});
});

it("count with raw values", function() {
testsql(qb().from('users').count(raw('??', 'name')), {
mysql: {
sql: 'select count(`name`) from `users`',
bindings: []
},
mssql: {
sql: 'select count([name]) from [users]',
bindings: []
},
postgres: {
sql: 'select count("name") from "users"',
bindings: []
}
});
});

it("count distinct with raw values", function() {
testsql(qb().from('users').countDistinct(raw('??', 'name')), {
mysql: {
sql: 'select count(distinct `name`) from `users`',
bindings: []
},
mssql: {
sql: 'select count(distinct [name]) from [users]',
bindings: []
},
postgres: {
sql: 'select count(distinct "name") from "users"',
bindings: []
}
});
});

it("max", function() {
testsql(qb().from('users').max('id'), {
mysql: {
Expand All @@ -2422,6 +2456,23 @@ describe("QueryBuilder", function() {
});
});

it("max with raw values", function() {
testsql(qb().from('users').max(raw('??', ['name'])), {
mysql: {
sql: 'select max(`name`) from `users`',
bindings: []
},
mssql: {
sql: 'select max([name]) from [users]',
bindings: []
},
postgres: {
sql: 'select max("name") from "users"',
bindings: []
}
});
});

it("min", function() {
testsql(qb().from('users').max('id'), {
mysql: {
Expand All @@ -2439,6 +2490,23 @@ describe("QueryBuilder", function() {
});
});

it("min with raw values", function() {
testsql(qb().from('users').min(raw('??', ['name'])), {
mysql: {
sql: 'select min(`name`) from `users`',
bindings: []
},
mssql: {
sql: 'select min([name]) from [users]',
bindings: []
},
postgres: {
sql: 'select min("name") from "users"',
bindings: []
}
});
});

it("sum", function() {
testsql(qb().from('users').sum('id'), {
mysql: {
Expand All @@ -2456,6 +2524,23 @@ describe("QueryBuilder", function() {
});
});

it("sum with raw values", function() {
testsql(qb().from('users').sum(raw('??', ['name'])), {
mysql: {
sql: 'select sum(`name`) from `users`',
bindings: []
},
mssql: {
sql: 'select sum([name]) from [users]',
bindings: []
},
postgres: {
sql: 'select sum("name") from "users"',
bindings: []
}
});
});

it("sum distinct", function() {
testsql(qb().from('users').sumDistinct('id'), {
mysql: {
Expand All @@ -2473,6 +2558,74 @@ describe("QueryBuilder", function() {
});
});

it("sum distinct with raw values", function() {
testsql(qb().from('users').sumDistinct(raw('??', ['name'])), {
mysql: {
sql: 'select sum(distinct `name`) from `users`',
bindings: []
},
mssql: {
sql: 'select sum(distinct [name]) from [users]',
bindings: []
},
postgres: {
sql: 'select sum(distinct "name") from "users"',
bindings: []
}
});
});

it("avg", function() {
testsql(qb().from('users').avg('id'), {
mysql: {
sql: 'select avg(`id`) from `users`',
bindings: []
},
mssql: {
sql: 'select avg([id]) from [users]',
bindings: []
},
postgres: {
sql: 'select avg("id") from "users"',
bindings: []
}
});
});

it("avg with raw values", function() {
testsql(qb().from('users').avg(raw('??', ['name'])), {
mysql: {
sql: 'select avg(`name`) from `users`',
bindings: []
},
mssql: {
sql: 'select avg([name]) from [users]',
bindings: []
},
postgres: {
sql: 'select avg("name") from "users"',
bindings: []
}
});
});

it("avg distinct with raw values", function() {
testsql(qb().from('users').avgDistinct(raw('??', ['name'])), {
mysql: {
sql: 'select avg(distinct `name`) from `users`',
bindings: []
},
mssql: {
sql: 'select avg(distinct [name]) from [users]',
bindings: []
},
postgres: {
sql: 'select avg(distinct "name") from "users"',
bindings: []
}
});
});

it("insert method", function() {
testsql(qb().into('users').insert({'email': 'foo'}), {
mysql: {
Expand Down

0 comments on commit b092a27

Please sign in to comment.