-
-
Notifications
You must be signed in to change notification settings - Fork 6.3k
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
fix: add lock clause for MSSQL select, select with join clause
typeorm didn't supported LOCK clause in SELECT + JOIN query. For example, we cannot buld SQL such as "SELECT * FROM USER U WITH(NOLOCK) INNER JOIN ORDER WITH(NOLOCK) O ON U.ID=O.UserID". This pull request enables LOCK with SELECT + JOIN sql query. Closes: #4764
- Loading branch information
Showing
5 changed files
with
264 additions
and
21 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,19 @@ | ||
import { Column, Entity, PrimaryGeneratedColumn } from "../../../../src"; | ||
|
||
@Entity() | ||
export class AdminUser { | ||
@PrimaryGeneratedColumn() | ||
id!: number; | ||
|
||
@Column() | ||
email!: number; | ||
|
||
@Column() | ||
scopes!: string; | ||
|
||
@Column() | ||
name!: string; | ||
|
||
@Column() | ||
unid!: number; | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,29 @@ | ||
import { Column, Entity, OneToMany, PrimaryGeneratedColumn } from "../../../../src"; | ||
import { CartItems } from "./CartItems"; | ||
|
||
@Entity() | ||
export class Cart { | ||
@PrimaryGeneratedColumn() | ||
ID!: number; | ||
|
||
@Column() | ||
UNID!: number; | ||
|
||
@Column() | ||
Type!: string; | ||
|
||
@Column() | ||
Cycle?: number; | ||
|
||
@Column() | ||
Term?: string; | ||
|
||
@Column() | ||
RegDate!: Date; | ||
|
||
@Column() | ||
ModifiedDate!: Date; | ||
|
||
@OneToMany((type) => CartItems, (t) => t.Cart) | ||
CartItems?: CartItems[]; | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,30 @@ | ||
import { Column, Entity, JoinColumn, ManyToOne, PrimaryGeneratedColumn } from "../../../../src"; | ||
import { Cart } from "./Cart"; | ||
|
||
@Entity() | ||
export class CartItems { | ||
@PrimaryGeneratedColumn() | ||
ID!: number; | ||
|
||
@Column() | ||
CartID!: number; | ||
|
||
@Column() | ||
ItemID!: number; | ||
|
||
@Column() | ||
OptionID!: number; | ||
|
||
@Column() | ||
Quantity!: number; | ||
|
||
@Column() | ||
RegDate!: Date; | ||
|
||
@Column() | ||
ModifiedDate!: Date; | ||
|
||
@ManyToOne((type) => Cart, (t) => t.CartItems) | ||
@JoinColumn({ name: "CartID" }) | ||
Cart?: Cart; | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,158 @@ | ||
import { expect } from "chai"; | ||
import "reflect-metadata"; | ||
import { Connection } from "../../../src/index"; | ||
import { | ||
closeTestingConnections, | ||
createTestingConnections, | ||
reloadTestingDatabases, | ||
} from "../../utils/test-utils"; | ||
import { Cart } from "./entity/Cart"; | ||
|
||
describe("mssql > add lock clause for MSSQL select, select with join clause", () => { | ||
// ------------------------------------------------------------------------- | ||
// Configuration | ||
// ------------------------------------------------------------------------- | ||
|
||
// connect to db | ||
let connections: Connection[]; | ||
|
||
before( | ||
async () => | ||
(connections = await createTestingConnections({ | ||
enabledDrivers: ["mssql"], | ||
entities: [__dirname + "/entity/*{.js,.ts}"], | ||
schemaCreate: true, | ||
dropSchema: true, | ||
})) | ||
); | ||
beforeEach(() => reloadTestingDatabases(connections)); | ||
after(() => closeTestingConnections(connections)); | ||
|
||
// ------------------------------------------------------------------------- | ||
// Specifications | ||
// ------------------------------------------------------------------------- | ||
it("should not have Lock clause", async () => { | ||
Promise.all( | ||
connections.map(async (connection) => { | ||
const lock = " WITH (NOLOCK)"; | ||
const selectQuery = connection | ||
.createQueryBuilder() | ||
.select("cart") | ||
.from(Cart, "cart") | ||
.where("1=1") | ||
.getQuery(); | ||
|
||
console.log(selectQuery); | ||
expect(selectQuery.includes(lock)).not.to.equal(true); | ||
|
||
await connection.query(selectQuery); | ||
}) | ||
); | ||
}); | ||
|
||
it("should have WITH (NOLOCK) clause", async () => { | ||
Promise.all( | ||
connections.map(async (connection) => { | ||
const lock = " WITH (NOLOCK)"; | ||
const selectQuery = connection | ||
.createQueryBuilder() | ||
.select("cart") | ||
.from(Cart, "cart") | ||
.setLock("dirty_read") | ||
.where("1=1") | ||
.getQuery(); | ||
|
||
console.log(selectQuery); | ||
expect(selectQuery.includes(lock)).to.equal(true); | ||
|
||
await connection.query(selectQuery); | ||
}) | ||
); | ||
}); | ||
|
||
it("should have two WITH (NOLOCK) clause", async () => { | ||
Promise.all( | ||
connections.map(async (connection) => { | ||
const lock = " WITH (NOLOCK)"; | ||
const selectQuery = connection | ||
.createQueryBuilder() | ||
.select("cart") | ||
.from(Cart, "cart") | ||
.innerJoinAndSelect("cart.CartItems", "cartItems") | ||
.setLock("dirty_read") | ||
.where("1=1") | ||
.getQuery(); | ||
|
||
console.log(selectQuery); | ||
expect(countInstances(selectQuery, lock)).to.equal(2); | ||
|
||
await connection.query(selectQuery); | ||
}) | ||
); | ||
}); | ||
|
||
it("should have WITH (HOLDLOCK, ROWLOCK) clause", async () => { | ||
Promise.all( | ||
connections.map(async (connection) => { | ||
const lock = " WITH (HOLDLOCK, ROWLOCK)"; | ||
const selectQuery = connection | ||
.createQueryBuilder() | ||
.select("cart") | ||
.from(Cart, "cart") | ||
.setLock("pessimistic_read") | ||
.where("1=1") | ||
.getQuery(); | ||
|
||
console.log(selectQuery); | ||
expect(selectQuery.includes(lock)).to.equal(true); | ||
|
||
await connection.query(selectQuery); | ||
}) | ||
); | ||
}); | ||
|
||
it("should have WITH (UPLOCK, ROWLOCK) clause", async () => { | ||
Promise.all( | ||
connections.map(async (connection) => { | ||
const lock = " WITH (UPDLOCK, ROWLOCK)"; | ||
const selectQuery = connection | ||
.createQueryBuilder() | ||
.select("cart") | ||
.from(Cart, "cart") | ||
.setLock("pessimistic_write") | ||
.where("1=1") | ||
.getQuery(); | ||
|
||
console.log(selectQuery); | ||
expect(selectQuery.includes(lock)).to.equal(true); | ||
|
||
await connection.query(selectQuery); | ||
}) | ||
); | ||
}); | ||
|
||
it("should have two WITH (UPDLOCK, ROWLOCK) clause", async () => { | ||
Promise.all( | ||
connections.map(async (connection) => { | ||
const lock = " WITH (UPDLOCK, ROWLOCK)"; | ||
const selectQuery = connection | ||
.createQueryBuilder() | ||
.select("cart") | ||
.from(Cart, "cart") | ||
.innerJoinAndSelect("cart.CartItems", "cartItems") | ||
.setLock("pessimistic_write") | ||
.where("1=1") | ||
.getQuery(); | ||
|
||
console.log(selectQuery); | ||
expect(countInstances(selectQuery, lock)).to.equal(2); | ||
|
||
await connection.query(selectQuery); | ||
}) | ||
); | ||
}); | ||
|
||
function countInstances(str: string, word: string) { | ||
return str.split(word).length - 1; | ||
} | ||
}); |