From 7cc1848fd4a44aefa986026ee659ed872ea6ab8f Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Micha=C5=82=20Wadas?= Date: Wed, 23 Mar 2022 14:29:45 +0100 Subject: [PATCH] feat: support for Common Table Expressions (#8534) * feat: support for Common Table Expressions Resolves #1116 #5899 * test: disable test for #4753 if no MySQL is present in ormconfig.json --- docs/select-query-builder.md | 34 ++++ src/driver/Driver.ts | 3 + src/driver/aurora-mysql/AuroraMysqlDriver.ts | 5 + src/driver/cockroachdb/CockroachDriver.ts | 8 + src/driver/mongodb/MongoDriver.ts | 5 + src/driver/mysql/MysqlDriver.ts | 23 ++- src/driver/oracle/OracleDriver.ts | 5 + src/driver/postgres/PostgresDriver.ts | 8 + src/driver/sap/SapDriver.ts | 5 + .../sqlite-abstract/AbstractSqliteDriver.ts | 6 + src/driver/sqlserver/SqlServerDriver.ts | 7 + src/driver/types/CteCapabilities.ts | 20 +++ src/query-builder/DeleteQueryBuilder.ts | 1 + src/query-builder/InsertQueryBuilder.ts | 1 + src/query-builder/QueryBuilder.ts | 95 ++++++++++++ src/query-builder/QueryBuilderCte.ts | 17 ++ src/query-builder/QueryExpressionMap.ts | 18 +++ src/query-builder/SelectQueryBuilder.ts | 1 + src/query-builder/SoftDeleteQueryBuilder.ts | 1 + src/query-builder/UpdateQueryBuilder.ts | 1 + .../query-builder/cte/entity/foo.ts | 12 ++ test/functional/query-builder/cte/helpers.ts | 9 ++ .../query-builder/cte/recursive-cte.ts | 49 ++++++ .../query-builder/cte/simple-cte.ts | 146 ++++++++++++++++++ test/github-issues/4753/issue-4753.ts | 38 ++++- 25 files changed, 505 insertions(+), 13 deletions(-) create mode 100644 src/driver/types/CteCapabilities.ts create mode 100644 src/query-builder/QueryBuilderCte.ts create mode 100644 test/functional/query-builder/cte/entity/foo.ts create mode 100644 test/functional/query-builder/cte/helpers.ts create mode 100644 test/functional/query-builder/cte/recursive-cte.ts create mode 100644 test/functional/query-builder/cte/simple-cte.ts diff --git a/docs/select-query-builder.md b/docs/select-query-builder.md index 6b851c3064..5f7eb3e1c5 100644 --- a/docs/select-query-builder.md +++ b/docs/select-query-builder.md @@ -1155,3 +1155,37 @@ const users = await dataSource ``` You will get all the rows, including the ones which are deleted. + +## Common table expressions + +`QueryBuilder` instances +support [common table expressions](https://en.wikipedia.org/wiki/Hierarchical_and_recursive_queries_in_SQL#Common_table_expression) +, if minimal supported version of your database supports them. Common table expressions aren't supported for Oracle yet. + +```typescript +const users = await connection.getRepository(User) + .createQueryBuilder('user') + .select("user.id", 'id') + .addCommonTableExpression(` + SELECT "userId" FROM "post" + `, 'post_users_ids') + .where(`user.id IN (SELECT "userId" FROM 'post_users_ids')`) + .getMany(); +``` + +Result values of `InsertQueryBuilder` or `UpdateQueryBuilder` can be used in Postgres: + +```typescript +const insertQueryBuilder = await connection.getRepository(User) + .createQueryBuilder() + .insert({ + name: 'John Smith' + }) + .returning(['id']); + +const users = await connection.getRepository(User) + .createQueryBuilder('user') + .addCommonTableExpression(insertQueryBuilder, 'insert_results') + .where(`user.id IN (SELECT "id" FROM 'insert_results')`) + .getMany(); +``` diff --git a/src/driver/Driver.ts b/src/driver/Driver.ts index ac16ee7992..4be6fdbf6b 100644 --- a/src/driver/Driver.ts +++ b/src/driver/Driver.ts @@ -2,6 +2,7 @@ import { QueryRunner } from "../query-runner/QueryRunner" import { ColumnMetadata } from "../metadata/ColumnMetadata" import { ObjectLiteral } from "../common/ObjectLiteral" import { ColumnType } from "./types/ColumnTypes" +import { CteCapabilities } from "./types/CteCapabilities" import { MappedColumnTypes } from "./types/MappedColumnTypes" import { SchemaBuilder } from "../schema-builder/SchemaBuilder" import { DataTypeDefaults } from "./types/DataTypeDefaults" @@ -99,6 +100,8 @@ export interface Driver { */ maxAliasLength?: number + cteCapabilities: CteCapabilities + /** * Performs connection to the database. * Depend on driver type it may create a connection pool. diff --git a/src/driver/aurora-mysql/AuroraMysqlDriver.ts b/src/driver/aurora-mysql/AuroraMysqlDriver.ts index 33303b3a45..dc6a1b06ac 100644 --- a/src/driver/aurora-mysql/AuroraMysqlDriver.ts +++ b/src/driver/aurora-mysql/AuroraMysqlDriver.ts @@ -1,5 +1,6 @@ import { Driver } from "../Driver" import { DriverUtils } from "../DriverUtils" +import { CteCapabilities } from "../types/CteCapabilities" import { AuroraMysqlQueryRunner } from "./AuroraMysqlQueryRunner" import { ObjectLiteral } from "../../common/ObjectLiteral" import { ColumnMetadata } from "../../metadata/ColumnMetadata" @@ -310,6 +311,10 @@ export class AuroraMysqlDriver implements Driver { */ maxAliasLength = 63 + cteCapabilities: CteCapabilities = { + enabled: false, + } + // ------------------------------------------------------------------------- // Constructor // ------------------------------------------------------------------------- diff --git a/src/driver/cockroachdb/CockroachDriver.ts b/src/driver/cockroachdb/CockroachDriver.ts index 1311e68531..40d3e980fd 100644 --- a/src/driver/cockroachdb/CockroachDriver.ts +++ b/src/driver/cockroachdb/CockroachDriver.ts @@ -4,6 +4,7 @@ import { ObjectLiteral } from "../../common/ObjectLiteral" import { DriverPackageNotInstalledError } from "../../error/DriverPackageNotInstalledError" import { DriverUtils } from "../DriverUtils" import { ColumnMetadata } from "../../metadata/ColumnMetadata" +import { CteCapabilities } from "../types/CteCapabilities" import { CockroachConnectionCredentialsOptions } from "./CockroachConnectionCredentialsOptions" import { CockroachConnectionOptions } from "./CockroachConnectionOptions" import { DateUtils } from "../../util/DateUtils" @@ -230,6 +231,13 @@ export class CockroachDriver implements Driver { */ maxAliasLength?: number + cteCapabilities: CteCapabilities = { + enabled: true, + writable: true, + materializedHint: true, + requiresRecursiveHint: true, + } + // ------------------------------------------------------------------------- // Constructor // ------------------------------------------------------------------------- diff --git a/src/driver/mongodb/MongoDriver.ts b/src/driver/mongodb/MongoDriver.ts index 0b578b3472..23dedc9408 100644 --- a/src/driver/mongodb/MongoDriver.ts +++ b/src/driver/mongodb/MongoDriver.ts @@ -1,6 +1,7 @@ import { Driver } from "../Driver" import { ConnectionIsNotSetError } from "../../error/ConnectionIsNotSetError" import { DriverPackageNotInstalledError } from "../../error/DriverPackageNotInstalledError" +import { CteCapabilities } from "../types/CteCapabilities" import { MongoQueryRunner } from "./MongoQueryRunner" import { ObjectLiteral } from "../../common/ObjectLiteral" import { ColumnMetadata } from "../../metadata/ColumnMetadata" @@ -212,6 +213,10 @@ export class MongoDriver implements Driver { "retryWrites", ] + cteCapabilities: CteCapabilities = { + enabled: false, + } + // ------------------------------------------------------------------------- // Constructor // ------------------------------------------------------------------------- diff --git a/src/driver/mysql/MysqlDriver.ts b/src/driver/mysql/MysqlDriver.ts index 9a77276463..133ef0d557 100644 --- a/src/driver/mysql/MysqlDriver.ts +++ b/src/driver/mysql/MysqlDriver.ts @@ -2,6 +2,7 @@ import { Driver, ReturningType } from "../Driver" import { ConnectionIsNotSetError } from "../../error/ConnectionIsNotSetError" import { DriverPackageNotInstalledError } from "../../error/DriverPackageNotInstalledError" import { DriverUtils } from "../DriverUtils" +import { CteCapabilities } from "../types/CteCapabilities" import { MysqlQueryRunner } from "./MysqlQueryRunner" import { ObjectLiteral } from "../../common/ObjectLiteral" import { ColumnMetadata } from "../../metadata/ColumnMetadata" @@ -309,6 +310,11 @@ export class MysqlDriver implements Driver { */ maxAliasLength = 63 + cteCapabilities: CteCapabilities = { + enabled: false, + requiresRecursiveHint: true, + } + /** * Supported returning types */ @@ -391,18 +397,25 @@ export class MysqlDriver implements Driver { await queryRunner.release() } - if (this.options.type === "mariadb") { - const result = (await this.createQueryRunner("master").query( - `SELECT VERSION() AS \`version\``, - )) as { version: string }[] - const dbVersion = result[0].version + const result = (await this.createQueryRunner("master").query( + `SELECT VERSION() AS \`version\``, + )) as { version: string }[] + const dbVersion = result[0].version + if (this.options.type === "mariadb") { if (VersionUtils.isGreaterOrEqual(dbVersion, "10.0.5")) { this._isReturningSqlSupported.delete = true } if (VersionUtils.isGreaterOrEqual(dbVersion, "10.5.0")) { this._isReturningSqlSupported.insert = true } + if (VersionUtils.isGreaterOrEqual(dbVersion, "10.2.0")) { + this.cteCapabilities.enabled = true + } + } else if (this.options.type === "mysql") { + if (VersionUtils.isGreaterOrEqual(dbVersion, "8.0.0")) { + this.cteCapabilities.enabled = true + } } } diff --git a/src/driver/oracle/OracleDriver.ts b/src/driver/oracle/OracleDriver.ts index 59ee777c25..6fee012487 100644 --- a/src/driver/oracle/OracleDriver.ts +++ b/src/driver/oracle/OracleDriver.ts @@ -1,6 +1,7 @@ import { Driver } from "../Driver" import { ConnectionIsNotSetError } from "../../error/ConnectionIsNotSetError" import { DriverPackageNotInstalledError } from "../../error/DriverPackageNotInstalledError" +import { CteCapabilities } from "../types/CteCapabilities" import { OracleQueryRunner } from "./OracleQueryRunner" import { ObjectLiteral } from "../../common/ObjectLiteral" import { ColumnMetadata } from "../../metadata/ColumnMetadata" @@ -220,6 +221,10 @@ export class OracleDriver implements Driver { */ maxAliasLength = 29 + cteCapabilities: CteCapabilities = { + enabled: false, // TODO: enable + } + // ------------------------------------------------------------------------- // Constructor // ------------------------------------------------------------------------- diff --git a/src/driver/postgres/PostgresDriver.ts b/src/driver/postgres/PostgresDriver.ts index d63170836a..81ce4c40cd 100644 --- a/src/driver/postgres/PostgresDriver.ts +++ b/src/driver/postgres/PostgresDriver.ts @@ -13,6 +13,7 @@ import { DateUtils } from "../../util/DateUtils" import { OrmUtils } from "../../util/OrmUtils" import { Driver } from "../Driver" import { ColumnType } from "../types/ColumnTypes" +import { CteCapabilities } from "../types/CteCapabilities" import { DataTypeDefaults } from "../types/DataTypeDefaults" import { MappedColumnTypes } from "../types/MappedColumnTypes" import { ReplicationMode } from "../types/ReplicationMode" @@ -272,6 +273,13 @@ export class PostgresDriver implements Driver { isGeneratedColumnsSupported: boolean = false + cteCapabilities: CteCapabilities = { + enabled: true, + writable: true, + requiresRecursiveHint: true, + materializedHint: true, + } + // ------------------------------------------------------------------------- // Constructor // ------------------------------------------------------------------------- diff --git a/src/driver/sap/SapDriver.ts b/src/driver/sap/SapDriver.ts index 72d1d562b6..0b4b17190a 100644 --- a/src/driver/sap/SapDriver.ts +++ b/src/driver/sap/SapDriver.ts @@ -16,6 +16,7 @@ import { ApplyValueTransformers } from "../../util/ApplyValueTransformers" import { DateUtils } from "../../util/DateUtils" import { OrmUtils } from "../../util/OrmUtils" import { Driver } from "../Driver" +import { CteCapabilities } from "../types/CteCapabilities" import { DataTypeDefaults } from "../types/DataTypeDefaults" import { MappedColumnTypes } from "../types/MappedColumnTypes" import { SapConnectionOptions } from "./SapConnectionOptions" @@ -204,6 +205,10 @@ export class SapDriver implements Driver { */ maxAliasLength = 128 + cteCapabilities: CteCapabilities = { + enabled: true, + } + // ------------------------------------------------------------------------- // Constructor // ------------------------------------------------------------------------- diff --git a/src/driver/sqlite-abstract/AbstractSqliteDriver.ts b/src/driver/sqlite-abstract/AbstractSqliteDriver.ts index 0a2db89f18..839e6043c8 100644 --- a/src/driver/sqlite-abstract/AbstractSqliteDriver.ts +++ b/src/driver/sqlite-abstract/AbstractSqliteDriver.ts @@ -4,6 +4,7 @@ import { ColumnMetadata } from "../../metadata/ColumnMetadata" import { DateUtils } from "../../util/DateUtils" import { DataSource } from "../../data-source/DataSource" import { RdbmsSchemaBuilder } from "../../schema-builder/RdbmsSchemaBuilder" +import { CteCapabilities } from "../types/CteCapabilities" import { MappedColumnTypes } from "../types/MappedColumnTypes" import { ColumnType } from "../types/ColumnTypes" import { QueryRunner } from "../../query-runner/QueryRunner" @@ -223,6 +224,11 @@ export abstract class AbstractSqliteDriver implements Driver { */ maxAliasLength?: number + cteCapabilities: CteCapabilities = { + enabled: true, + requiresRecursiveHint: true, + } + // ------------------------------------------------------------------------- // Protected Properties // ------------------------------------------------------------------------- diff --git a/src/driver/sqlserver/SqlServerDriver.ts b/src/driver/sqlserver/SqlServerDriver.ts index 15dd5fd830..582dd41b82 100644 --- a/src/driver/sqlserver/SqlServerDriver.ts +++ b/src/driver/sqlserver/SqlServerDriver.ts @@ -2,6 +2,7 @@ import { Driver } from "../Driver" import { ConnectionIsNotSetError } from "../../error/ConnectionIsNotSetError" import { DriverPackageNotInstalledError } from "../../error/DriverPackageNotInstalledError" import { DriverUtils } from "../DriverUtils" +import { CteCapabilities } from "../types/CteCapabilities" import { SqlServerQueryRunner } from "./SqlServerQueryRunner" import { ObjectLiteral } from "../../common/ObjectLiteral" import { ColumnMetadata } from "../../metadata/ColumnMetadata" @@ -222,6 +223,12 @@ export class SqlServerDriver implements Driver { datetimeoffset: { precision: 7 }, } + cteCapabilities: CteCapabilities = { + enabled: true, + // todo: enable it for SQL Server - it's partially supported, but there are issues with generation of non-standard OUTPUT clause + writable: false, + } + /** * Max length allowed by MSSQL Server for aliases (identifiers). * @see https://docs.microsoft.com/en-us/sql/sql-server/maximum-capacity-specifications-for-sql-server diff --git a/src/driver/types/CteCapabilities.ts b/src/driver/types/CteCapabilities.ts new file mode 100644 index 0000000000..aa845cfae6 --- /dev/null +++ b/src/driver/types/CteCapabilities.ts @@ -0,0 +1,20 @@ +export interface CteCapabilities { + /** + * Are CTEs supported at all? + */ + enabled: boolean + + /** + * Are RETURNING clauses supported in CTEs? + */ + writable?: boolean + /** + * Is RECURSIVE clause required for recursive CTEs? + */ + requiresRecursiveHint?: boolean + + /** + * Is MATERIALIZED clause supported? + */ + materializedHint?: boolean +} diff --git a/src/query-builder/DeleteQueryBuilder.ts b/src/query-builder/DeleteQueryBuilder.ts index 2d76b97885..e55443daa4 100644 --- a/src/query-builder/DeleteQueryBuilder.ts +++ b/src/query-builder/DeleteQueryBuilder.ts @@ -39,6 +39,7 @@ export class DeleteQueryBuilder */ getQuery(): string { let sql = this.createComment() + sql += this.createCteExpression() sql += this.createDeleteExpression() return sql.trim() } diff --git a/src/query-builder/InsertQueryBuilder.ts b/src/query-builder/InsertQueryBuilder.ts index b2fcb043df..a1f3c0de2f 100644 --- a/src/query-builder/InsertQueryBuilder.ts +++ b/src/query-builder/InsertQueryBuilder.ts @@ -33,6 +33,7 @@ export class InsertQueryBuilder extends QueryBuilder { */ getQuery(): string { let sql = this.createComment() + sql += this.createCteExpression() sql += this.createInsertExpression() return sql.trim() } diff --git a/src/query-builder/QueryBuilder.ts b/src/query-builder/QueryBuilder.ts index d30e6b4994..c23f8cd376 100644 --- a/src/query-builder/QueryBuilder.ts +++ b/src/query-builder/QueryBuilder.ts @@ -1,6 +1,7 @@ import { ObjectLiteral } from "../common/ObjectLiteral" import { QueryRunner } from "../query-runner/QueryRunner" import { DataSource } from "../data-source/DataSource" +import { QueryBuilderCteOptions } from "./QueryBuilderCte" import { QueryExpressionMap } from "./QueryExpressionMap" import { SelectQueryBuilder } from "./SelectQueryBuilder" import { UpdateQueryBuilder } from "./UpdateQueryBuilder" @@ -596,6 +597,22 @@ export abstract class QueryBuilder { return this } + /** + * Adds CTE to query + */ + addCommonTableExpression( + queryBuilder: QueryBuilder | string, + alias: string, + options?: QueryBuilderCteOptions, + ): this { + this.expressionMap.commonTableExpressions.push({ + queryBuilder, + alias, + options: options || {}, + }) + return this + } + // ------------------------------------------------------------------------- // Protected Methods // ------------------------------------------------------------------------- @@ -1048,6 +1065,80 @@ export abstract class QueryBuilder { ) } + protected createCteExpression(): string { + if (!this.hasCommonTableExpressions()) { + return "" + } + const databaseRequireRecusiveHint = + this.connection.driver.cteCapabilities.requiresRecursiveHint + + const cteStrings = this.expressionMap.commonTableExpressions.map( + (cte) => { + const cteBodyExpression = + typeof cte.queryBuilder === "string" + ? cte.queryBuilder + : cte.queryBuilder.getQuery() + if (typeof cte.queryBuilder !== "string") { + if (cte.queryBuilder.hasCommonTableExpressions()) { + throw new TypeORMError( + `Nested CTEs aren't supported (CTE: ${cte.alias})`, + ) + } + if ( + !this.connection.driver.cteCapabilities.writable && + !InstanceChecker.isSelectQueryBuilder(cte.queryBuilder) + ) { + throw new TypeORMError( + `Only select queries are supported in CTEs in ${this.connection.options.type} (CTE: ${cte.alias})`, + ) + } + this.setParameters(cte.queryBuilder.getParameters()) + } + let cteHeader = this.escape(cte.alias) + if (cte.options.columnNames) { + const escapedColumnNames = cte.options.columnNames.map( + (column) => this.escape(column), + ) + if ( + InstanceChecker.isSelectQueryBuilder(cte.queryBuilder) + ) { + if ( + cte.queryBuilder.expressionMap.selects.length && + cte.options.columnNames.length !== + cte.queryBuilder.expressionMap.selects.length + ) { + throw new TypeORMError( + `cte.options.columnNames length (${cte.options.columnNames.length}) doesn't match subquery select list length ${cte.queryBuilder.expressionMap.selects.length} (CTE: ${cte.alias})`, + ) + } + } + cteHeader += `(${escapedColumnNames.join(", ")})` + } + const recursiveClause = + cte.options.recursive && databaseRequireRecusiveHint + ? "RECURSIVE" + : "" + const materializeClause = + cte.options.materialized && + this.connection.driver.cteCapabilities.materializedHint + ? "MATERIALIZED" + : "" + + return [ + recursiveClause, + cteHeader, + materializeClause, + "AS", + `(${cteBodyExpression})`, + ] + .filter(Boolean) + .join(" ") + }, + ) + + return "WITH " + cteStrings.join(", ") + " " + } + /** * Creates "WHERE" condition for an in-ids condition. */ @@ -1459,4 +1550,8 @@ export abstract class QueryBuilder { protected obtainQueryRunner() { return this.queryRunner || this.connection.createQueryRunner() } + + protected hasCommonTableExpressions(): boolean { + return this.expressionMap.commonTableExpressions.length > 0 + } } diff --git a/src/query-builder/QueryBuilderCte.ts b/src/query-builder/QueryBuilderCte.ts new file mode 100644 index 0000000000..0583c1edb4 --- /dev/null +++ b/src/query-builder/QueryBuilderCte.ts @@ -0,0 +1,17 @@ +export interface QueryBuilderCteOptions { + /** + * Supported only by Postgres currently + * Oracle users should use query with undocumented materialize hint + */ + materialized?: boolean + /** + * Supported by Postgres, SQLite, MySQL and MariaDB + * SQL Server automatically detects recursive queries + */ + recursive?: boolean + /** + * Overwrite column names + * If number of columns returned doesn't work, it throws + */ + columnNames?: string[] +} diff --git a/src/query-builder/QueryExpressionMap.ts b/src/query-builder/QueryExpressionMap.ts index 7027ef869c..d944b6ab17 100644 --- a/src/query-builder/QueryExpressionMap.ts +++ b/src/query-builder/QueryExpressionMap.ts @@ -2,6 +2,8 @@ import { Alias } from "./Alias" import { ObjectLiteral } from "../common/ObjectLiteral" import { OrderByCondition } from "../find-options/OrderByCondition" import { JoinAttribute } from "./JoinAttribute" +import { QueryBuilder } from "./QueryBuilder" +import { QueryBuilderCteOptions } from "./QueryBuilderCte" import { RelationIdAttribute } from "./relation-id/RelationIdAttribute" import { RelationCountAttribute } from "./relation-count/RelationCountAttribute" import { DataSource } from "../data-source/DataSource" @@ -320,6 +322,12 @@ export class QueryExpressionMap { */ locallyGenerated: { [key: number]: ObjectLiteral } = {} + commonTableExpressions: { + queryBuilder: QueryBuilder | string + alias: string + options: QueryBuilderCteOptions + }[] = [] + // ------------------------------------------------------------------------- // Constructor // ------------------------------------------------------------------------- @@ -504,6 +512,16 @@ export class QueryExpressionMap { map.useTransaction = this.useTransaction map.nativeParameters = Object.assign({}, this.nativeParameters) map.comment = this.comment + map.commonTableExpressions = this.commonTableExpressions.map( + (cteOptions) => ({ + alias: cteOptions.alias, + queryBuilder: + typeof cteOptions.queryBuilder === "string" + ? cteOptions.queryBuilder + : cteOptions.queryBuilder.clone(), + options: cteOptions.options, + }), + ) return map } } diff --git a/src/query-builder/SelectQueryBuilder.ts b/src/query-builder/SelectQueryBuilder.ts index 4ae071ff38..0c11657e60 100644 --- a/src/query-builder/SelectQueryBuilder.ts +++ b/src/query-builder/SelectQueryBuilder.ts @@ -80,6 +80,7 @@ export class SelectQueryBuilder */ getQuery(): string { let sql = this.createComment() + sql += this.createCteExpression() sql += this.createSelectExpression() sql += this.createJoinExpression() sql += this.createWhereExpression() diff --git a/src/query-builder/SoftDeleteQueryBuilder.ts b/src/query-builder/SoftDeleteQueryBuilder.ts index 08d509621c..835a45c39d 100644 --- a/src/query-builder/SoftDeleteQueryBuilder.ts +++ b/src/query-builder/SoftDeleteQueryBuilder.ts @@ -46,6 +46,7 @@ export class SoftDeleteQueryBuilder */ getQuery(): string { let sql = this.createUpdateExpression() + sql += this.createCteExpression() sql += this.createOrderByExpression() sql += this.createLimitExpression() return sql.trim() diff --git a/src/query-builder/UpdateQueryBuilder.ts b/src/query-builder/UpdateQueryBuilder.ts index d68075315e..06973b407b 100644 --- a/src/query-builder/UpdateQueryBuilder.ts +++ b/src/query-builder/UpdateQueryBuilder.ts @@ -49,6 +49,7 @@ export class UpdateQueryBuilder */ getQuery(): string { let sql = this.createComment() + sql += this.createCteExpression() sql += this.createUpdateExpression() sql += this.createOrderByExpression() sql += this.createLimitExpression() diff --git a/test/functional/query-builder/cte/entity/foo.ts b/test/functional/query-builder/cte/entity/foo.ts new file mode 100644 index 0000000000..20c0ce1df4 --- /dev/null +++ b/test/functional/query-builder/cte/entity/foo.ts @@ -0,0 +1,12 @@ +import { PrimaryColumn } from "../../../../../src" +import { Entity } from "../../../../../src/decorator/entity/Entity" +import { Column } from "../../../../../src/decorator/columns/Column" + +@Entity() +export class Foo { + @PrimaryColumn() + id: number + + @Column("varchar") + bar: string +} diff --git a/test/functional/query-builder/cte/helpers.ts b/test/functional/query-builder/cte/helpers.ts new file mode 100644 index 0000000000..9ed04a843c --- /dev/null +++ b/test/functional/query-builder/cte/helpers.ts @@ -0,0 +1,9 @@ +import { Connection } from "../../../../src" +import { CteCapabilities } from "../../../../src/driver/types/CteCapabilities" + +export function filterByCteCapabilities( + capability: keyof CteCapabilities, + equalsTo: boolean = true, +): (conn: Connection) => boolean { + return (conn) => conn.driver.cteCapabilities[capability] === equalsTo +} diff --git a/test/functional/query-builder/cte/recursive-cte.ts b/test/functional/query-builder/cte/recursive-cte.ts new file mode 100644 index 0000000000..f32e0bd42e --- /dev/null +++ b/test/functional/query-builder/cte/recursive-cte.ts @@ -0,0 +1,49 @@ +import { expect } from "chai" +import { Connection } from "../../../../src" +import { + closeTestingConnections, + createTestingConnections, + reloadTestingDatabases, +} from "../../../utils/test-utils" +import { filterByCteCapabilities } from "./helpers" + +describe("query builder > cte > recursive", () => { + let connections: Connection[] + before( + async () => + (connections = await createTestingConnections({ + entities: [__dirname + "/entity/*{.js,.ts}"], + schemaCreate: true, + dropSchema: true, + })), + ) + beforeEach(() => reloadTestingDatabases(connections)) + after(() => closeTestingConnections(connections)) + + it("should work with simple recursive query", () => + Promise.all( + connections + .filter(filterByCteCapabilities("enabled")) + .map(async (connection) => { + const qb = await connection + .createQueryBuilder() + .select([]) + .from("cte", "cte") + .addCommonTableExpression( + ` + SELECT 1 + UNION ALL + SELECT cte.foo + 1 + FROM cte + WHERE cte.foo < 10 + `, + "cte", + { recursive: true, columnNames: ["foo"] }, + ) + .addSelect("cte.foo", "foo") + .getRawMany<{ foo: number }>() + + expect(qb).to.have.length(10) + }), + )) +}) diff --git a/test/functional/query-builder/cte/simple-cte.ts b/test/functional/query-builder/cte/simple-cte.ts new file mode 100644 index 0000000000..96f0b17a5c --- /dev/null +++ b/test/functional/query-builder/cte/simple-cte.ts @@ -0,0 +1,146 @@ +import "reflect-metadata" +import { expect } from "chai" +import { + createTestingConnections, + closeTestingConnections, + reloadTestingDatabases, +} from "../../../utils/test-utils" +import { Connection } from "../../../../src/connection/Connection" +import { Foo } from "./entity/foo" +import { filterByCteCapabilities } from "./helpers" + +describe("query builder > cte > simple", () => { + let connections: Connection[] + before( + async () => + (connections = await createTestingConnections({ + entities: [__dirname + "/entity/*{.js,.ts}"], + schemaCreate: true, + dropSchema: true, + })), + ) + beforeEach(() => reloadTestingDatabases(connections)) + after(() => closeTestingConnections(connections)) + + it("show allow select from CTE", () => + Promise.all( + connections + .filter(filterByCteCapabilities("enabled")) + .map(async (connection) => { + await connection + .getRepository(Foo) + .insert( + [1, 2, 3].map((i) => ({ id: i, bar: String(i) })), + ) + const cteQuery = connection + .createQueryBuilder() + .select() + .addSelect(`foo.bar`) + .from(Foo, "foo") + .where(`foo.bar = :value`, { value: "2" }) + + const qb = await connection + .createQueryBuilder() + .addCommonTableExpression(cteQuery, "qaz", { + columnNames: ["raz"], + }) + .from("qaz", "qaz") + .select([]) + .addSelect("qaz.raz", "raz") + + expect(await qb.getRawMany()).to.deep.equal([{ raz: "2" }]) + }), + )) + + it("should allow join with CTE", () => + Promise.all( + connections + .filter(filterByCteCapabilities("enabled")) + .map(async (connection) => { + await connection + .getRepository(Foo) + .insert( + [1, 2, 3].map((i) => ({ id: i, bar: String(i) })), + ) + const cteQuery = connection + .createQueryBuilder() + .select() + .addSelect("bar") + .from(Foo, "foo") + .where(`foo.bar = '2'`) + + const results = await connection + .createQueryBuilder(Foo, "foo") + .addCommonTableExpression(cteQuery, "qaz", { + columnNames: ["raz"], + }) + .innerJoin("qaz", "qaz", "qaz.raz = foo.bar") + .getMany() + + expect(results).to.have.length(1) + + expect(results[0]).to.include({ + bar: "2", + }) + }), + )) + + it("should allow to use INSERT with RETURNING clause in CTE", () => + Promise.all( + connections + .filter(filterByCteCapabilities("writable")) + .map(async (connection) => { + const bar = Math.random().toString() + const cteQuery = connection + .createQueryBuilder() + .insert() + .into(Foo) + .values({ + id: 7, + bar, + }) + .returning(["id", "bar"]) + + const results = await connection + .createQueryBuilder() + .select() + .addCommonTableExpression(cteQuery, "insert_result") + .from("insert_result", "insert_result") + .getRawMany() + + expect(results).to.have.length(1) + + expect(results[0]).to.include({ + bar, + }) + }), + )) + + it("should allow string for CTE", () => + Promise.all( + connections + .filter(filterByCteCapabilities("enabled")) + .map(async (connection) => { + const results = await connection + .createQueryBuilder() + .select() + .addCommonTableExpression( + ` + SELECT 1 + UNION + SELECT 2 + `, + "cte", + { columnNames: ["foo"] }, + ) + .from("cte", "cte") + .addSelect("foo", "row") + .getRawMany<{ row: any }>() + + const [rowWithOne, rowWithTwo] = results + + expect(String(rowWithOne.row)).to.equal("1") + expect(String(rowWithTwo.row)).to.equal("2") + }), + )) +}) diff --git a/test/github-issues/4753/issue-4753.ts b/test/github-issues/4753/issue-4753.ts index 61e969d986..a17748e4f8 100644 --- a/test/github-issues/4753/issue-4753.ts +++ b/test/github-issues/4753/issue-4753.ts @@ -1,31 +1,53 @@ import { getConnectionManager } from "../../../src" import { DataSource } from "../../../src/data-source/DataSource" -import { closeTestingConnections } from "../../utils/test-utils" +import { MysqlConnectionOptions } from "../../../src/driver/mysql/MysqlConnectionOptions" +import { + closeTestingConnections, + getTypeOrmConfig, + TestingConnectionOptions, +} from "../../utils/test-utils" import { User } from "./entity/User" +function isMySql(v: TestingConnectionOptions): v is MysqlConnectionOptions { + return v.type === "mysql" +} + describe("github issues > #4753 MySQL Replication Config broken", () => { let connections: DataSource[] = [] after(() => closeTestingConnections(connections)) it("should connect without error when using replication", async () => { - const connection = getConnectionManager().create({ + const connectionOptions: MysqlConnectionOptions | undefined = + getTypeOrmConfig() + .filter((v) => !v.skip) + .find(isMySql) + + if (!connectionOptions) { + // Skip if MySQL tests aren't enabled at all + return + } + const connectionManager = getConnectionManager() + const connection = connectionManager.create({ type: "mysql", replication: { master: { - username: "test", - password: "test", - database: "test", + host: connectionOptions.host, + username: connectionOptions.username, + password: connectionOptions.password, + database: connectionOptions.database, }, slaves: [ { - username: "test", - password: "test", - database: "test", + host: connectionOptions.host, + username: connectionOptions.username, + password: connectionOptions.password, + database: connectionOptions.database, }, ], }, entities: [User], }) + connections.push(connection) await connection.connect() connection.isInitialized.should.be.true