Skip to content

Commit

Permalink
feat(query-builder): allow mapping of complex joined results (#988)
Browse files Browse the repository at this point in the history
To select multiple entities and map them from `QueryBuilder`, we can use
`joinAndSelect` or `leftJoinAndSelect` method:

```ts
// `res` will contain array of authors, with books and their tags populated
const res = await orm.em.createQueryBuilder(Author, 'a')
  .select('*')
  .leftJoinAndSelect('a.books', 'b')
  .leftJoinAndSelect('b.tags', 't')
  .where({ 't.name': ['sick', 'sexy'] })
  .getResultList();
```

Closes #932
  • Loading branch information
B4nan committed Oct 26, 2020
1 parent ddab271 commit 60dd2d8
Show file tree
Hide file tree
Showing 9 changed files with 147 additions and 21 deletions.
15 changes: 15 additions & 0 deletions docs/docs/query-builder.md
Original file line number Diff line number Diff line change
Expand Up @@ -177,6 +177,21 @@ console.log(qb.getQuery());
// limit ? offset ?
```

## Mapping joined results

To select multiple entities and map them from `QueryBuilder`, we can use
`joinAndSelect` or `leftJoinAndSelect` method:

```ts
// `res` will contain array of authors, with books and their tags populated
const res = await orm.em.createQueryBuilder(Author, 'a')
.select('*')
.leftJoinAndSelect('a.books', 'b')
.leftJoinAndSelect('b.tags', 't')
.where({ 't.name': ['sick', 'sexy'] })
.getResultList();
```

## Complex Where Conditions

There are multiple ways to construct complex query conditions. You can either write parts of SQL
Expand Down
5 changes: 4 additions & 1 deletion packages/core/src/drivers/DatabaseDriver.ts
Original file line number Diff line number Diff line change
Expand Up @@ -204,7 +204,10 @@ export abstract class DatabaseDriver<C extends Connection> implements IDatabaseD
throw new Error(`Pessimistic locks are not supported by ${this.constructor.name} driver`);
}

protected shouldHaveColumn<T extends AnyEntity<T>>(prop: EntityProperty<T>, populate: PopulateOptions<T>[], includeFormulas = true): boolean {
/**
* @internal
*/
shouldHaveColumn<T extends AnyEntity<T>>(prop: EntityProperty<T>, populate: PopulateOptions<T>[], includeFormulas = true): boolean {
if (prop.formula) {
return includeFormulas;
}
Expand Down
10 changes: 8 additions & 2 deletions packages/knex/src/AbstractSqlDriver.ts
Original file line number Diff line number Diff line change
Expand Up @@ -434,7 +434,10 @@ export abstract class AbstractSqlDriver<C extends AbstractSqlConnection = Abstra
});
}

protected mergeJoinedResult<T extends AnyEntity<T>>(rawResults: Dictionary[], meta: EntityMetadata<T>): EntityData<T>[] {
/**
* @internal
*/
mergeJoinedResult<T extends AnyEntity<T>>(rawResults: Dictionary[], meta: EntityMetadata<T>): EntityData<T>[] {
// group by the root entity primary key first
const res = rawResults.reduce((result, item) => {
const pk = Utils.getCompositeKeyHash<T>(item as T, meta);
Expand Down Expand Up @@ -469,7 +472,10 @@ export abstract class AbstractSqlDriver<C extends AbstractSqlConnection = Abstra
return fields;
}

protected mapPropToFieldNames<T extends AnyEntity<T>>(qb: QueryBuilder<T>, prop: EntityProperty<T>, tableAlias?: string): Field<T>[] {
/**
* @internal
*/
mapPropToFieldNames<T extends AnyEntity<T>>(qb: QueryBuilder<T>, prop: EntityProperty<T>, tableAlias?: string): Field<T>[] {
if (prop.formula) {
const alias = qb.ref(tableAlias ?? qb.alias).toString();
const aliased = qb.ref(tableAlias ? `${tableAlias}_${prop.fieldNames[0]}` : prop.fieldNames[0]).toString();
Expand Down
63 changes: 55 additions & 8 deletions packages/knex/src/query/QueryBuilder.ts
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
import { QueryBuilder as KnexQueryBuilder, Raw, Transaction, Value } from 'knex';
import {
AnyEntity, Dictionary, EntityMetadata, FlatQueryOrderMap, GroupOperator, LockMode, MetadataStorage,
PopulateOptions, QBFilterQuery, QueryFlag, QueryHelper, QueryOrderMap, ReferenceType, Utils, ValidationError,
AnyEntity, Dictionary, EntityMetadata, EntityProperty, FlatQueryOrderMap, GroupOperator, LockMode, MetadataStorage, EntityData,
PopulateOptions, QBFilterQuery, QueryFlag, QueryHelper, QueryOrderMap, ReferenceType, Utils, ValidationError, LoadStrategy,
} from '@mikro-orm/core';
import { QueryType } from './enums';
import { AbstractSqlDriver } from '../AbstractSqlDriver';
Expand Down Expand Up @@ -33,6 +33,7 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
private _having: Dictionary = {};
private _limit?: number;
private _offset?: number;
private _joinedProps = new Map<string, PopulateOptions<any>>();
private _cache?: boolean | number | [string, number];
private lockMode?: LockMode;
private subQueries: Dictionary<string> = {};
Expand Down Expand Up @@ -60,7 +61,7 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
return this.init(QueryType.SELECT);
}

addSelect(fields: string | string[]): this {
addSelect(fields: Field<T> | Field<T>[]): this {
if (this.type && this.type !== QueryType.SELECT) {
return this;
}
Expand Down Expand Up @@ -103,6 +104,38 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
return this.join(field, alias, cond, 'leftJoin');
}

joinAndSelect(field: string, alias: string, cond: QBFilterQuery = {}, type: 'leftJoin' | 'innerJoin' | 'pivotJoin' = 'innerJoin', path?: string): this {
const prop = this.joinReference(field, alias, cond, type, path);
this.addSelect(this.getFieldsForJoinedLoad<T>(prop, alias));
const [fromAlias] = this.helper.splitField(field);
const populate = this._joinedProps.get(fromAlias);
const item = { field: prop.name, strategy: LoadStrategy.JOINED, children: [] };

if (populate) {
populate.children!.push(item);
} else { // root entity
this._populate.push(item);
}

this._joinedProps.set(alias, item);

return this;
}

leftJoinAndSelect(field: string, alias: string, cond: QBFilterQuery = {}): this {
return this.joinAndSelect(field, alias, cond, 'leftJoin');
}

protected getFieldsForJoinedLoad<U extends AnyEntity<U>>(prop: EntityProperty<U>, alias: string): Field<U>[] {
const fields: Field<U>[] = [];
const meta2 = this.metadata.find<U>(prop.type)!;
meta2.props
.filter(prop => this.driver.shouldHaveColumn(prop, this._populate))
.forEach(prop => fields.push(...this.driver.mapPropToFieldNames<U>(this as unknown as QueryBuilder<U>, prop, alias)));

return fields;
}

withSubQuery(subQuery: KnexQueryBuilder, alias: string): this {
this.subQueries[alias] = subQuery.toString();
return this;
Expand Down Expand Up @@ -347,15 +380,20 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
* Executes the query, returning array of results
*/
async getResultList(): Promise<T[]> {
const res = await this.execute<T[]>('all', true);
let res = await this.execute<EntityData<T>[]>('all', true);

if (this._joinedProps.size > 0) {
res = this.driver.mergeJoinedResult(res, this.metadata.find(this.entityName)!);
}

return res.map(r => this.em!.map<T>(this.entityName, r));
}

/**
* Executes the query, returning the first result or null
*/
async getSingleResult(): Promise<T | null> {
const res = await this.getResult();
const res = await this.getResultList();
return res[0] || null;
}

Expand All @@ -381,7 +419,7 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
Object.assign(qb, this);

// clone array/object properties
const properties = ['flags', '_fields', '_populate', '_populateMap', '_joins', '_aliasMap', '_cond', '_data', '_orderBy', '_schema', '_cache', 'subQueries'];
const properties = ['flags', '_fields', '_populate', '_populateMap', '_joins', '_joinedProps', '_aliasMap', '_cond', '_data', '_orderBy', '_schema', '_cache', 'subQueries'];
properties.forEach(prop => (qb as any)[prop] = Utils.copy(this[prop as keyof this]));
qb.finalized = false;

Expand All @@ -399,13 +437,20 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
return qb;
}

private joinReference(field: string, alias: string, cond: Dictionary, type: 'leftJoin' | 'innerJoin' | 'pivotJoin', path?: string): void {
private joinReference(field: string, alias: string, cond: Dictionary, type: 'leftJoin' | 'innerJoin' | 'pivotJoin', path?: string): EntityProperty {
const [fromAlias, fromField] = this.helper.splitField(field);
const entityName = this._aliasMap[fromAlias];
const prop = this.metadata.get(entityName).properties[fromField];
const meta = this.metadata.get(entityName);
const prop = meta.properties[fromField];

if (!prop) {
throw new Error(`Trying to join ${field}, but ${fromField} is not a defined relation on ${meta.className}`);
}

this._aliasMap[alias] = prop.type;
cond = QueryHelper.processWhere(cond, this.entityName, this.metadata, this.platform)!;
const aliasedName = `${fromAlias}.${prop.name}`;
path = path ?? `${(Object.values(this._joins).find(j => j.alias === fromAlias)?.path ?? entityName)}.${prop.name}`;

if (prop.reference === ReferenceType.ONE_TO_MANY) {
this._joins[aliasedName] = this.helper.joinOneToReference(prop, fromAlias, alias, type, cond);
Expand All @@ -429,6 +474,8 @@ export class QueryBuilder<T extends AnyEntity<T> = AnyEntity> {
if (!this._joins[aliasedName].path && path) {
this._joins[aliasedName].path = path;
}

return prop;
}

private prepareFields<T extends AnyEntity<T>, U extends string | Raw = string | Raw>(fields: Field<T>[], type: 'where' | 'groupBy' | 'sub-query' = 'where'): U[] {
Expand Down
11 changes: 3 additions & 8 deletions packages/knex/src/query/QueryBuilderHelper.ts
Original file line number Diff line number Diff line change
Expand Up @@ -117,7 +117,7 @@ export class QueryBuilderHelper {
};
}

joinManyToManyReference(prop: EntityProperty, ownerAlias: string, alias: string, pivotAlias: string, type: 'leftJoin' | 'innerJoin' | 'pivotJoin', cond: Dictionary, path?: string): Dictionary<JoinOptions> {
joinManyToManyReference(prop: EntityProperty, ownerAlias: string, alias: string, pivotAlias: string, type: 'leftJoin' | 'innerJoin' | 'pivotJoin', cond: Dictionary, path: string): Dictionary<JoinOptions> {
const ret = {
[`${ownerAlias}.${prop.name}`]: {
prop, type, cond, ownerAlias,
Expand All @@ -127,23 +127,18 @@ export class QueryBuilderHelper {
inverseJoinColumns: prop.inverseJoinColumns,
primaryKeys: prop.referencedColumnNames,
table: prop.pivotTable,
path: path.endsWith('[pivot]') ? path : `${path}[pivot]`,
} as JoinOptions,
};

if (path) {
ret[`${ownerAlias}.${prop.name}`].path = path.endsWith('[pivot]') ? path : `${path}[pivot]`;
}

if (type === 'pivotJoin') {
return ret;
}

const prop2 = this.metadata.find(prop.pivotTable)!.properties[prop.type + (prop.owner ? '_inverse' : '_owner')];
ret[`${pivotAlias}.${prop2.name}`] = this.joinManyToOneReference(prop2, pivotAlias, alias, type);

if (path) {
ret[`${pivotAlias}.${prop2.name}`].path = path;
}
ret[`${pivotAlias}.${prop2.name}`].path = path;

return ret;
}
Expand Down
2 changes: 1 addition & 1 deletion packages/mongodb/src/MongoDriver.ts
Original file line number Diff line number Diff line change
Expand Up @@ -280,7 +280,7 @@ export class MongoDriver extends DatabaseDriver<MongoConnection> {
return fields;
}

protected shouldHaveColumn<T>(prop: EntityProperty<T>, populate: PopulateOptions<T>[]): boolean {
shouldHaveColumn<T>(prop: EntityProperty<T>, populate: PopulateOptions<T>[]): boolean {
if (super.shouldHaveColumn(prop, populate)) {
return true;
}
Expand Down
2 changes: 1 addition & 1 deletion tests/EntityManager.mysql.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -755,7 +755,7 @@ describe('EntityManagerMySql', () => {
const qb2 = orm.em.createQueryBuilder(Book2);
const res2 = await qb2.select('*').where({ title: 'not exists' }).getSingleResult();
expect(res2).toBeNull();
const res3 = await qb1.select('*').getResultList();
const res3 = await qb1.select('*').getResult();
expect(res3).toHaveLength(1);
});

Expand Down
38 changes: 38 additions & 0 deletions tests/EntityManager.sqlite2.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -854,6 +854,44 @@ describe('EntityManagerSqlite2', () => {
expect(b4.object).toBe(123);
});

test('mapping joined results from query builder', async () => {
const author = orm.em.create(Author4, { name: 'Jon Snow', email: 'snow@wall.st' });
const book1 = orm.em.create(Book4, { title: 'My Life on the Wall, part 1', author });
const book2 = orm.em.create(Book4, { title: 'My Life on the Wall, part 2', author });
const book3 = orm.em.create(Book4, { title: 'My Life on the Wall, part 3', author });
const tag1 = orm.em.create(BookTag4, { name: 'silly' });
const tag2 = orm.em.create(BookTag4, { name: 'funny' });
const tag3 = orm.em.create(BookTag4, { name: 'sick' });
const tag4 = orm.em.create(BookTag4, { name: 'strange' });
const tag5 = orm.em.create(BookTag4, { name: 'sexy' });
book1.tags.add(tag1, tag3);
book2.tags.add(tag1, tag2, tag5);
book3.tags.add(tag2, tag4, tag5);

await orm.em.persist([book1, book2, book3]).flush();
orm.em.clear();

const qb = orm.em.createQueryBuilder(Author4, 'a');
qb.select('*')
.leftJoinAndSelect('a.books', 'b')
.leftJoinAndSelect('b.tags', 't')
.where({ 't.name': ['sick', 'sexy'] });
const sql = 'select `a`.*, ' +
'`b`.`id` as `b_id`, `b`.`created_at` as `b_created_at`, `b`.`updated_at` as `b_updated_at`, `b`.`title` as `b_title`, `b`.`author_id` as `b_author_id`, `b`.`publisher_id` as `b_publisher_id`, `b`.`meta` as `b_meta`, ' +
'`t`.`id` as `t_id`, `t`.`created_at` as `t_created_at`, `t`.`updated_at` as `t_updated_at`, `t`.`name` as `t_name`, `t`.`version` as `t_version` ' +
'from `author4` as `a` ' +
'left join `book4` as `b` on `a`.`id` = `b`.`author_id` ' +
'left join `tags_ordered` as `e1` on `b`.`id` = `e1`.`book4_id` ' +
'left join `book_tag4` as `t` on `e1`.`book_tag4_id` = `t`.`id` ' +
'where `t`.`name` in (\'sick\', \'sexy\')';
expect(qb.getFormattedQuery()).toEqual(sql);
const res = await qb.getSingleResult();
expect(res).not.toBeNull();
expect(res!.books[0]).not.toBeNull();
expect(res!.books[0].title).toBe('My Life on the Wall, part 1');
expect(res!.books[0].tags[0].name).toBe('sick');
});

test('question marks and parameter interpolation (GH issue #920)', async () => {
const e = orm.em.create(Author4, { name: `?baz? uh \\? ? wut? \\\\ wut`, email: '123' });
await orm.em.persistAndFlush(e);
Expand Down
22 changes: 22 additions & 0 deletions tests/QueryBuilder.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -181,6 +181,28 @@ describe('QueryBuilder', () => {
expect(qb.getParams()).toEqual(['test 123', 2, 1]);
});

test('complex select with mapping of joined results', async () => {
const qb = orm.em.createQueryBuilder(FooBar2, 'fb1');
qb.select('*').leftJoinAndSelect('fb1.baz', 'fz');

const err = `Trying to join fz.fooBar, but fooBar is not a defined relation on FooBaz2`;
expect(() => qb.leftJoinAndSelect('fz.fooBar', 'fb2')).toThrowError(err);

qb.leftJoinAndSelect('fz.bar', 'fb2')
.where({ 'fz.name': 'baz' })
.limit(1);
const sql = 'select `fb1`.*, ' +
'`fz`.`id` as `fz_id`, `fz`.`name` as `fz_name`, `fz`.`version` as `fz_version`, ' +
'`fb2`.`id` as `fb2_id`, `fb2`.`name` as `fb2_name`, `fb2`.`baz_id` as `fb2_baz_id`, `fb2`.`foo_bar_id` as `fb2_foo_bar_id`, `fb2`.`version` as `fb2_version`, `fb2`.`blob` as `fb2_blob`, `fb2`.`array` as `fb2_array`, `fb2`.`object` as `fb2_object`, (select 123) as `fb2_random`, ' +
'(select 123) as `random` from `foo_bar2` as `fb1` ' +
'left join `foo_baz2` as `fz` on `fb1`.`baz_id` = `fz`.`id` ' +
'left join `foo_bar2` as `fb2` on `fz`.`id` = `fb2`.`baz_id` ' +
'where `fz`.`name` = ? ' +
'limit ?';
expect(qb.getQuery()).toEqual(sql);
expect(qb.getParams()).toEqual(['baz', 1]);
});

test('select leftJoin 1:1 inverse', async () => {
const qb = orm.em.createQueryBuilder(FooBaz2, 'fz');
qb.select(['fb.*', 'fz.*'])
Expand Down

0 comments on commit 60dd2d8

Please sign in to comment.