Skip to content

Commit

Permalink
feat(aggretations): Add aggregations support to typeorm
Browse files Browse the repository at this point in the history
  • Loading branch information
doug-martin committed Jul 16, 2020
1 parent d67e733 commit 7233c23
Show file tree
Hide file tree
Showing 7 changed files with 261 additions and 3 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -12,7 +12,7 @@ export const CONNECTION_OPTIONS: ConnectionOptions = {
dropSchema: true,
entities: [TestEntity, TestSoftDeleteEntity, TestRelation, TestEntityRelationEntity],
synchronize: true,
logging: false,
logging: true,
};

export function createTestConnection(): Promise<Connection> {
Expand Down
79 changes: 79 additions & 0 deletions packages/query-typeorm/__tests__/query/aggregate.builder.spec.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,79 @@
/* eslint-disable @typescript-eslint/naming-convention */
import { AggregateQuery } from '@nestjs-query/core';
import { closeTestConnection, createTestConnection, getTestConnection } from '../__fixtures__/connection.fixture';
import { TestEntity } from '../__fixtures__/test.entity';
import { AggregateBuilder } from '../../src/query';

describe('AggregateBuilder', (): void => {
beforeEach(createTestConnection);
afterEach(closeTestConnection);

const getRepo = () => getTestConnection().getRepository(TestEntity);
const getQueryBuilder = () => getRepo().createQueryBuilder();
const createAggregateBuilder = () => new AggregateBuilder<TestEntity>();

const assertSQL = (agg: AggregateQuery<TestEntity>, expectedSql: string, expectedArgs: any[]): void => {
const selectQueryBuilder = createAggregateBuilder().build(getQueryBuilder(), agg, 'TestEntity');
const [sql, params] = selectQueryBuilder.getQueryAndParameters();
expect(sql).toEqual(expectedSql);
expect(params).toEqual(expectedArgs);
};

it('should throw an error if no selects are generated', (): void => {
expect(() => createAggregateBuilder().build(getQueryBuilder(), {})).toThrow('No aggregate fields found.');
});

it('or multiple operators for a single field together', (): void => {
assertSQL(
{
count: ['testEntityPk'],
avg: ['numberType'],
sum: ['numberType'],
max: ['stringType', 'dateType', 'numberType'],
min: ['stringType', 'dateType', 'numberType'],
},
'SELECT ' +
'COUNT("TestEntity"."test_entity_pk") AS "COUNT_testEntityPk", ' +
'SUM("TestEntity"."number_type") AS "SUM_numberType", ' +
'AVG("TestEntity"."number_type") AS "AVG_numberType", ' +
'MAX("TestEntity"."string_type") AS "MAX_stringType", ' +
'MAX("TestEntity"."date_type") AS "MAX_dateType", ' +
'MAX("TestEntity"."number_type") AS "MAX_numberType", ' +
'MIN("TestEntity"."string_type") AS "MIN_stringType", ' +
'MIN("TestEntity"."date_type") AS "MIN_dateType", ' +
'MIN("TestEntity"."number_type") AS "MIN_numberType" ' +
'FROM "test_entity" "TestEntity"',
[],
);
});

describe('.convertToAggregateResponse', () => {
it('should convert a flat response into an Aggregtate response', () => {
const dbResult = {
COUNT_testEntityPk: 10,
SUM_numberType: 55,
AVG_numberType: 5,
MAX_stringType: 'z',
MAX_numberType: 10,
MIN_stringType: 'a',
MIN_numberType: 1,
};
expect(AggregateBuilder.convertToAggregateResponse<TestEntity>(dbResult)).toEqual({
count: { testEntityPk: 10 },
sum: { numberType: 55 },
avg: { numberType: 5 },
max: { stringType: 'z', numberType: 10 },
min: { stringType: 'a', numberType: 1 },
});
});

it('should throw an error if a column is not expected', () => {
const dbResult = {
COUNTtestEntityPk: 10,
};
expect(() => AggregateBuilder.convertToAggregateResponse<TestEntity>(dbResult)).toThrow(
'Unknown aggregate column encountered.',
);
});
});
});
Original file line number Diff line number Diff line change
Expand Up @@ -118,6 +118,82 @@ describe('TypeOrmQueryService', (): void => {
});
});

describe('#aggregate', () => {
it('call select with the aggregate columns and return the result', async () => {
const queryService = moduleRef.get(TestEntityService);
const queryResult = await queryService.aggregate(
{},
{
count: ['testEntityPk'],
avg: ['numberType'],
sum: ['numberType'],
max: ['testEntityPk', 'dateType', 'numberType', 'stringType'],
min: ['testEntityPk', 'dateType', 'numberType', 'stringType'],
},
);
return expect(queryResult).toEqual({
avg: {
numberType: 5.5,
},
count: {
testEntityPk: 10,
},
max: {
dateType: '2020-02-10 00:00:00.000',
numberType: 10,
stringType: 'foo9',
testEntityPk: 'test-entity-9',
},
min: {
dateType: '2020-02-01 06:00:00.000',
numberType: 1,
stringType: 'foo1',
testEntityPk: 'test-entity-1',
},
sum: {
numberType: 55,
},
});
});

it('call select with the aggregate columns and return the result with a filter', async () => {
const queryService = moduleRef.get(TestEntityService);
const queryResult = await queryService.aggregate(
{ stringType: { in: ['foo1', 'foo2', 'foo3'] } },
{
count: ['testEntityPk'],
avg: ['numberType'],
sum: ['numberType'],
max: ['testEntityPk', 'dateType', 'numberType', 'stringType'],
min: ['testEntityPk', 'dateType', 'numberType', 'stringType'],
},
);
return expect(queryResult).toEqual({
avg: {
numberType: 2,
},
count: {
testEntityPk: 3,
},
max: {
dateType: '2020-02-03 06:00:00.000',
numberType: 3,
stringType: 'foo3',
testEntityPk: 'test-entity-3',
},
min: {
dateType: '2020-02-01 06:00:00.000',
numberType: 1,
stringType: 'foo1',
testEntityPk: 'test-entity-1',
},
sum: {
numberType: 6,
},
});
});
});

describe('#count', () => {
it('call select and return the result', async () => {
const queryService = moduleRef.get(TestEntityService);
Expand Down
71 changes: 71 additions & 0 deletions packages/query-typeorm/src/query/aggregate.builder.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,71 @@
import { SelectQueryBuilder } from 'typeorm';
import { AggregateQuery, AggregateResponse } from '@nestjs-query/core';
import { BadRequestException } from '@nestjs/common';

enum AggregateFuncs {
AVG = 'AVG',
SUM = 'SUM',
COUNT = 'COUNT',
MAX = 'MAX',
MIN = 'MIN',
}

const AGG_REGEXP = /(AVG|SUM|COUNT|MAX|MIN)_(.*)/;

/**
* @internal
* Builds a WHERE clause from a Filter.
*/
export class AggregateBuilder<Entity> {
static convertToAggregateResponse<Entity>(response: Record<string, unknown>): AggregateResponse<Entity> {
return Object.keys(response).reduce((agg, resultField: string) => {
const matchResult = AGG_REGEXP.exec(resultField);
if (!matchResult) {
throw new Error('Unknown aggregate column encountered.');
}
const [matchedFunc, matchedFieldName] = matchResult.slice(1);
const aggFunc = matchedFunc.toLowerCase() as keyof AggregateResponse<Entity>;
const fieldName = matchedFieldName as keyof Entity;
const aggResult = agg[aggFunc] || {};
return {
...agg,
// eslint-disable-next-line @typescript-eslint/no-unsafe-assignment
[aggFunc]: { ...aggResult, [fieldName]: response[resultField] },
};
}, {} as AggregateResponse<Entity>);
}

/**
* Builds a aggregate SELECT clause from a aggregate.
* @param qb - the `typeorm` SelectQueryBuilder
* @param aggregate - the aggregates to select.
* @param alias - optional alias to use to qualify an identifier
*/
build<Qb extends SelectQueryBuilder<Entity>>(qb: Qb, aggregate: AggregateQuery<Entity>, alias?: string): Qb {
const selects = [
...this.createAggSelect(AggregateFuncs.COUNT, aggregate.count, alias),
...this.createAggSelect(AggregateFuncs.SUM, aggregate.sum, alias),
...this.createAggSelect(AggregateFuncs.AVG, aggregate.avg, alias),
...this.createAggSelect(AggregateFuncs.MAX, aggregate.max, alias),
...this.createAggSelect(AggregateFuncs.MIN, aggregate.min, alias),
];
if (!selects.length) {
throw new BadRequestException('No aggregate fields found.');
}
const [head, ...tail] = selects;
return tail.reduce((acc: Qb, [select, selectAlias]) => {
return acc.addSelect(select, selectAlias);
}, qb.select(head[0], head[1]));
}

private createAggSelect(func: AggregateFuncs, fields?: (keyof Entity)[], alias?: string): [string, string][] {
if (!fields) {
return [];
}
return fields.map((field) => {
const col = alias ? `${alias}.${field as string}` : (field as string);
const aggAlias = `${func}_${field as string}`;
return [`${func}(${col})`, aggAlias];
});
}
}
26 changes: 25 additions & 1 deletion packages/query-typeorm/src/query/filter-query.builder.ts
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
import { Filter, Paging, Query, SortField, getFilterFields } from '@nestjs-query/core';
import { Filter, Paging, Query, SortField, getFilterFields, AggregateQuery } from '@nestjs-query/core';
import {
DeleteQueryBuilder,
QueryBuilder,
Expand All @@ -8,6 +8,7 @@ import {
WhereExpression,
} from 'typeorm';
import { SoftDeleteQueryBuilder } from 'typeorm/query-builder/SoftDeleteQueryBuilder';
import { AggregateBuilder } from './aggregate.builder';
import { WhereBuilder } from './where.builder';

/**
Expand Down Expand Up @@ -38,6 +39,7 @@ export class FilterQueryBuilder<Entity> {
constructor(
readonly repo: Repository<Entity>,
readonly whereBuilder: WhereBuilder<Entity> = new WhereBuilder<Entity>(),
readonly aggregateBulder: AggregateBuilder<Entity> = new AggregateBuilder<Entity>(),
) {}

/**
Expand All @@ -54,6 +56,13 @@ export class FilterQueryBuilder<Entity> {
return qb;
}

aggregate(query: Query<Entity>, aggregate: AggregateQuery<Entity>): SelectQueryBuilder<Entity> {
let qb = this.createQueryBuilder();
qb = this.applyAggregate(qb, aggregate, qb.alias);
qb = this.applyFilter(qb, query.filter, qb.alias);
return qb;
}

/**
* Create a `typeorm` DeleteQueryBuilder with a WHERE clause.
*
Expand Down Expand Up @@ -97,6 +106,21 @@ export class FilterQueryBuilder<Entity> {
return qb.limit(paging.limit).offset(paging.offset);
}

/**
* Applies the filter from a Query to a `typeorm` QueryBuilder.
*
* @param qb - the `typeorm` QueryBuilder.
* @param aggregate - the aggregates to select.
* @param alias - optional alias to use to qualify an identifier
*/
private applyAggregate<Qb extends SelectQueryBuilder<Entity>>(
qb: Qb,
aggregate: AggregateQuery<Entity>,
alias?: string,
): Qb {
return this.aggregateBulder.build(qb, aggregate, alias);
}

/**
* Applies the filter from a Query to a `typeorm` QueryBuilder.
*
Expand Down
1 change: 1 addition & 0 deletions packages/query-typeorm/src/query/index.ts
Original file line number Diff line number Diff line change
Expand Up @@ -2,3 +2,4 @@ export * from './filter-query.builder';
export * from './where.builder';
export * from './sql-comparison.builder';
export * from './relation-query.builder';
export * from './aggregate.builder';
9 changes: 8 additions & 1 deletion packages/query-typeorm/src/services/typeorm-query.service.ts
Original file line number Diff line number Diff line change
Expand Up @@ -6,11 +6,13 @@ import {
Class,
QueryService,
Filter,
AggregateQuery,
AggregateResponse,
} from '@nestjs-query/core';
import { Repository, DeleteResult } from 'typeorm';
import { QueryDeepPartialEntity } from 'typeorm/query-builder/QueryPartialEntity';
import { MethodNotAllowedException, NotFoundException } from '@nestjs/common';
import { FilterQueryBuilder } from '../query';
import { FilterQueryBuilder, AggregateBuilder } from '../query';
import { RelationQueryService } from './relation-query.service';

export interface TypeOrmQueryServiceOpts<Entity> {
Expand Down Expand Up @@ -67,6 +69,11 @@ export class TypeOrmQueryService<Entity> extends RelationQueryService<Entity> im
return this.filterQueryBuilder.select(query).getMany();
}

async aggregate(filter: Filter<Entity>, aggregate: AggregateQuery<Entity>): Promise<AggregateResponse<Entity>> {
const result = await this.filterQueryBuilder.aggregate({ filter }, aggregate).getRawOne<Record<string, unknown>>();
return AggregateBuilder.convertToAggregateResponse(result);
}

async count(filter: Filter<Entity>): Promise<number> {
return this.filterQueryBuilder.select({ filter }).getCount();
}
Expand Down

0 comments on commit 7233c23

Please sign in to comment.