diff --git a/docs/find-options.md b/docs/find-options.md index 24dd68c2fa..0c47e88c32 100644 --- a/docs/find-options.md +++ b/docs/find-options.md @@ -219,10 +219,19 @@ or mode: "pessimistic_read" | "pessimistic_write" | "dirty_read" | + /* + "pessimistic_partial_write" and "pessimistic_write_or_fail" are deprecated and + will be removed in a future version. + + Use onLocked instead. + */ "pessimistic_partial_write" | "pessimistic_write_or_fail" | "for_no_key_update" | - "for_key_share" + "for_key_share", + + tables: string[], + onLocked: "nowait" | "skip_locked" } ``` @@ -237,19 +246,7 @@ userRepository.findOne({ }) ``` -Support of lock modes, and SQL statements they translate to, are listed in the table below (blank cell denotes unsupported). When specified lock mode is not supported, a `LockNotSupportedOnGivenDriverError` error will be thrown. - -```text -| | pessimistic_read | pessimistic_write | dirty_read | pessimistic_partial_write | pessimistic_write_or_fail | for_no_key_update | for_key_share | -| --------------- | -------------------- | ----------------------- | ------------- | --------------------------- | --------------------------- | ------------------- | ------------- | -| MySQL | LOCK IN SHARE MODE | FOR UPDATE | (nothing) | FOR UPDATE SKIP LOCKED | FOR UPDATE NOWAIT | | | -| Postgres | FOR SHARE | FOR UPDATE | (nothing) | FOR UPDATE SKIP LOCKED | FOR UPDATE NOWAIT | FOR NO KEY UPDATE | FOR KEY SHARE | -| Oracle | FOR UPDATE | FOR UPDATE | (nothing) | | | | | -| SQL Server | WITH (HOLDLOCK, ROWLOCK) | WITH (UPDLOCK, ROWLOCK) | WITH (NOLOCK) | | | | | -| AuroraDataApi | LOCK IN SHARE MODE | FOR UPDATE | (nothing) | | | | | -| CockroachDB | | FOR UPDATE | (nothing) | | FOR UPDATE NOWAIT | FOR NO KEY UPDATE | | - -``` +See [lock modes](./select-query-builder.md#lock-modes) for more information Complete example of find options: diff --git a/docs/select-query-builder.md b/docs/select-query-builder.md index c97614f670..0d999d50af 100644 --- a/docs/select-query-builder.md +++ b/docs/select-query-builder.md @@ -901,6 +901,22 @@ Using `take` and `skip` will prevent those issues. ## Set locking QueryBuilder supports both optimistic and pessimistic locking. + +#### Lock modes +Support of lock modes, and SQL statements they translate to, are listed in the table below (blank cell denotes unsupported). When specified lock mode is not supported, a `LockNotSupportedOnGivenDriverError` error will be thrown. + +```text +| | pessimistic_read | pessimistic_write | dirty_read | pessimistic_partial_write (Deprecated, use onLocked instead) | pessimistic_write_or_fail (Deprecated, use onLocked instead) | for_no_key_update | for_key_share | +| --------------- | --------------------------------- | ----------------------- | ------------- | -------------------------------------------------------------- | -------------------------------------------------------------- | ------------------- | ------------- | +| MySQL | FOR SHARE (8+)/LOCK IN SHARE MODE | FOR UPDATE | (nothing) | FOR UPDATE SKIP LOCKED | FOR UPDATE NOWAIT | | | +| Postgres | FOR SHARE | FOR UPDATE | (nothing) | FOR UPDATE SKIP LOCKED | FOR UPDATE NOWAIT | FOR NO KEY UPDATE | FOR KEY SHARE | +| Oracle | FOR UPDATE | FOR UPDATE | (nothing) | | | | | +| SQL Server | WITH (HOLDLOCK, ROWLOCK) | WITH (UPDLOCK, ROWLOCK) | WITH (NOLOCK) | | | | | +| AuroraDataApi | LOCK IN SHARE MODE | FOR UPDATE | (nothing) | | | | | +| CockroachDB | | FOR UPDATE | (nothing) | | FOR UPDATE NOWAIT | FOR NO KEY UPDATE | | + +``` + To use pessimistic read locking use the following method: ```typescript @@ -943,6 +959,39 @@ const users = await dataSource Optimistic locking works in conjunction with both `@Version` and `@UpdatedDate` decorators. +### setOnLock +Allows you to control what happens when a row is locked. By default, the database will wait for the lock. +You can control that behavior by using `setOnLocked` + + +To not wait: + +```typescript +const users = await dataSource + .getRepository(User) + .createQueryBuilder("user") + .setLock("pessimistic_write") + .setOnLocked("nowait") + .getMany() +``` + +To skip the row: + +```typescript +const users = await dataSource + .getRepository(User) + .createQueryBuilder("user") + .setLock("pessimistic_write") + .setOnLocked("skip_locked") + .getMany() +``` + +Database support for `setOnLocked` based on [lock mode](#lock-modes): +- Postgres: `pessimistic_read`, `pessimistic_write`, `for_no_key_update`, `for_key_share` +- MySQL 8+: `pessimistic_read`, `pessimistic_write` +- MySQL < 8, Maria DB: `pessimistic_write` +- Cockroach: `pessimistic_write` (`nowait` only) + ## Use custom index You can provide a certain index for database server to use in some cases. This feature is only supported in MySQL. diff --git a/src/driver/Driver.ts b/src/driver/Driver.ts index 4be6fdbf6b..46e2ad3cc4 100644 --- a/src/driver/Driver.ts +++ b/src/driver/Driver.ts @@ -26,6 +26,11 @@ export interface Driver { */ options: BaseDataSourceOptions + /** + * Database version/release. Often requires a SQL query to the DB, so it is not always set + */ + version?: string + /** * Database name used to perform all write queries. * diff --git a/src/driver/DriverUtils.ts b/src/driver/DriverUtils.ts index d60b982053..4c75d8c744 100644 --- a/src/driver/DriverUtils.ts +++ b/src/driver/DriverUtils.ts @@ -1,5 +1,6 @@ import { Driver } from "./Driver" import { hash, shorten } from "../util/StringUtils" +import { VersionUtils } from "../util/VersionUtils" /** * Common driver utility functions. @@ -32,6 +33,13 @@ export class DriverUtils { return ["mysql", "mariadb"].includes(driver.options.type) } + static isReleaseVersionOrGreater(driver: Driver, version: string): boolean { + return ( + driver.version != null && + VersionUtils.isGreaterOrEqual(driver.version, version) + ) + } + static isPostgresFamily(driver: Driver): boolean { return ["postgres", "aurora-postgres"].includes(driver.options.type) } diff --git a/src/driver/mysql/MysqlDriver.ts b/src/driver/mysql/MysqlDriver.ts index d4fe9e7f85..e428e6fe9b 100644 --- a/src/driver/mysql/MysqlDriver.ts +++ b/src/driver/mysql/MysqlDriver.ts @@ -65,6 +65,11 @@ export class MysqlDriver implements Driver { */ options: MysqlConnectionOptions + /** + * Version of MySQL. Requires a SQL query to the DB, so it is not always set + */ + version?: string + /** * Master database used to perform all write queries. */ @@ -402,6 +407,7 @@ export class MysqlDriver implements Driver { version: string }[] = await queryRunner.query(`SELECT VERSION() AS \`version\``) const dbVersion = result[0].version + this.version = dbVersion await queryRunner.release() if (this.options.type === "mariadb") { diff --git a/src/driver/postgres/PostgresDriver.ts b/src/driver/postgres/PostgresDriver.ts index 0dfad6d7a3..226f4a9ea7 100644 --- a/src/driver/postgres/PostgresDriver.ts +++ b/src/driver/postgres/PostgresDriver.ts @@ -71,6 +71,11 @@ export class PostgresDriver implements Driver { */ options: PostgresConnectionOptions + /** + * Version of Postgres. Requires a SQL query to the DB, so it is not always set + */ + version?: string + /** * Database name used to perform all write queries. */ @@ -385,6 +390,7 @@ export class PostgresDriver implements Driver { /^PostgreSQL ([\d\.]+) .*$/, "$1", ) + this.version = versionString this.isGeneratedColumnsSupported = VersionUtils.isGreaterOrEqual( versionString, "12.0", diff --git a/src/find-options/FindOneOptions.ts b/src/find-options/FindOneOptions.ts index 058206c8a1..7d6978524c 100644 --- a/src/find-options/FindOneOptions.ts +++ b/src/find-options/FindOneOptions.ts @@ -74,11 +74,18 @@ export interface FindOneOptions { | "pessimistic_read" | "pessimistic_write" | "dirty_read" + /* + "pessimistic_partial_write" and "pessimistic_write_or_fail" are deprecated and + will be removed in a future version. + + Use onLocked instead. + */ | "pessimistic_partial_write" | "pessimistic_write_or_fail" | "for_no_key_update" | "for_key_share" tables?: string[] + onLocked?: "nowait" | "skip_locked" } /** diff --git a/src/query-builder/QueryExpressionMap.ts b/src/query-builder/QueryExpressionMap.ts index 1a0a6f4cbe..5596cbd1e8 100644 --- a/src/query-builder/QueryExpressionMap.ts +++ b/src/query-builder/QueryExpressionMap.ts @@ -186,6 +186,12 @@ export class QueryExpressionMap { | "pessimistic_read" | "pessimistic_write" | "dirty_read" + /* + "pessimistic_partial_write" and "pessimistic_write_or_fail" are deprecated and + will be removed in a future version. + + Use onLocked instead. + */ | "pessimistic_partial_write" | "pessimistic_write_or_fail" | "for_no_key_update" @@ -201,6 +207,11 @@ export class QueryExpressionMap { */ lockTables?: string[] + /** + * Modify behavior when encountering locked rows. NOWAIT or SKIP LOCKED + */ + onLocked?: "nowait" | "skip_locked" + /** * Indicates if soft-deleted rows should be included in entity result. * By default the soft-deleted rows are not included. @@ -492,6 +503,7 @@ export class QueryExpressionMap { map.skip = this.skip map.take = this.take map.lockMode = this.lockMode + map.onLocked = this.onLocked map.lockVersion = this.lockVersion map.lockTables = this.lockTables map.withDeleted = this.withDeleted diff --git a/src/query-builder/SelectQueryBuilder.ts b/src/query-builder/SelectQueryBuilder.ts index b60ea169a8..0585dfb165 100644 --- a/src/query-builder/SelectQueryBuilder.ts +++ b/src/query-builder/SelectQueryBuilder.ts @@ -1485,6 +1485,12 @@ export class SelectQueryBuilder | "pessimistic_read" | "pessimistic_write" | "dirty_read" + /* + "pessimistic_partial_write" and "pessimistic_write_or_fail" are deprecated and + will be removed in a future version. + + Use setOnLocked instead. + */ | "pessimistic_partial_write" | "pessimistic_write_or_fail" | "for_no_key_update" @@ -1502,6 +1508,12 @@ export class SelectQueryBuilder | "pessimistic_read" | "pessimistic_write" | "dirty_read" + /* + "pessimistic_partial_write" and "pessimistic_write_or_fail" are deprecated and + will be removed in a future version. + + Use setOnLocked instead. + */ | "pessimistic_partial_write" | "pessimistic_write_or_fail" | "for_no_key_update" @@ -1515,6 +1527,14 @@ export class SelectQueryBuilder return this } + /** + * Sets lock handling by adding NO WAIT or SKIP LOCKED. + */ + setOnLocked(onLocked: "nowait" | "skip_locked"): this { + this.expressionMap.onLocked = onLocked + return this + } + /** * Disables the global condition of "non-deleted" for the entity with delete date columns. */ @@ -2104,7 +2124,10 @@ export class SelectQueryBuilder } } - if (driver.options.type === "postgres" && selectDistinctOn.length > 0) { + if ( + DriverUtils.isPostgresFamily(driver) && + selectDistinctOn.length > 0 + ) { const selectDistinctOnMap = selectDistinctOn .map((on) => this.replacePropertyNames(on)) .join(", ") @@ -2491,7 +2514,7 @@ export class SelectQueryBuilder if (this.expressionMap.lockTables) { if ( !( - driver.options.type === "postgres" || + DriverUtils.isPostgresFamily(driver) || driver.options.type === "cockroachdb" ) ) { @@ -2505,15 +2528,31 @@ export class SelectQueryBuilder lockTablesClause = " OF " + this.expressionMap.lockTables.join(", ") } + let onLockExpression = "" + if (this.expressionMap.onLocked === "nowait") { + onLockExpression = " NOWAIT" + } else if (this.expressionMap.onLocked === "skip_locked") { + onLockExpression = " SKIP LOCKED" + } switch (this.expressionMap.lockMode) { case "pessimistic_read": if ( - DriverUtils.isMySQLFamily(driver) || + driver.options.type === "mysql" || driver.options.type === "aurora-mysql" ) { + if ( + DriverUtils.isReleaseVersionOrGreater(driver, "8.0.0") + ) { + return ( + " FOR SHARE" + lockTablesClause + onLockExpression + ) + } else { + return " LOCK IN SHARE MODE" + } + } else if (driver.options.type === "mariadb") { return " LOCK IN SHARE MODE" - } else if (driver.options.type === "postgres") { - return " FOR SHARE" + lockTablesClause + } else if (DriverUtils.isPostgresFamily(driver)) { + return " FOR SHARE" + lockTablesClause + onLockExpression } else if (driver.options.type === "oracle") { return " FOR UPDATE" } else if (driver.options.type === "mssql") { @@ -2527,19 +2566,19 @@ export class SelectQueryBuilder driver.options.type === "aurora-mysql" || driver.options.type === "oracle" ) { - return " FOR UPDATE" + return " FOR UPDATE" + onLockExpression } else if ( - driver.options.type === "postgres" || + DriverUtils.isPostgresFamily(driver) || driver.options.type === "cockroachdb" ) { - return " FOR UPDATE" + lockTablesClause + return " FOR UPDATE" + lockTablesClause + onLockExpression } else if (driver.options.type === "mssql") { return "" } else { throw new LockNotSupportedOnGivenDriverError() } case "pessimistic_partial_write": - if (driver.options.type === "postgres") { + if (DriverUtils.isPostgresFamily(driver)) { return " FOR UPDATE" + lockTablesClause + " SKIP LOCKED" } else if (DriverUtils.isMySQLFamily(driver)) { return " FOR UPDATE SKIP LOCKED" @@ -2548,7 +2587,7 @@ export class SelectQueryBuilder } case "pessimistic_write_or_fail": if ( - driver.options.type === "postgres" || + DriverUtils.isPostgresFamily(driver) || driver.options.type === "cockroachdb" ) { return " FOR UPDATE" + lockTablesClause + " NOWAIT" @@ -2557,24 +2596,27 @@ export class SelectQueryBuilder } else { throw new LockNotSupportedOnGivenDriverError() } - case "for_no_key_update": if ( - driver.options.type === "postgres" || + DriverUtils.isPostgresFamily(driver) || driver.options.type === "cockroachdb" ) { - return " FOR NO KEY UPDATE" + lockTablesClause + return ( + " FOR NO KEY UPDATE" + + lockTablesClause + + onLockExpression + ) } else { throw new LockNotSupportedOnGivenDriverError() } - case "for_key_share": - if (driver.options.type === "postgres") { - return " FOR KEY SHARE" + lockTablesClause + if (DriverUtils.isPostgresFamily(driver)) { + return ( + " FOR KEY SHARE" + lockTablesClause + onLockExpression + ) } else { throw new LockNotSupportedOnGivenDriverError() } - default: return "" } @@ -2669,7 +2711,7 @@ export class SelectQueryBuilder selectionPath = `${asText}(${selectionPath})` } - if (this.connection.driver.options.type === "postgres") + if (DriverUtils.isPostgresFamily(this.connection.driver)) if (column.precision) { // cast to JSON to trigger parsing in the driver selectionPath = `ST_AsGeoJSON(${selectionPath}, ${column.precision})::json` @@ -2753,7 +2795,7 @@ export class SelectQueryBuilder if ( this.connection.driver.options.type === "cockroachdb" || - this.connection.driver.options.type === "postgres" + DriverUtils.isPostgresFamily(this.connection.driver) ) { // Postgres and CockroachDB can pass multiple parameters to the `DISTINCT` function // https://www.postgresql.org/docs/9.5/sql-select.html#SQL-DISTINCT @@ -3118,6 +3160,10 @@ export class SelectQueryBuilder undefined, tableNames, ) + + if (this.findOptions.lock.onLocked) { + this.setOnLocked(this.findOptions.lock.onLocked) + } } } diff --git a/test/functional/query-builder/locking/query-builder-locking.ts b/test/functional/query-builder/locking/query-builder-locking.ts index 5c7f5069fb..9cdeeea356 100644 --- a/test/functional/query-builder/locking/query-builder-locking.ts +++ b/test/functional/query-builder/locking/query-builder-locking.ts @@ -1084,4 +1084,153 @@ describe("query builder > locking", () => { }) }), )) + + it("pessimistic_partial_write and skip_locked works", () => + Promise.all( + connections.map(async (connection) => { + if ( + connection.driver.options.type === "postgres" || + DriverUtils.isMySQLFamily(connection.driver) + ) { + const sql = connection + .createQueryBuilder(PostWithVersion, "post") + .setLock("pessimistic_partial_write") + .setOnLocked("skip_locked") + .where("post.id = :id", { id: 1 }) + .getSql() + + expect(sql.endsWith("FOR UPDATE SKIP LOCKED")).to.be.true + } + }), + )) + + it("pessimistic_write_or_fail and skip_locked ignores skip_locked", () => + Promise.all( + connections.map(async (connection) => { + if ( + connection.driver.options.type === "postgres" || + DriverUtils.isMySQLFamily(connection.driver) + ) { + const sql = connection + .createQueryBuilder(PostWithVersion, "post") + .setLock("pessimistic_write_or_fail") + .setOnLocked("skip_locked") + .where("post.id = :id", { id: 1 }) + .getSql() + + expect(sql.endsWith("FOR UPDATE NOWAIT")).to.be.true + } + }), + )) + + it('skip_locked with "pessimistic_read"', () => + Promise.all( + connections.map(async (connection) => { + if ( + connection.driver.options.type === "postgres" || + (connection.driver.options.type === "mysql" && + DriverUtils.isReleaseVersionOrGreater( + connection.driver, + "8.0.0", + )) + ) { + const sql = connection + .createQueryBuilder(PostWithVersion, "post") + .setLock("pessimistic_read") + .setOnLocked("skip_locked") + .where("post.id = :id", { id: 1 }) + .getSql() + + expect(sql.endsWith("FOR SHARE SKIP LOCKED")).to.be.true + } + }), + )) + + it('nowait with "pessimistic_read"', () => + Promise.all( + connections.map(async (connection) => { + if ( + connection.driver.options.type === "postgres" || + (connection.driver.options.type === "mysql" && + DriverUtils.isReleaseVersionOrGreater( + connection.driver, + "8.0.0", + )) + ) { + const sql = connection + .createQueryBuilder(PostWithVersion, "post") + .setLock("pessimistic_read") + .setOnLocked("nowait") + .where("post.id = :id", { id: 1 }) + .getSql() + + expect(sql.endsWith("FOR SHARE NOWAIT")).to.be.true + } + }), + )) + + it('skip_locked with "pessimistic_read" check getOne', () => + Promise.all( + connections.map(async (connection) => { + if ( + connection.driver.options.type === "postgres" || + (connection.driver.options.type === "mysql" && + DriverUtils.isReleaseVersionOrGreater( + connection.driver, + "8.0.0", + )) + ) { + return connection.manager.transaction((entityManager) => { + return Promise.resolve( + entityManager + .createQueryBuilder(PostWithVersion, "post") + .setLock("pessimistic_read") + .setOnLocked("skip_locked") + .where("post.id = :id", { id: 1 }) + .getOne().should.not.be.rejected, + ) + }) + } + }), + )) + + it('skip_locked with "for_key_share" check getOne', () => + Promise.all( + connections.map(async (connection) => { + if (connection.driver.options.type === "postgres") { + return connection.manager.transaction((entityManager) => { + return Promise.resolve( + entityManager + .createQueryBuilder(PostWithVersion, "post") + .setLock("for_key_share") + .setOnLocked("skip_locked") + .where("post.id = :id", { id: 1 }) + .getOne().should.not.be.rejected, + ) + }) + } + }), + )) + + it('skip_locked with "pessimistic_read" fails on early versions of MySQL', () => + Promise.all( + connections.map(async (connection) => { + if ( + connection.driver.options.type === "mysql" && + !DriverUtils.isReleaseVersionOrGreater( + connection.driver, + "8.0.0", + ) + ) { + const sql = connection + .createQueryBuilder(PostWithVersion, "post") + .setLock("pessimistic_read") + .setOnLocked("nowait") + .where("post.id = :id", { id: 1 }) + .getSql() + + expect(sql.endsWith("LOCK IN SHARE MODE")).to.be.true + } + }), + )) }) diff --git a/test/functional/repository/find-options-locking/find-options-locking.ts b/test/functional/repository/find-options-locking/find-options-locking.ts index b4a27d4198..212ea4ed94 100644 --- a/test/functional/repository/find-options-locking/find-options-locking.ts +++ b/test/functional/repository/find-options-locking/find-options-locking.ts @@ -222,6 +222,90 @@ describe("repository > find options > locking", () => { }), )) + it("should attach SKIP LOCKED for pessimistic_read", () => + Promise.all( + connections.map(async (connection) => { + if ( + !( + connection.driver.options.type === "postgres" || + (connection.driver.options.type === "mysql" && + DriverUtils.isReleaseVersionOrGreater( + connection.driver, + "8.0.0", + )) + ) + ) + return + + const executedSql: string[] = [] + + await connection.manager.transaction((entityManager) => { + const originalQuery = entityManager.queryRunner!.query.bind( + entityManager.queryRunner, + ) + entityManager.queryRunner!.query = (...args: any[]) => { + executedSql.push(args[0]) + return originalQuery(...args) + } + + return entityManager + .getRepository(PostWithVersion) + .findOne({ + where: { id: 1 }, + lock: { + mode: "pessimistic_read", + onLocked: "skip_locked", + }, + }) + }) + + expect(executedSql.join(" ").includes("FOR SHARE SKIP LOCKED")) + .to.be.true + }), + )) + + it("should attach NOWAIT for pessimistic_write", () => + Promise.all( + connections.map(async (connection) => { + if ( + !( + connection.driver.options.type === "postgres" || + (DriverUtils.isMySQLFamily(connection.driver) && + DriverUtils.isReleaseVersionOrGreater( + connection.driver, + "8.0.0", + )) + ) + ) + return + + const executedSql: string[] = [] + + await connection.manager.transaction((entityManager) => { + const originalQuery = entityManager.queryRunner!.query.bind( + entityManager.queryRunner, + ) + entityManager.queryRunner!.query = (...args: any[]) => { + executedSql.push(args[0]) + return originalQuery(...args) + } + + return entityManager + .getRepository(PostWithVersion) + .findOne({ + where: { id: 1 }, + lock: { + mode: "pessimistic_write", + onLocked: "nowait", + }, + }) + }) + + expect(executedSql.join(" ").includes("FOR UPDATE NOWAIT")).to + .be.true + }), + )) + it("should attach pessimistic write lock statement on query if locking enabled", () => Promise.all( connections.map(async (connection) => {