Skip to content

Commit

Permalink
feat(query-builder): allow joining sub-queries (#4747)
Browse files Browse the repository at this point in the history
Sometimes you might want to join a relation, but want to have more
control over the query. The ORM allows you to override the join target
with a sub-query, while keeping the original metadata for hydration:

```ts
// subquery can be a knex query builder as well
const subquery = await em.createQueryBuilder(Book, 'b')
  .where({ ... })
  .orderBy({ title: 'asc' }).limit(1);

const authors = await em.createQueryBuilder(Author, 'a')
  .select('*')
  // pass in both the property path and the subquery into the first argument as a tuple
  .leftJoinAndSelect(['a.books', subquery], 'b')
  // you can join more relations on top of the subquery join
  .leftJoinAndSelect('b.tags', 't')
  .getResultList();
```

This will produce query similar to the following:

```sql
select `a`.*,
  `b`.`id` as `b__id`, `b`.`title` as `b__title`, `b`.`author_id` as `b__author_id`, `b`.`publisher_id` as `b__publisher_id`,
  `t`.`id` as `t__id`, `t`.`name` as `t__name`
  from `author` as `a`
  left join (
    select `b`.*, `b`.price * 1.19 as `price_taxed`
    from `book` as `b`
    order by `b`.`title` asc
    limit 1
  ) as `b` on `b`.`author_id` = `a`.`id`
  left join `book_tags` as `e1` on `b`.`uuid_pk` = `e1`.`book_uuid_pk`
  left join `book_tag` as `t` on `e1`.`book_tag_id` = `t`.`id`
```

Closes #4429
Closes #4549
  • Loading branch information
B4nan committed Nov 5, 2023
1 parent 7cd0c6f commit 613332c
Show file tree
Hide file tree
Showing 6 changed files with 227 additions and 39 deletions.
36 changes: 36 additions & 0 deletions docs/docs/query-builder.md
Original file line number Diff line number Diff line change
Expand Up @@ -192,6 +192,42 @@ const res = await em.createQueryBuilder(Author, 'a')
.getResultList();
```

## Joining sub-queries

Sometimes you might want to join a relation, but want to have more control over the query. The ORM allows you to override the join target with a sub-query, while keeping the original metadata for hydration:

```ts
// subquery can be a knex query builder as well
const subquery = await em.createQueryBuilder(Book, 'b')
.where({ ... })
.orderBy({ title: 'asc' }).limit(1);

const authors = await em.createQueryBuilder(Author, 'a')
.select('*')
// pass in both the property path and the subquery into the first argument as a tuple
.leftJoinAndSelect(['a.books', subquery], 'b')
// you can join more relations on top of the subquery join
.leftJoinAndSelect('b.tags', 't')
.getResultList();
```

This will produce query similar to the following:

```sql
select `a`.*,
`b`.`id` as `b__id`, `b`.`title` as `b__title`, `b`.`author_id` as `b__author_id`, `b`.`publisher_id` as `b__publisher_id`,
`t`.`id` as `t__id`, `t`.`name` as `t__name`
from `author` as `a`
left join (
select `b`.*, `b`.price * 1.19 as `price_taxed`
from `book` as `b`
order by `b`.`title` asc
limit 1
) as `b` on `b`.`author_id` = `a`.`id`
left join `book_tags` as `e1` on `b`.`uuid_pk` = `e1`.`book_uuid_pk`
left join `book_tag` as `t` on `e1`.`book_tag_id` = `t`.`id`
```

## Complex Where Conditions

There are multiple ways to construct complex query conditions. You can either write parts of SQL manually, use `andWhere()`/`orWhere()`, or provide condition object:
Expand Down
9 changes: 9 additions & 0 deletions docs/docs/upgrading-v5-to-v6.md
Original file line number Diff line number Diff line change
Expand Up @@ -387,3 +387,12 @@ id2: string;
@PrimaryKey({ type: new BigIntType('number') })
id3: number;
```

## Join condition alias

Additional join conditions used to be implicitly aliased to the root entity, now they are aliased to the joined entity instead. If you are using explicit aliases in the join conditions, nothing changes.

```ts
// the `name` used to resolve to `b.name`, now it will resolve to `a.name` instead
qb.join('b.author', 'a', { name: 'foo' });
```
87 changes: 65 additions & 22 deletions packages/knex/src/query/QueryBuilder.ts
Original file line number Diff line number Diff line change
@@ -1,43 +1,43 @@
import { inspect } from 'util';
import type { Knex } from 'knex';
import {
helper,
LoadStrategy,
LockMode,
PopulateHint,
QueryFlag,
QueryHelper,
raw,
RawQueryFragment,
ReferenceKind,
serialize,
Utils,
ValidationError,
type AnyEntity,
type EntityKey,
type ConnectionType,
type Dictionary,
type EntityData,
type EntityKey,
type EntityMetadata,
type EntityName,
type EntityProperty,
type FilterQuery,
type FlatQueryOrderMap,
type FlushMode,
type GroupOperator,
helper,
LoadStrategy,
LockMode,
type LoggingOptions,
type MetadataStorage,
type ObjectQuery,
PopulateHint,
type PopulateOptions,
type QBFilterQuery,
type QBQueryOrderMap,
QueryFlag,
QueryHelper,
type QueryOrderMap,
type QueryResult,
raw,
RawQueryFragment,
ReferenceKind,
type RequiredEntityData,
type LoggingOptions,
serialize,
Utils,
ValidationError,
} from '@mikro-orm/core';
import { QueryType } from './enums';
import type { AbstractSqlDriver } from '../AbstractSqlDriver';
import { QueryBuilderHelper, type Alias } from './QueryBuilderHelper';
import { type Alias, QueryBuilderHelper } from './QueryBuilderHelper';
import type { SqlEntityManager } from '../SqlEntityManager';
import { CriteriaNodeFactory } from './CriteriaNodeFactory';
import type { Field, JoinOptions } from '../typings';
Expand Down Expand Up @@ -213,23 +213,40 @@ export class QueryBuilder<T extends object = AnyEntity> {
return this.init(QueryType.COUNT) as CountQueryBuilder<T>;
}

join(field: string, alias: string, cond: QBFilterQuery = {}, type: 'leftJoin' | 'innerJoin' | 'pivotJoin' = 'innerJoin', path?: string, schema?: string): this {
join(field: string | Knex.QueryBuilder | QueryBuilder<any>, alias: string, cond: QBFilterQuery = {}, type: 'leftJoin' | 'innerJoin' | 'pivotJoin' = 'innerJoin', path?: string, schema?: string): this {
this.joinReference(field, alias, cond, type, path, schema);
return this;
}

leftJoin(field: string, alias: string, cond: QBFilterQuery = {}, schema?: string): this {
innerJoin(field: string | Knex.QueryBuilder | QueryBuilder<any>, alias: string, cond: QBFilterQuery = {}, schema?: string): this {
this.join(field, alias, cond, 'innerJoin', undefined, schema);
return this;
}

leftJoin(field: string | Knex.QueryBuilder | QueryBuilder<any>, alias: string, cond: QBFilterQuery = {}, schema?: string): this {
return this.join(field, alias, cond, 'leftJoin', undefined, schema);
}

joinAndSelect(field: string, alias: string, cond: QBFilterQuery = {}, type: 'leftJoin' | 'innerJoin' | 'pivotJoin' = 'innerJoin', path?: string, fields?: string[], schema?: string): SelectQueryBuilder<T> {
joinAndSelect(field: string | [field: string, Knex.QueryBuilder | QueryBuilder<any>], alias: string, cond: QBFilterQuery = {}, type: 'leftJoin' | 'innerJoin' | 'pivotJoin' = 'innerJoin', path?: string, fields?: string[], schema?: string): SelectQueryBuilder<T> {
if (!this.type) {
this.select('*');
}

let subquery!: string;

if (Array.isArray(field)) {
subquery = field[1] instanceof QueryBuilder ? field[1].getFormattedQuery() : field[1].toString();
field = field[0];
}

const prop = this.joinReference(field, alias, cond, type, path, schema);
this.addSelect(this.getFieldsForJoinedLoad(prop, alias, fields));
const [fromAlias] = this.helper.splitField(field as EntityKey<T>);

if (subquery) {
this._joins[`${fromAlias}.${prop.name}#${alias}`].subquery = subquery;
}

this.addSelect(this.getFieldsForJoinedLoad(prop, alias, fields));
const populate = this._joinedProps.get(fromAlias);
const item = { field: prop.name, strategy: LoadStrategy.JOINED, children: [] };

Expand All @@ -244,11 +261,11 @@ export class QueryBuilder<T extends object = AnyEntity> {
return this as SelectQueryBuilder<T>;
}

leftJoinAndSelect(field: string, alias: string, cond: QBFilterQuery = {}, fields?: string[], schema?: string): SelectQueryBuilder<T> {
leftJoinAndSelect(field: string | [field: string, Knex.QueryBuilder | QueryBuilder<any>], alias: string, cond: QBFilterQuery = {}, fields?: string[], schema?: string): SelectQueryBuilder<T> {
return this.joinAndSelect(field, alias, cond, 'leftJoin', undefined, fields, schema);
}

innerJoinAndSelect(field: string, alias: string, cond: QBFilterQuery = {}, fields?: string[], schema?: string): SelectQueryBuilder<T> {
innerJoinAndSelect(field: string | [field: string, Knex.QueryBuilder | QueryBuilder<any>], alias: string, cond: QBFilterQuery = {}, fields?: string[], schema?: string): SelectQueryBuilder<T> {
return this.joinAndSelect(field, alias, cond, 'innerJoin', undefined, fields, schema);
}

Expand Down Expand Up @@ -856,8 +873,34 @@ export class QueryBuilder<T extends object = AnyEntity> {
return qb;
}

private joinReference(field: string, alias: string, cond: Dictionary, type: 'leftJoin' | 'innerJoin' | 'pivotJoin', path?: string, schema?: string): EntityProperty<T> {
private joinReference(field: string | Knex.QueryBuilder | QueryBuilder, alias: string, cond: Dictionary, type: 'leftJoin' | 'innerJoin' | 'pivotJoin', path?: string, schema?: string): EntityProperty<T> {
this.ensureNotFinalized();

if (typeof field === 'object') {
const prop = {
name: '__subquery__',
kind: ReferenceKind.MANY_TO_ONE,
} as EntityProperty;

if (field instanceof QueryBuilder) {
prop.type = field.mainAlias.entityName;
prop.targetMeta = field.mainAlias.metadata!;
field = field.getKnexQuery();
}

this._joins[`${this.alias}.${prop.name}#${alias}`] = {
prop,
alias,
type,
cond,
schema,
subquery: field.toString(),
ownerAlias: this.alias,
} as any;

return prop;
}

const [fromAlias, fromField] = this.helper.splitField(field as EntityKey<T>);
const q = (str: string) => `'${str}'`;

Expand Down
41 changes: 29 additions & 12 deletions packages/knex/src/query/QueryBuilderHelper.ts
Original file line number Diff line number Diff line change
Expand Up @@ -227,41 +227,58 @@ export class QueryBuilderHelper {

processJoins(qb: Knex.QueryBuilder, joins: Dictionary<JoinOptions>, schema?: string): void {
Object.values(joins).forEach(join => {
let table = `${join.table} as ${join.alias}`;
let table = join.table;
const method = join.type === 'innerJoin' ? 'inner join' : 'left join';
const conditions: string[] = [];
const params: Knex.Value[] = [];
schema = join.schema && join.schema !== '*' ? join.schema : schema;

if (schema) {
table = `${schema}.${table}`;
}

const conditions: string[] = [];
const params: Knex.Value[] = [];

join.primaryKeys!.forEach((primaryKey, idx) => {
const right = `${join.alias}.${join.joinColumns![idx]}`;
if (!join.subquery) {
join.primaryKeys!.forEach((primaryKey, idx) => {
const right = `${join.alias}.${join.joinColumns![idx]}`;

if (join.prop.formula) {
const left = join.prop.formula(join.ownerAlias);
conditions.push(`${left} = ${this.knex.ref(right)}`);
return;
}

const left = `${join.ownerAlias}.${primaryKey}`;
conditions.push(`${this.knex.ref(left)} = ${this.knex.ref(right)}`);
});
const left = `${join.ownerAlias}.${primaryKey}`;
conditions.push(`${this.knex.ref(left)} = ${this.knex.ref(right)}`);
});
}

if (join.prop.targetMeta!.discriminatorValue && !join.path?.endsWith('[pivot]')) {
if (join.prop.targetMeta?.discriminatorValue && !join.path?.endsWith('[pivot]')) {
const typeProperty = join.prop.targetMeta!.root.discriminatorColumn!;
const alias = join.inverseAlias ?? join.alias;
join.cond[`${alias}.${typeProperty}`] = join.prop.targetMeta!.discriminatorValue;
}

Object.keys(join.cond).forEach(key => {
conditions.push(this.processJoinClause(key, join.cond[key], params));
const needsPrefix = key.includes('.') || Utils.isOperator(key) || RawQueryFragment.isKnownFragment(key);
const newKey = needsPrefix ? key : `${join.alias}.${key}`;
conditions.push(this.processJoinClause(newKey, join.cond[key], params));
});

return qb.joinRaw(`${method} ${this.knex.ref(table)} on ${conditions.join(' and ')}`, params);
let sql = method + ' ';

if (join.subquery) {
sql += `(${join.subquery})`;
} else {
sql += this.knex.ref(table);
}

sql += ` as ${this.knex.ref(join.alias)}`;

if (conditions.length > 0) {
sql += ` on ${conditions.join(' and ')}`;
}

return qb.joinRaw(sql, params);
});
}

Expand Down
1 change: 1 addition & 0 deletions packages/knex/src/typings.ts
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,7 @@ export interface JoinOptions {
// used as cache when overriding the on condition via `populateWhere` as we need
// to revert the change when wrapping queries when pagination is triggered.
cond_?: Dictionary;
subquery?: string;
}

export interface Column {
Expand Down
Loading

0 comments on commit 613332c

Please sign in to comment.