Skip to content

Commit

Permalink
feat(QueryBuilder): support object alias notation for aggregate methods
Browse files Browse the repository at this point in the history
i.e. `count`, `countDistinct`, `max`, `min`, `avg`, `avgDistinct`, `sum`, `sumDistinct`
  • Loading branch information
joelmukuthu committed Feb 16, 2018
1 parent 76b849d commit dde6e3e
Show file tree
Hide file tree
Showing 4 changed files with 161 additions and 8 deletions.
32 changes: 28 additions & 4 deletions src/helpers.js
Expand Up @@ -99,19 +99,43 @@ export function aggregateStatement(stmt, { aliasSeparator, wrap }) {
const value = stmt.value;
const method = stmt.method;
const distinct = stmt.aggregateDistinct ? 'distinct ' : '';
const addAlias = (value, alias) => {
if (alias) {
return value + aliasSeparator + wrap(alias);
}
return value;
};
const aggregateArray = (value, alias) => {
const columns = value.map(val => ` ${wrap(val)}`);
const aggregated = `${method}(${distinct.trim() + columns})`;
return addAlias(aggregated, alias);
};
const aggregateString = (value, alias) => {
const aggregated = `${method}(${distinct + wrap(value)})`;
return addAlias(aggregated, alias);
};

if (Array.isArray(value)) {
const columns = value.map(val => ` ${wrap(val)}`)
return `${method}(${distinct.trim() + columns})`;
return aggregateArray(value);
}

if (typeof value === 'object') {
const keys = Object.keys(value);
const alias = keys[0];
const column = value[alias];
if (Array.isArray(column)) {
return aggregateArray(column, alias);
}
return aggregateString(column, alias);
}

// Allows us to speciy an alias for the aggregate types.
const splitOn = value.toLowerCase().indexOf(' as ');
if (splitOn !== -1) {
const column = value.slice(0, splitOn);
const alias = value.slice(splitOn + 4);
return `${method}(${distinct + wrap(column)})${aliasSeparator}${wrap(alias)}`;
return aggregateString(column, alias);
}

return `${method}(${distinct + wrap(value)})`;
return aggregateString(value);
}
2 changes: 0 additions & 2 deletions src/query/builder.js
Expand Up @@ -745,8 +745,6 @@ assign(Builder.prototype, {
if (!columns.length) {
columns = '*';
} else if (columns.length === 1) {
// if only one argument was passed, pass it along as a string since it may
// contain an alias e.g. 'column as alias'
columns = columns[0];
}

Expand Down
48 changes: 48 additions & 0 deletions test/integration/builder/aggregate.js
Expand Up @@ -327,6 +327,54 @@ module.exports = function(knex) {

});

it('supports countDistinct with multiple columns with alias', function () {

return knex('accounts').countDistinct({ count: ['id', 'logins'] })
.testSql(function (tester) {
tester(
'mysql',
'select count(distinct `id`, `logins`) as `logins` from `accounts`',
[],
[{
count: 3
}]
);
tester(
'postgresql',
'select count(distinct "id", "logins") as "logins" from "accounts"',
[],
[{
count: '3'
}]
);
tester(
'sqlite3',
'select count(distinct `id`, `logins`) as `logins` from `accounts`',
[],
[{
count: 3
}]
);
tester(
'oracle',
'select count(distinct "id", "logins") "logins" from "accounts"',
[],
[{
COUNT: 3
}]
);
tester(
'mssql',
'select count(distinct [id], [logins]) as [logins] from [accounts]',
[],
[{
count: [3]
}]
);
});

});

it("support the groupBy function", function() {

return knex('accounts').count('id').groupBy('logins').orderBy('logins', 'asc').testSql(function(tester) {
Expand Down
87 changes: 85 additions & 2 deletions test/unit/query/builder.js
Expand Up @@ -2875,7 +2875,7 @@ describe("QueryBuilder", function() {
});
});

it("count with alias", function() {
it("count with string alias", function() {
testsql(qb().from('users').count('* as all'), {
mysql: {
sql: 'select count(*) as `all` from `users`',
Expand Down Expand Up @@ -2904,7 +2904,36 @@ describe("QueryBuilder", function() {
});
});

it("count distinct with alias", function() {
it("count with object alias", function () {
testsql(qb().from('users').count({ all: '*' }), {
mysql: {
sql: 'select count(*) as `all` from `users`',
bindings: []
},
mssql: {
sql: 'select count(*) as [all] from [users]',
bindings: []
},
oracle: {
sql: 'select count(*) "all" from "users"',
bindings: []
},
oracledb: {
sql: 'select count(*) "all" from "users"',
bindings: []
},
postgres: {
sql: 'select count(*) as "all" from "users"',
bindings: []
},
redshift: {
sql: 'select count(*) as "all" from "users"',
bindings: []
},
});
});

it("count distinct with string alias", function() {
testsql(qb().from('users').countDistinct('* as all'), {
mysql: {
sql: 'select count(distinct *) as `all` from `users`',
Expand Down Expand Up @@ -2933,6 +2962,35 @@ describe("QueryBuilder", function() {
});
});

it("count distinct with object alias", function () {
testsql(qb().from('users').countDistinct({ all: '*' }), {
mysql: {
sql: 'select count(distinct *) as `all` from `users`',
bindings: []
},
oracle: {
sql: 'select count(distinct *) "all" from "users"',
bindings: []
},
mssql: {
sql: 'select count(distinct *) as [all] from [users]',
bindings: []
},
oracledb: {
sql: 'select count(distinct *) "all" from "users"',
bindings: []
},
postgres: {
sql: 'select count(distinct *) as "all" from "users"',
bindings: []
},
redshift: {
sql: 'select count(distinct *) as "all" from "users"',
bindings: []
},
});
});

it("count with raw values", function() {
testsql(qb().from('users').count(raw('??', 'name')), {
mysql: {
Expand Down Expand Up @@ -2992,6 +3050,31 @@ describe("QueryBuilder", function() {
});
});

it("count distinct with multiple columns with alias", function () {
testsql(qb().from('users').countDistinct({ alias: ['foo', 'bar'] }), {
mysql: {
sql: 'select count(distinct `foo`, `bar`) as `alias` from `users`',
bindings: []
},
oracle: {
sql: 'select count(distinct "foo", "bar") "alias" from "users"',
bindings: []
},
mssql: {
sql: 'select count(distinct [foo], [bar]) as [alias] from [users]',
bindings: []
},
oracledb: {
sql: 'select count(distinct "foo", "bar") "alias" from "users"',
bindings: []
},
postgres: {
sql: 'select count(distinct "foo", "bar") as "alias" from "users"',
bindings: []
}
});
});

it("max", function() {
testsql(qb().from('users').max('id'), {
mysql: {
Expand Down

0 comments on commit dde6e3e

Please sign in to comment.