diff --git a/docs/docs/query-builder.md b/docs/docs/query-builder.md index eb31bccbc244..98d369994442 100644 --- a/docs/docs/query-builder.md +++ b/docs/docs/query-builder.md @@ -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: diff --git a/docs/docs/upgrading-v5-to-v6.md b/docs/docs/upgrading-v5-to-v6.md index e91bd493486f..f8a77cc6d975 100644 --- a/docs/docs/upgrading-v5-to-v6.md +++ b/docs/docs/upgrading-v5-to-v6.md @@ -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' }); +``` diff --git a/packages/knex/src/query/QueryBuilder.ts b/packages/knex/src/query/QueryBuilder.ts index 1e90f03b9b5f..807779cf08f2 100644 --- a/packages/knex/src/query/QueryBuilder.ts +++ b/packages/knex/src/query/QueryBuilder.ts @@ -1,23 +1,11 @@ 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, @@ -25,19 +13,31 @@ import { 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'; @@ -213,23 +213,40 @@ export class QueryBuilder { return this.init(QueryType.COUNT) as CountQueryBuilder; } - join(field: string, alias: string, cond: QBFilterQuery = {}, type: 'leftJoin' | 'innerJoin' | 'pivotJoin' = 'innerJoin', path?: string, schema?: string): this { + join(field: string | Knex.QueryBuilder | QueryBuilder, 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, alias: string, cond: QBFilterQuery = {}, schema?: string): this { + this.join(field, alias, cond, 'innerJoin', undefined, schema); + return this; + } + + leftJoin(field: string | Knex.QueryBuilder | QueryBuilder, 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 { + joinAndSelect(field: string | [field: string, Knex.QueryBuilder | QueryBuilder], alias: string, cond: QBFilterQuery = {}, type: 'leftJoin' | 'innerJoin' | 'pivotJoin' = 'innerJoin', path?: string, fields?: string[], schema?: string): SelectQueryBuilder { 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); + + 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: [] }; @@ -244,11 +261,11 @@ export class QueryBuilder { return this as SelectQueryBuilder; } - leftJoinAndSelect(field: string, alias: string, cond: QBFilterQuery = {}, fields?: string[], schema?: string): SelectQueryBuilder { + leftJoinAndSelect(field: string | [field: string, Knex.QueryBuilder | QueryBuilder], alias: string, cond: QBFilterQuery = {}, fields?: string[], schema?: string): SelectQueryBuilder { return this.joinAndSelect(field, alias, cond, 'leftJoin', undefined, fields, schema); } - innerJoinAndSelect(field: string, alias: string, cond: QBFilterQuery = {}, fields?: string[], schema?: string): SelectQueryBuilder { + innerJoinAndSelect(field: string | [field: string, Knex.QueryBuilder | QueryBuilder], alias: string, cond: QBFilterQuery = {}, fields?: string[], schema?: string): SelectQueryBuilder { return this.joinAndSelect(field, alias, cond, 'innerJoin', undefined, fields, schema); } @@ -856,8 +873,34 @@ export class QueryBuilder { return qb; } - private joinReference(field: string, alias: string, cond: Dictionary, type: 'leftJoin' | 'innerJoin' | 'pivotJoin', path?: string, schema?: string): EntityProperty { + private joinReference(field: string | Knex.QueryBuilder | QueryBuilder, alias: string, cond: Dictionary, type: 'leftJoin' | 'innerJoin' | 'pivotJoin', path?: string, schema?: string): EntityProperty { 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); const q = (str: string) => `'${str}'`; diff --git a/packages/knex/src/query/QueryBuilderHelper.ts b/packages/knex/src/query/QueryBuilderHelper.ts index d0aa40909c2a..e82eeaa88a8e 100644 --- a/packages/knex/src/query/QueryBuilderHelper.ts +++ b/packages/knex/src/query/QueryBuilderHelper.ts @@ -227,19 +227,19 @@ export class QueryBuilderHelper { processJoins(qb: Knex.QueryBuilder, joins: Dictionary, 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); @@ -247,21 +247,38 @@ export class QueryBuilderHelper { 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); }); } diff --git a/packages/knex/src/typings.ts b/packages/knex/src/typings.ts index a04b6f674012..24a2e708c6c0 100644 --- a/packages/knex/src/typings.ts +++ b/packages/knex/src/typings.ts @@ -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 { diff --git a/tests/QueryBuilder.test.ts b/tests/QueryBuilder.test.ts index f3ae11fea21f..25fcb7f0fe83 100644 --- a/tests/QueryBuilder.test.ts +++ b/tests/QueryBuilder.test.ts @@ -2,6 +2,7 @@ import { inspect } from 'util'; import { LockMode, MikroORM, QueryFlag, QueryOrder, raw, sql, UnderscoreNamingStrategy } from '@mikro-orm/core'; import { CriteriaNode, QueryBuilder, PostgreSqlDriver } from '@mikro-orm/postgresql'; import { MySqlDriver } from '@mikro-orm/mysql'; +import { v4 } from 'uuid'; import { Address2, Author2, Book2, BookTag2, Car2, CarOwner2, Configuration2, FooBar2, FooBaz2, FooParam2, Publisher2, PublisherType, Test2, User2 } from './entities-sql'; import { initORMMySql, mockLogger } from './bootstrap'; import { BaseEntity2 } from './entities-sql/BaseEntity2'; @@ -390,7 +391,7 @@ describe('QueryBuilder', () => { const qb = orm.em.createQueryBuilder(Author2, 'a'); qb.select(['a.*', 'b.*']) .leftJoin('a.books', 'b', { - [raw('json_contains(`b`.`meta`, ?)', [{ 'b.foo': 'bar' }])]: [], + [sql`json_contains(b.meta, ${{ 'b.foo': 'bar' }})`]: [], [raw('json_contains(`b`.`meta`, ?) = ?', [{ 'b.foo': 'bar' }, false])]: [], [raw('lower(??)', ['b.title'])]: '321', }) @@ -398,7 +399,7 @@ describe('QueryBuilder', () => { expect(qb.getQuery()).toEqual('select `a`.*, `b`.* from `author2` as `a` ' + 'left join `book2` as `b` ' + 'on `a`.`id` = `b`.`author_id` ' + - 'and json_contains(`b`.`meta`, ?) ' + + 'and json_contains(b.meta, ?) ' + 'and json_contains(`b`.`meta`, ?) = ? ' + 'and lower(`b`.`title`) = ? ' + 'where `b`.`title` = ?'); @@ -406,7 +407,7 @@ describe('QueryBuilder', () => { expect(qb.getFormattedQuery()).toEqual('select `a`.*, `b`.* from `author2` as `a` ' + 'left join `book2` as `b` ' + 'on `a`.`id` = `b`.`author_id` ' + - 'and json_contains(`b`.`meta`, \'{\\"b.foo\\":\\"bar\\"}\') ' + + 'and json_contains(b.meta, \'{\\"b.foo\\":\\"bar\\"}\') ' + 'and json_contains(`b`.`meta`, \'{\\"b.foo\\":\\"bar\\"}\') = false ' + 'and lower(`b`.`title`) = \'321\' ' + "where `b`.`title` = 'test 123'"); @@ -1983,7 +1984,6 @@ describe('QueryBuilder', () => { }); test('select with sub-query', async () => { - const knex = orm.em.getKnex(); const qb1 = orm.em.createQueryBuilder(Book2, 'b').count('b.uuid', true).where({ author: sql.ref('a.id') }).as('Author2.booksTotal'); const qb2 = orm.em.createQueryBuilder(Author2, 'a'); qb2.select(['*', qb1]).orderBy({ booksTotal: 'desc' }); @@ -1998,7 +1998,6 @@ describe('QueryBuilder', () => { }); test('select where sub-query', async () => { - const knex = orm.em.getKnex(); const qb1 = orm.em.createQueryBuilder(Book2, 'b').count('b.uuid', true).where({ author: sql.ref('a.id') }).getKnexQuery(); const qb2 = orm.em.createQueryBuilder(Author2, 'a'); qb2.select('*').withSubQuery(qb1, 'a.booksTotal').where({ 'a.booksTotal': { $in: [1, 2, 3] } }); @@ -2022,6 +2021,89 @@ describe('QueryBuilder', () => { expect(qb8.getParams()).toEqual([100]); }); + test('join sub-query', async () => { + const author = await orm.em.insert(Author2, { name: 'a', email: 'e' }); + const t1 = await orm.em.insert(BookTag2, { name: 't1' }); + const t2 = await orm.em.insert(BookTag2, { name: 't2' }); + const t3 = await orm.em.insert(BookTag2, { name: 't3' }); + await orm.em.insert(Book2, { uuid: v4(), title: 'foo 1', author, price: 123, tags: [t1, t2, t3] }); + await orm.em.insert(Book2, { uuid: v4(), title: 'foo 2', author, price: 123, tags: [t1, t2, t3] }); + + // simple join with ORM subquery + const qb1 = orm.em.createQueryBuilder(Book2, 'b').limit(1).orderBy({ title: 1 }); + const qb2 = orm.em.createQueryBuilder(Author2, 'a'); + qb2.select(['*', 'sub.*']) + .leftJoin(qb1, 'sub', { author_id: sql.ref('a.id') }) + .where({ 'sub.title': /^foo/ }); + expect(qb2.getFormattedQuery()).toEqual('select `a`.*, `sub`.* from `author2` as `a` left join (select `b`.*, `b`.price * 1.19 as `price_taxed` from `book2` as `b` order by `b`.`title` asc limit 1) as `sub` on `sub`.`author_id` = `a`.`id` where `sub`.`title` like \'foo%\''); + const res2 = await qb2.execute(); + expect(res2).toHaveLength(1); + expect(res2[0]).toMatchObject({ + author_id: 1, + email: 'e', + foo: 'lol', + id: 1, + name: 'a', + price: '123.00', + price_taxed: '146.3700', + title: 'foo 1', + }); + orm.em.clear(); + + // simple join with knex subquery + const qb3 = orm.em.createQueryBuilder(Author2, 'a'); + qb3.select(['*', 'sub.*']) + .leftJoin(qb1.getKnexQuery(), 'sub', { author_id: sql.ref('a.id') }) + .where({ 'sub.title': /^foo/ }); + expect(qb2.getFormattedQuery()).toEqual('select `a`.*, `sub`.* from `author2` as `a` left join (select `b`.*, `b`.price * 1.19 as `price_taxed` from `book2` as `b` order by `b`.`title` asc limit 1) as `sub` on `sub`.`author_id` = `a`.`id` where `sub`.`title` like \'foo%\''); + const res3 = await qb3.execute(); + expect(res3).toHaveLength(1); + expect(res3[0]).toMatchObject({ + author_id: 1, + email: 'e', + foo: 'lol', + id: 1, + name: 'a', + price: '123.00', + price_taxed: '146.3700', + title: 'foo 1', + }); + orm.em.clear(); + + // using knex subquery to hydrate existing relation + const qb4 = orm.em.createQueryBuilder(Author2, 'a'); + qb4.select(['*']) + .leftJoinAndSelect(['a.books', qb1.getKnexQuery()], 'sub', { author: sql.ref('a.id') }) + .leftJoinAndSelect('sub.tags', 't') + .where({ 'sub.title': /^foo/ }); + expect(qb4.getFormattedQuery()).toEqual('select `a`.*, `sub`.`uuid_pk` as `sub__uuid_pk`, `sub`.`created_at` as `sub__created_at`, `sub`.`title` as `sub__title`, `sub`.`price` as `sub__price`, `sub`.price * 1.19 as `sub__price_taxed`, `sub`.`double` as `sub__double`, `sub`.`meta` as `sub__meta`, `sub`.`author_id` as `sub__author_id`, `sub`.`publisher_id` as `sub__publisher_id`, `t`.`id` as `t__id`, `t`.`name` as `t__name` from `author2` as `a` left join (select `b`.*, `b`.price * 1.19 as `price_taxed` from `book2` as `b` order by `b`.`title` asc limit 1) as `sub` on `sub`.`author_id` = `a`.`id` left join `book2_tags` as `e1` on `sub`.`uuid_pk` = `e1`.`book2_uuid_pk` left join `book_tag2` as `t` on `e1`.`book_tag2_id` = `t`.`id` where `sub`.`title` like \'foo%\''); + const res4 = await qb4.getResult(); + expect(res4).toHaveLength(1); + expect(res4[0]).toMatchObject({ + name: 'a', + email: 'e', + }); + expect(res4[0].books).toHaveLength(1); + expect(res4[0].books[0]).toMatchObject({ + title: 'foo 1', + price: '123.00', + priceTaxed: '146.3700', + }); + expect(res4[0].books[0].tags).toHaveLength(3); + orm.em.clear(); + + // with a regular join we get two books, as there is no limit + const qb5 = orm.em.createQueryBuilder(Author2, 'a'); + qb5.select(['*', 'sub.*']) + .leftJoinAndSelect('a.books', 'sub', { author: sql.ref('a.id') }) + .where({ 'sub.title': /^foo/ }); + expect(qb5.getFormattedQuery()).toEqual('select `a`.*, `sub`.*, `sub`.`uuid_pk` as `sub__uuid_pk`, `sub`.`created_at` as `sub__created_at`, `sub`.`title` as `sub__title`, `sub`.`price` as `sub__price`, `sub`.price * 1.19 as `sub__price_taxed`, `sub`.`double` as `sub__double`, `sub`.`meta` as `sub__meta`, `sub`.`author_id` as `sub__author_id`, `sub`.`publisher_id` as `sub__publisher_id` from `author2` as `a` left join `book2` as `sub` on `a`.`id` = `sub`.`author_id` and `sub`.`author_id` = `a`.`id` where `sub`.`title` like \'foo%\''); + const res5 = await qb5.getResult(); + expect(res5).toHaveLength(1); + expect(res5[0].books).toHaveLength(2); + orm.em.clear(); + }); + test('CriteriaNode', async () => { const node = new CriteriaNode(orm.em.getMetadata(), Author2.name); node.payload = { foo: 123 };