diff --git a/lib/sql.js b/lib/sql.js index 4f07a6b..cad5523 100644 --- a/lib/sql.js +++ b/lib/sql.js @@ -1260,6 +1260,15 @@ SQLConnector.prototype.buildFields = function(model, data, excludeIds) { return this._buildFieldsForKeys(model, data, keys, excludeIds); }; +/** + * Build a part of query for group by + * @param {String[]} groupBy Array of column names to be grouped by + * @returns a part of query for group by as a string + */ +SQLConnector.prototype.buildGroupBy = function(groupBy) { + return 'GROUP BY ' + groupBy.join(','); +}; + /** * Build an array of fields for the database operation from data array * @param {String} model Model name @@ -1439,7 +1448,25 @@ SQLConnector.prototype.buildSelect = function(model, filter, options) { } } + let extraSelect = ''; + if (filter.sum) { + extraSelect = `SUM(${filter.sum}) as sumOf${filter.sum}, `; + } + if (filter.count) { + extraSelect += `COUNT(${filter.count}) as countOf${filter.count}, `; + } + if (filter.avg) { + extraSelect += `AVG(${filter.avg}) as avgOf${filter.avg}, `; + } + if (filter.min) { + extraSelect += `MIN(${filter.min}) as minOf${filter.min}, `; + } + if (filter.max) { + extraSelect += `MAX(${filter.max}) as maxOf${filter.max}, `; + } + let selectStmt = new ParameterizedSQL('SELECT ' + + extraSelect + this.buildColumnNames(model, filter) + ' FROM ' + this.tableEscaped(model)); @@ -1449,6 +1476,10 @@ SQLConnector.prototype.buildSelect = function(model, filter, options) { selectStmt.merge(whereStmt); } + if (filter.groupBy) { + selectStmt.merge(this.buildGroupBy(filter.groupBy)); + } + if (filter.order) { selectStmt.merge(this.buildOrderBy(model, filter.order)); } @@ -1510,7 +1541,23 @@ SQLConnector.prototype.all = function find(model, filter, options, cb) { } const objs = data.map(function(obj) { - return self.fromRow(model, obj); + const object = self.fromRow(model, obj); + if (obj[`sumOf${filter.sum}`]) { + object[`sumOf${filter.sum}`] = obj[`sumOf${filter.sum}`]; + } + if (obj[`countOf${filter.count}`]) { + object[`countOf${filter.count}`] = obj[`countOf${filter.count}`]; + } + if (obj[`avgOf${filter.avg}`]) { + object[`avgOf${filter.avg}`] = obj[`avgOf${filter.avg}`]; + } + if (obj[`minOf${filter.min}`]) { + object[`minOf${filter.min}`] = obj[`minOf${filter.min}`]; + } + if (obj[`maxOf${filter.max}`]) { + object[`maxOf${filter.max}`] = obj[`maxOf${filter.max}`]; + } + return object; }); if (filter && filter.include) { self.getModelDefinition(model).model.include( diff --git a/test/sql.test.js b/test/sql.test.js index 405801b..b23206e 100644 --- a/test/sql.test.js +++ b/test/sql.test.js @@ -256,6 +256,11 @@ describe('sql connector', function() { expect(orderBy).to.eql('ORDER BY `NAME`'); }); + it('builds group by with one field', function() { + const groupBy = connector.buildGroupBy(['id']); + expect(groupBy).to.eql('GROUP BY id'); + }); + it('builds order by with two fields', function() { const orderBy = connector.buildOrderBy('customer', ['name', 'vip']); expect(orderBy).to.eql('ORDER BY `NAME`,`VIP`'); @@ -366,6 +371,28 @@ describe('sql connector', function() { }); }); + it('builds SELECT with groupBy, sum, avg, min, max & count', function() { + const sql = connector.buildSelect('customer', + { + groupBy: ['name'], + sum: 'salary', + avg: 'salary', + min: 'salary', + max: 'salary', + count: 'salary', + }); + expect(sql.toJSON()).to.eql({ + sql: 'SELECT SUM(salary) as sumOfsalary, COUNT(salary) as countOfsalary,' + + ' AVG(salary) as avgOfsalary, MIN(salary) as minOfsalary,' + + ' MAX(salary) as maxOfsalary, `NAME`,`middle_name`,`LASTNAME`,`VIP`,' + + '`primary_address`,`TOKEN`,`ADDRESS`' + + ' FROM `CUSTOMER`' + + ' GROUP BY name' + + ' ORDER BY `NAME`', + params: [], + }); + }); + it('builds INSERT', function() { const sql = connector.buildInsert('customer', {name: 'John', vip: true}); expect(sql.toJSON()).to.eql({