Skip to content

Commit

Permalink
feat(core): add pagination support (QueryFlag.PAGINATE) (#544)
Browse files Browse the repository at this point in the history
This introduces `QueryFlag.PAGINATE` that can be used to correctly paginate queries that join to-many relations.

```typescript
const res = await orm.em.find(Author2, { books: { title: /^Bible/ } }, {
  orderBy: { name: QueryOrder.ASC, books: { title: QueryOrder.ASC } },
  offset: 3,
  limit: 5,
  flags: [QueryFlag.PAGINATE],
});
```
  • Loading branch information
B4nan committed Aug 9, 2020
1 parent 43a9ce9 commit d43241e
Show file tree
Hide file tree
Showing 10 changed files with 193 additions and 45 deletions.
6 changes: 3 additions & 3 deletions ROADMAP.md
Expand Up @@ -29,15 +29,15 @@ discuss specifics.
- [x] Nested conditions in `qb.update()` queries via subqueries (#319)
- [x] Nested conditions in `em.remove()` via subqueries (#492)
- [x] Use custom errors for specific cases (unique constraint violation, db not accessible, ...)
- [x] Paginator helper or something similar ([doctrine docs](https://www.doctrine-project.org/projects/doctrine-orm/en/latest/tutorials/pagination.html))
- [ ] Lazy scalar properties (allow having props that won't be loaded by default, but can be populated)
- [ ] Support computed properties
- [ ] Association scopes/filters ([hibernate docs](https://docs.jboss.org/hibernate/orm/3.6/reference/en-US/html/filters.html))
- [ ] Support external hooks when using EntitySchema (hooks outside of entity)
- [ ] Cache metadata only with ts-morph provider
- [ ] Diffing entity level indexes in schema generator
- [ ] Support computed properties
- [ ] Add `groupBy` and `distinct` to `FindOptions` and `FindOneOptions`
- [ ] Paginator helper or something similar ([doctrine docs](https://www.doctrine-project.org/projects/doctrine-orm/en/latest/tutorials/pagination.html))
- [ ] Add custom types for blob, array, json
- [ ] Lazy scalar properties (allow having props that won't be loaded by default, but can be populated)
- [ ] Seeds (#251)
- [ ] Static checking of population (#214)
- [ ] Nested object validation (#466)
Expand Down
4 changes: 3 additions & 1 deletion packages/core/src/drivers/IDatabaseDriver.ts
@@ -1,6 +1,6 @@
import { EntityData, EntityMetadata, EntityProperty, AnyEntity, FilterQuery, Primary, Dictionary } from '../typings';
import { Connection, QueryResult, Transaction } from '../connections';
import { QueryOrderMap } from '../enums';
import { QueryOrderMap, QueryFlag } from '../enums';
import { Platform } from '../platforms';
import { MetadataStorage } from '../metadata';
import { LockMode } from '../unit-of-work';
Expand Down Expand Up @@ -82,6 +82,7 @@ export interface FindOptions {
refresh?: boolean;
fields?: string[];
schema?: string;
flags?: QueryFlag[];
}

export interface FindOneOptions {
Expand All @@ -92,4 +93,5 @@ export interface FindOneOptions {
refresh?: boolean;
fields?: string[];
schema?: string;
flags?: QueryFlag[];
}
7 changes: 7 additions & 0 deletions packages/core/src/enums.ts
Expand Up @@ -39,3 +39,10 @@ export interface QueryOrderMap {
export interface FlatQueryOrderMap {
[x: string]: QueryOrderKeysFlat;
}

export enum QueryFlag {
DISTINCT = 'DISTINCT',
PAGINATE = 'PAGINATE',
UPDATE_SUB_QUERY = 'UPDATE_SUB_QUERY',
DELETE_SUB_QUERY = 'DELETE_SUB_QUERY',
}
11 changes: 7 additions & 4 deletions packages/knex/src/AbstractSqlDriver.ts
@@ -1,8 +1,7 @@
import { Raw, Transaction as KnexTransaction, QueryBuilder as KnexQueryBuilder, Value } from 'knex';
import { QueryBuilder as KnexQueryBuilder, Raw, Transaction as KnexTransaction, Value } from 'knex';
import {
AnyEntity, Constructor, Dictionary, EntityData, EntityMetadata, EntityProperty, FilterQuery, Primary, QueryOrderMap,
Configuration, Utils, Collection, FindOneOptions, FindOptions, ReferenceType, wrap, DatabaseDriver, QueryResult,
Transaction, EntityManager, IDatabaseDriver, EntityManagerType, LockMode,
AnyEntity, Collection, Configuration, Constructor, DatabaseDriver, Dictionary, EntityData, EntityManager, EntityManagerType, EntityMetadata, EntityProperty,
FilterQuery, FindOneOptions, FindOptions, IDatabaseDriver, LockMode, Primary, QueryOrderMap, QueryResult, ReferenceType, Transaction, Utils, wrap,
} from '@mikro-orm/core';
import { AbstractSqlConnection, AbstractSqlPlatform, QueryBuilder } from './index';
import { SqlEntityManager } from './SqlEntityManager';
Expand Down Expand Up @@ -46,6 +45,8 @@ export abstract class AbstractSqlDriver<C extends AbstractSqlConnection = Abstra
qb.limit(options.limit, options.offset);
}

Utils.asArray(options.flags).forEach(flag => qb.setFlag(flag));

return this.rethrow(qb.execute('all'));
}

Expand All @@ -72,6 +73,8 @@ export abstract class AbstractSqlDriver<C extends AbstractSqlConnection = Abstra
.setLockMode(options.lockMode)
.withSchema(options.schema);

Utils.asArray(options.flags).forEach(flag => qb.setFlag(flag));

return this.rethrow(qb.execute('get'));
}

Expand Down
4 changes: 2 additions & 2 deletions packages/knex/src/index.ts
Expand Up @@ -3,7 +3,7 @@ export * from './AbstractSqlDriver';
export * from './AbstractSqlPlatform';
export * from './SqlEntityManager';
export * from './SqlEntityRepository';
export * from './query/index';
export * from './schema/index';
export * from './query';
export * from './schema';
export { SqlEntityManager as EntityManager } from './SqlEntityManager';
export { SqlEntityRepository as EntityRepository } from './SqlEntityRepository';
60 changes: 45 additions & 15 deletions packages/knex/src/query/QueryBuilder.ts
@@ -1,9 +1,9 @@
import { QueryBuilder as KnexQueryBuilder, Raw, Transaction, Value } from 'knex';
import {
AnyEntity, Dictionary, EntityProperty, FlatQueryOrderMap, GroupOperator, LockMode, MetadataStorage,
QBFilterQuery, QueryOrderMap, ReferenceType, SmartQueryHelper, Utils, ValidationError,
AnyEntity, Dictionary, EntityMetadata, EntityProperty, FlatQueryOrderMap, GroupOperator, LockMode, MetadataStorage, QBFilterQuery, QueryFlag,
QueryOrderMap, ReferenceType, SmartQueryHelper, Utils, ValidationError,
} from '@mikro-orm/core';
import { QueryFlag, QueryType } from './enums';
import { QueryType } from './enums';
import { AbstractSqlDriver, QueryBuilderHelper } from '../index';
import { CriteriaNode } from './internal';
import { SqlEntityManager } from '../SqlEntityManager';
Expand Down Expand Up @@ -172,7 +172,7 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
return this;
}

limit(limit: number, offset = 0): this {
limit(limit?: number, offset = 0): this {
this._limit = limit;

if (offset) {
Expand All @@ -182,7 +182,7 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
return this;
}

offset(offset: number): this {
offset(offset?: number): this {
this._offset = offset;
return this;
}
Expand Down Expand Up @@ -349,7 +349,7 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
return ret;
}

private prepareFields<T extends string | Raw = string | Raw>(fields: (string | KnexQueryBuilder)[], type: 'where' | 'groupBy' = 'where'): T[] {
private prepareFields<T extends string | Raw = string | Raw>(fields: (string | KnexQueryBuilder)[], type: 'where' | 'groupBy' | 'sub-query' = 'where'): T[] {
const ret: (string | KnexQueryBuilder)[] = [];

fields.forEach(f => {
Expand Down Expand Up @@ -461,19 +461,49 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
SmartQueryHelper.processParams([this._data, this._cond, this._having]);
this.finalized = true;

if (this.flags.has(QueryFlag.PAGINATE) && this._limit! > 0) {
this.wrapPaginateSubQuery(meta);
}

if (this.flags.has(QueryFlag.UPDATE_SUB_QUERY) || this.flags.has(QueryFlag.DELETE_SUB_QUERY)) {
const subQuery = this.clone();
subQuery.finalized = true;
this.wrapModifySubQuery(meta);
}
}

private wrapPaginateSubQuery(meta: EntityMetadata): void {
const pks = this.prepareFields(meta.primaryKeys, 'sub-query');
const subQuery = this.clone().limit(undefined).offset(undefined);
subQuery.finalized = true;
const knexQuery = subQuery.as(this.alias).clearSelect().select(pks);

// wrap one more time to get around MySQL limitations
// https://stackoverflow.com/questions/45494/mysql-error-1093-cant-specify-target-table-for-update-in-from-clause
const subSubQuery = this.getKnex().select(this.prepareFields(meta.primaryKeys)).from(subQuery.as(this.alias));
const method = this.flags.has(QueryFlag.UPDATE_SUB_QUERY) ? 'update' : 'delete';
// 3 sub-queries are needed to get around mysql limitations with order by + limit + where in + group by (o.O)
// https://stackoverflow.com/questions/17892762/mysql-this-version-of-mysql-doesnt-yet-support-limit-in-all-any-some-subqu
const subSubQuery = this.getKnex().select(pks).from(knexQuery).groupBy(pks).limit(this._limit!);

this[method](this._data).where({
[Utils.getPrimaryKeyHash(meta.primaryKeys)]: { $in: subSubQuery },
});
if (this._offset) {
subSubQuery.offset(this._offset);
}

const subSubSubQuery = this.getKnex().select(pks).from(subSubQuery.as(this.alias));
this._limit = undefined;
this._offset = undefined;
this.select(this._fields!).where({
[Utils.getPrimaryKeyHash(meta.primaryKeys)]: { $in: subSubSubQuery },
});
}

private wrapModifySubQuery(meta: EntityMetadata): void {
const subQuery = this.clone();
subQuery.finalized = true;

// wrap one more time to get around MySQL limitations
// https://stackoverflow.com/questions/45494/mysql-error-1093-cant-specify-target-table-for-update-in-from-clause
const subSubQuery = this.getKnex().select(this.prepareFields(meta.primaryKeys)).from(subQuery.as(this.alias));
const method = this.flags.has(QueryFlag.UPDATE_SUB_QUERY) ? 'update' : 'delete';

this[method](this._data).where({
[Utils.getPrimaryKeyHash(meta.primaryKeys)]: { $in: subSubQuery },
});
}

private autoJoinPivotTable(field: string): void {
Expand Down
6 changes: 0 additions & 6 deletions packages/knex/src/query/enums.ts
Expand Up @@ -6,9 +6,3 @@ export enum QueryType {
UPDATE = 'UPDATE',
DELETE = 'DELETE',
}

export enum QueryFlag {
DISTINCT = 'DISTINCT',
UPDATE_SUB_QUERY = 'UPDATE_SUB_QUERY',
DELETE_SUB_QUERY = 'DELETE_SUB_QUERY',
}
84 changes: 73 additions & 11 deletions tests/EntityManager.mysql.test.ts
Expand Up @@ -2,7 +2,7 @@ import { v4 } from 'uuid';
import chalk from 'chalk';

import {
Collection, Configuration, EntityManager, LockMode, MikroORM, QueryOrder, Reference, Utils, Logger, ValidationError, wrap,
Collection, Configuration, EntityManager, LockMode, MikroORM, QueryFlag, QueryOrder, Reference, Utils, Logger, ValidationError, wrap,
UniqueConstraintViolationException, TableNotFoundException, NotNullConstraintViolationException, TableExistsException, SyntaxErrorException,
NonUniqueFieldNameException, InvalidFieldNameException,
} from '@mikro-orm/core';
Expand Down Expand Up @@ -188,7 +188,7 @@ describe('EntityManagerMySql', () => {
orm.em.clear();

const repo = orm.em.getRepository(FooBar2);
const a = await repo.findOne(bar.id, ['baz']);
const a = await repo.findOne(bar.id, { populate: ['baz'], flags: [QueryFlag.DISTINCT] });
expect(wrap(a!.baz).isInitialized()).toBe(true);
expect(wrap(a!.baz!.bar).isInitialized()).toBe(true);
});
Expand Down Expand Up @@ -1964,16 +1964,78 @@ describe('EntityManagerMySql', () => {
orm.em.clear();
});

test('pagination', async () => {
for (let i = 1; i <= 10; i++) {
const num = `${i}`.padStart(2, '0');
const god = new Author2(`God ${num}`, `hello${num}@heaven.god`);
new Book2(`Bible ${num}.1`, god);
new Book2(`Bible ${num}.2`, god);
new Book2(`Bible ${num}.3`, god);
orm.em.persist(god);
}

await orm.em.flush();
orm.em.clear();

// without paginate flag it fails to get 5 records
const res1 = await orm.em.find(Author2, { books: { title: /^Bible/ } }, {
orderBy: { name: QueryOrder.ASC, books: { title: QueryOrder.ASC } },
limit: 5,
});

expect(res1).toHaveLength(2);
expect(res1.map(a => a.name)).toEqual(['God 01', 'God 02']);

const mock = jest.fn();
const logger = new Logger(mock, true);
Object.assign(orm.em.config, { logger });

// with paginate flag (and a bit of dark sql magic) we get what we want
const res2 = await orm.em.find(Author2, { books: { title: /^Bible/ } }, {
orderBy: { name: QueryOrder.ASC, books: { title: QueryOrder.ASC } },
offset: 3,
limit: 5,
flags: [QueryFlag.PAGINATE],
});

expect(res2).toHaveLength(5);
expect(res2.map(a => a.name)).toEqual(['God 04', 'God 05', 'God 06', 'God 07', 'God 08']);
expect(mock.mock.calls[0][0]).toMatch('select `e0`.*, `e2`.`author_id` as `address_author_id` ' +
'from `author2` as `e0` ' +
'left join `book2` as `e1` on `e0`.`id` = `e1`.`author_id` ' +
'left join `address2` as `e2` on `e0`.`id` = `e2`.`author_id` where `e0`.`id` in (select `e0`.`id` ' +
'from (select `e0`.`id` ' +
'from (select `e0`.`id` ' +
'from `author2` as `e0` ' +
'left join `book2` as `e1` on `e0`.`id` = `e1`.`author_id` ' +
'left join `address2` as `e2` on `e0`.`id` = `e2`.`author_id` ' +
'where `e1`.`title` like ? order by `e0`.`name` asc, `e1`.`title` asc' +
') as `e0` group by `e0`.`id` limit ? offset ?' +
') as `e0`' +
') order by `e0`.`name` asc, `e1`.`title` asc');

// with paginate flag without offset
const res3 = await orm.em.find(Author2, { books: { title: /^Bible/ } }, {
orderBy: { name: QueryOrder.ASC, books: { title: QueryOrder.ASC } },
limit: 5,
flags: [QueryFlag.PAGINATE],
});

expect(res3).toHaveLength(5);
expect(res3.map(a => a.name)).toEqual(['God 01', 'God 02', 'God 03', 'God 04', 'God 05']);
});

test('exceptions', async () => {
const driver = orm.em.getDriver();
await driver.nativeInsert(Author2.name, { name: 'author', email: 'email' });
await expect(driver.nativeInsert(Author2.name, { name: 'author', email: 'email' })).rejects.toThrow(UniqueConstraintViolationException);
await expect(driver.nativeInsert(Author2.name, {})).rejects.toThrow(NotNullConstraintViolationException);
await expect(driver.nativeInsert('not_existing', { foo: 'bar' })).rejects.toThrow(TableNotFoundException);
await expect(driver.execute('create table author2 (foo text not null)')).rejects.toThrow(TableExistsException);
await expect(driver.execute('foo bar 123')).rejects.toThrow(SyntaxErrorException);
await expect(driver.execute('select id from author2, foo_bar2')).rejects.toThrow(NonUniqueFieldNameException);
await expect(driver.execute('select uuid from author2')).rejects.toThrow(InvalidFieldNameException);
await orm.em.transactional(async em => {
await em.nativeInsert(Author2, { name: 'author', email: 'email' });
await expect(em.nativeInsert(Author2, { name: 'author', email: 'email' })).rejects.toThrow(UniqueConstraintViolationException);
await expect(em.nativeInsert('not_existing', { foo: 'bar' })).rejects.toThrow(TableNotFoundException);
await expect(em.execute('create table author2 (foo text not null)')).rejects.toThrow(TableExistsException);
await expect(em.execute('foo bar 123')).rejects.toThrow(SyntaxErrorException);
await expect(em.execute('select id from author2, foo_bar2')).rejects.toThrow(NonUniqueFieldNameException);
await expect(em.execute('select uuid from author2')).rejects.toThrow(InvalidFieldNameException);
await expect(em.execute('insert into foo_bar2 () values ()')).rejects.toThrow(NotNullConstraintViolationException);
});
});

test('em.execute()', async () => {
Expand Down
52 changes: 51 additions & 1 deletion tests/EntityManager.postgre.test.ts
@@ -1,6 +1,6 @@
import { v4 } from 'uuid';
import {
Collection, Configuration, EntityManager, LockMode, MikroORM, QueryOrder, Reference, Utils, Logger, ValidationError, wrap, UniqueConstraintViolationException,
Collection, Configuration, EntityManager, LockMode, MikroORM, QueryFlag, QueryOrder, Reference, Utils, Logger, ValidationError, wrap, UniqueConstraintViolationException,
TableNotFoundException, NotNullConstraintViolationException, TableExistsException, SyntaxErrorException, NonUniqueFieldNameException, InvalidFieldNameException,
} from '@mikro-orm/core';
import { PostgreSqlDriver, PostgreSqlConnection } from '@mikro-orm/postgresql';
Expand Down Expand Up @@ -1208,6 +1208,56 @@ describe('EntityManagerPostgre', () => {
expect(address2).toBeNull();
});

test('pagination', async () => {
for (let i = 1; i <= 10; i++) {
const num = `${i}`.padStart(2, '0');
const god = new Author2(`God ${num}`, `hello${num}@heaven.god`);
new Book2(`Bible ${num}.1`, god);
new Book2(`Bible ${num}.2`, god);
new Book2(`Bible ${num}.3`, god);
orm.em.persist(god);
}

await orm.em.flush();
orm.em.clear();

// without paginate flag it fails to get 5 records
const res1 = await orm.em.find(Author2, { books: { title: /^Bible/ } }, {
orderBy: { name: QueryOrder.ASC, books: { title: QueryOrder.ASC } },
offset: 3,
limit: 5,
});

expect(res1).toHaveLength(2);
expect(res1.map(a => a.name)).toEqual(['God 02', 'God 03']);

const mock = jest.fn();
const logger = new Logger(mock, true);
Object.assign(orm.em.config, { logger });

// with paginate flag (and a bit of dark sql magic) we get what we want
const res2 = await orm.em.find(Author2, { books: { title: /^Bible/ } }, {
orderBy: { name: QueryOrder.ASC, books: { title: QueryOrder.ASC } },
offset: 3,
limit: 5,
flags: [QueryFlag.PAGINATE],
});

expect(res2).toHaveLength(5);
expect(res2.map(a => a.name)).toEqual(['God 04', 'God 05', 'God 06', 'God 07', 'God 08']);
expect(mock.mock.calls[0][0]).toMatch('select "e0".* ' +
'from "author2" as "e0" ' +
'left join "book2" as "e1" on "e0"."id" = "e1"."author_id" where "e0"."id" in (select "e0"."id" ' +
'from (select "e0"."id" ' +
'from (select "e0"."id" ' +
'from "author2" as "e0" ' +
'left join "book2" as "e1" on "e0"."id" = "e1"."author_id" ' +
'where "e1"."title" like $1 order by "e0"."name" asc, "e1"."title" asc' +
') as "e0" group by "e0"."id" limit $2 offset $3' +
') as "e0"' +
') order by "e0"."name" asc, "e1"."title" asc');
});

test('exceptions', async () => {
const driver = orm.em.getDriver();
await driver.nativeInsert(Author2.name, { name: 'author', email: 'email' });
Expand Down
4 changes: 2 additions & 2 deletions tests/QueryBuilder.test.ts
@@ -1,6 +1,6 @@
import { inspect } from 'util';
import { LockMode, MikroORM, QueryOrder } from '@mikro-orm/core';
import { QueryFlag, CriteriaNode, ArrayCriteriaNode } from '@mikro-orm/knex';
import { LockMode, MikroORM, QueryFlag, QueryOrder } from '@mikro-orm/core';
import { CriteriaNode } from '@mikro-orm/knex';
import { MySqlDriver } from '@mikro-orm/mysql';
import { Author2, Book2, BookTag2, Car2, CarOwner2, FooBar2, FooBaz2, FooParam2, Publisher2, PublisherType, Test2, User2 } from './entities-sql';
import { initORMMySql } from './bootstrap';
Expand Down

0 comments on commit d43241e

Please sign in to comment.