* added find options and new option relationLoadStrategy * find now returns null instead of undefined; removed primary relations support; bugfixing; added some changes and tests from next branch; * added typename to connection options; added data loader types, lot of deprecations; new es2020 emit by tsc; new custom repositories syntax * applied lint fixing * replaced some instanceof checks * reverting docker compose image versions * optimizing imports * reverting back some instanceof checks to prevent compiler errors * downgrading es compilation version * docs: remove "primary" from relation options (#8619) remove ex-line 26 for being deprecated in 0.3.0: "* `primary: boolean` - Indicates whether this relation's column will be a primary column or not." * Revert "reverting back some instanceof checks to prevent compiler errors" This reverts commit 7bf12a39e2297d097aa2a42989afd0e9e4f49bb0. * Revert "optimizing imports" This reverts commit 7588ac14e4f1bf1a82e3b7883134b9c2c8ae5f3f. * Revert "replaced some instanceof checks" This reverts commit bfa5a2d706f697ed1c1beb38b4455c0d33121e5a. * fixing few comments * removing transaction decorators * this test is invalid - it's not clear why the hell getTreeRepository will throw an error and it's not clear what kind of error its going to throw * addded mixed list support in connection options * trying to fix oracle length issue * lintfix * removed shorten usages * added named entity target support to the connection * fixing entity target support in relation options via entity schema * debugging oracle issue * fixed issue with alias not being shortened in many to many alias cases * some day we'll have a prettier. * fixing oracle tests * fixing oracle failing test * removed "null" support in where expressions; fixed softDelete and restore incorrect usages * renamed FindConditions to FindOptionsWhere * version bump * docs: update loading relation in find method (v 0.3.0) (#8621) * docs: update relation definition method Update the method that allows loading a specific relation inside the find method. This method is found on the one-to-one-relations page. Change `const users = await userRepository.find({ relations: ["profile"] });` to `const users = await userRepository.find({ relations: {profile: true});`. * fix formatting Co-authored-by: Umed Khudoiberdiev <pleerock.me@gmail.com> * docs: change relations option definition (#8620) * docs: change relations option definition change line 139 from `const users = await connection.getRepository(User).find({ relations: ["profile", "photos", "videos"] });` to `const users = await connection.getRepository(User).find({ relations: { profile: true, photos: true, videos: true] });` to reflect version 0.3.0 changes * docs: change relations option definition Rectified a type on line 139 from: `const users = await connection.getRepository(User).find({ relations: { profile: true, photos: true, videos: true] });` to `const users = await connection.getRepository(User).find({ relations: { profile: true, photos: true, videos: true} });` * formatting Co-authored-by: Umed Khudoiberdiev <pleerock.me@gmail.com> * lint * improved find options types * fixed types and removed nonnever because it causes circual issue for some reason * docs: update entitymanager definition (#8623) * docs: update entitymanager definition change the "What is EntityManager?" page to be up-to-date with v 0.3.0 1. line 6 changes from `You can access the entity manager via 'getManager()' or from 'Connection'.` to `You can access the entity manager via DataSource's manager.` 2. the import on `getManager` in line 10 becomes `Manager` that the user have configured beforehand: `import {getManager} from "typeorm";` becomes `import {Manager} from "./config/DataSource";` 3.change entityManager definition in line 13: from `const entityManager = getManager(); // you can also get it via getConnection().manager` to `const entityManager = Manager;` * docs: update entitymanager definition changed line 10 from: `import {Manager} from "./config/DataSource";` to `import {DataSource} from "typeorm";` and changed line 13 and 14 from: `const entityManager = Manager;` `const user = await entityManager.findOne(User, 1);` to `const myDataSource = new DataSource({ /*...*/ });` `const user = await myDataSource.manager.findOne(User, 1);` for a simpler way of describing the origin of DataSource and how it works. * In return type doesn't seem to work in all cases * feat: mssql v7 support (#8592) Adds support for v7 of the mssql library as v6 is EOL. This also makes use of the new toReadableStream method on requests to return a native stream where required. * fix: prefix relation id columns contained in embedded entities (#6977) (#7432) * fix: prefix relation id columns contained in embedded entities (#6977) Searches embedded entity columns for relation ID column if relation column is in embedded entity. If not found, creates new relation ID with embedded metadata set to match the relation column. fixes: #2254 fixes: #3132 fixes: #3226 fixes: #6977 * test: prefix subcounters sub-entity with "sub" to fit in 30 character identifier for oracle Problem introduced with #6981 * fix: find by Date object in sqlite driver (#7538) * fix: find by Date object in sqlite driver In sqlite, Date objects are persisted as UtcDatetimeString. But a Date object parameter was escaped with .toISOString(), making such queries impossible. This commit aligns both transforms. This bug does *not* apply to better-sql where you can only bind numbers, strings, bigints, buffers, and null. This is breaking for when the user inserted their dates manually as ISO and relied on this old maltransformation, after this their find()s by Date won't work anymore. BREAKING CHANGE: Change Date serialization in selects Closes: #2286 * add failing test * fix: find by Date object in sqlite driver (with query builder) Also consider query builder parameter escaping * test: add test for 3426 Co-authored-by: James Ward <james@notjam.es> * manually ported changes from #7796 * updated changelog * fixes after merge * new findOne syntax * new find* syntax * new find* syntax * lint * tsc version bump * tsc version bump and fixed mongodb issues * moved date fns into non dev deps * returned oracledb dep into place * removed lock files * returned lock files back * eslint upgrade * fixing mongodb issue * fixing mongodb issue * test: keep junction aliases short (#8637) Tests a fix for an issue where junction aliases (e.g. in many-to-many relations) are not unique because they are too long and thus truncated by the driver. Closes: #8627 Related to: 76cee41dcf1c146d02715c7f48fed33672d28c67 * fixing mongodb issues * fixing sqlite test * fixing sqlite test * fixing sqlite test * fixing mongodb test * fixing entity schema tests * fixing entity schema tests * merged latest master * removed driver instanceof checks * removed function instanceof checks * removed Object instanceof checks * removing instanceof checks... * fixing instanceof checks * added InstanceChecker to remove remaining instanceof checks * fixed failing test * linting * fixing failing test * version bump * compiler fixes * Connection type usages replace to DataSource * updated dev deps * updated deps, add prettier, removed oracledb due to m1 issue * chalk downgrade * fixing failing test * applied prettier formatting * replaced eslint to prettier * okay I think we can call it lint * fixing linting * fixed prettier introduced compiler bug * fixed failing test * prettier; * fixed failing test * alias shortening only for junction tables; fixed failing tests; * changed aurora db names and reverted change of junction table name shorten algorithm * format * removed platform from docker compose * made numeric parameters to not use parameters to prevent parameters number limit issue. Also enabled shorten only for junction tables * fixing test * fixing returning columns bugs * fixing test * fixed returning issue * fixing merge conflicts * updating documentation * working on docs / improving api * working on docs * fixed isConnected issue * re-worked commands * commenting cli command tests for now * commenting cli command tests for now * removed platform * returned Connection back * refactor: export tree repository helper methods (#8753) * Migrated protected tree methods to util class * Added tree repository extend override * Ran prettier format * merge master into 0.3.0 Co-authored-by: Bitcollage <serkan.sipahi@yahoo.de> * working on documentation Co-authored-by: Bilel Taktak <47742269+Parsath@users.noreply.github.com> Co-authored-by: Salah Azzouz <52634440+Salah-Azzouz@users.noreply.github.com> Co-authored-by: Daniel Hensby <dhensby@users.noreply.github.com> Co-authored-by: Nebojša Cvetković <nebkat@gmail.com> Co-authored-by: Philip Waritschlager <philip+github@waritschlager.de> Co-authored-by: James Ward <james@notjam.es> Co-authored-by: Felix Gohla <37421906+felix-gohla@users.noreply.github.com> Co-authored-by: Dmitry Zotov <dmzt08@gmail.com> Co-authored-by: Jimmy Chen <50786287+Q16solver@users.noreply.github.com> Co-authored-by: Bitcollage <serkan.sipahi@yahoo.de>
30 KiB
Select using Query Builder
- What is
QueryBuilder - Important note when using the
QueryBuilder - How to create and use a
QueryBuilder - Getting values using QueryBuilder
- What are aliases for?
- Using parameters to escape data
- Adding
WHEREexpression - Adding
HAVINGexpression - Adding
ORDER BYexpression - Adding
GROUP BYexpression - Adding
LIMITexpression - Adding
OFFSETexpression - Joining relations
- Inner and left joins
- Join without selection
- Joining any entity or table
- Joining and mapping functionality
- Getting the generated query
- Getting raw results
- Streaming result data
- Using pagination
- Set locking
- Use custom index
- Max execution time
- Partial selection
- Using subqueries
- Hidden Columns
- Querying Deleted rows
What is QueryBuilder
QueryBuilder is one of the most powerful features of TypeORM -
it allows you to build SQL queries using elegant and convenient syntax,
execute them and get automatically transformed entities.
Simple example of QueryBuilder:
const firstUser = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.where("user.id = :id", { id: 1 })
.getOne()
It builds the following SQL query:
SELECT
user.id as userId,
user.firstName as userFirstName,
user.lastName as userLastName
FROM users user
WHERE user.id = 1
and returns you an instance of User:
User {
id: 1,
firstName: "Timber",
lastName: "Saw"
}
Important note when using the QueryBuilder
When using the QueryBuilder, you need to provide unique parameters in your WHERE expressions. This will not work:
const result = await dataSource
.createQueryBuilder('user')
.leftJoinAndSelect('user.linkedSheep', 'linkedSheep')
.leftJoinAndSelect('user.linkedCow', 'linkedCow')
.where('user.linkedSheep = :id', { id: sheepId })
.andWhere('user.linkedCow = :id', { id: cowId });
... but this will:
const result = await dataSource
.createQueryBuilder('user')
.leftJoinAndSelect('user.linkedSheep', 'linkedSheep')
.leftJoinAndSelect('user.linkedCow', 'linkedCow')
.where('user.linkedSheep = :sheepId', { sheepId })
.andWhere('user.linkedCow = :cowId', { cowId });
Note that we uniquely named :sheepId and :cowId instead of using :id twice for different parameters.
How to create and use a QueryBuilder
There are several ways how you can create a Query Builder:
-
Using DataSource:
const user = await dataSource .createQueryBuilder() .select("user") .from(User, "user") .where("user.id = :id", { id: 1 }) .getOne() -
Using entity manager:
const user = await dataSource.manager .createQueryBuilder(User, "user") .where("user.id = :id", { id: 1 }) .getOne() -
Using repository:
const user = await dataSource .getRepository(User) .createQueryBuilder("user") .where("user.id = :id", { id: 1 }) .getOne()
There are 5 different QueryBuilder types available:
-
SelectQueryBuilder- used to build and executeSELECTqueries. Example:const user = await dataSource .createQueryBuilder() .select("user") .from(User, "user") .where("user.id = :id", { id: 1 }) .getOne() -
InsertQueryBuilder- used to build and executeINSERTqueries. Example:await dataSource .createQueryBuilder() .insert() .into(User) .values([ { firstName: "Timber", lastName: "Saw" }, { firstName: "Phantom", lastName: "Lancer" }, ]) .execute() -
UpdateQueryBuilder- used to build and executeUPDATEqueries. Example:await dataSource .createQueryBuilder() .update(User) .set({ firstName: "Timber", lastName: "Saw" }) .where("id = :id", { id: 1 }) .execute() -
DeleteQueryBuilder- used to build and executeDELETEqueries. Example:await dataSource .createQueryBuilder() .delete() .from(User) .where("id = :id", { id: 1 }) .execute() -
RelationQueryBuilder- used to build and execute relation-specific operations [TBD]. Example:```typescript await dataSource .createQueryBuilder() .relation(User,"photos") .of(id) .loadMany(); ```
You can switch between different types of query builder within any of them, once you do, you will get a new instance of query builder (unlike all other methods).
Getting values using QueryBuilder
To get a single result from the database,
for example to get a user by id or name, you must use getOne:
const timber = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.where("user.id = :id OR user.name = :name", { id: 1, name: "Timber" })
.getOne()
getOneOrFail will get a single result from the database, but if
no result exists it will throw an EntityNotFoundError:
const timber = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.where("user.id = :id OR user.name = :name", { id: 1, name: "Timber" })
.getOneOrFail()
To get multiple results from the database,
for example, to get all users from the database, use getMany:
const users = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.getMany()
There are two types of results you can get using select query builder: entities or raw results.
Most of the time, you need to select real entities from your database, for example, users.
For this purpose, you use getOne and getMany.
But sometimes you need to select some specific data, let's say the sum of all user photos.
This data is not an entity, it's called raw data.
To get raw data, you use getRawOne and getRawMany.
Examples:
const { sum } = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.select("SUM(user.photosCount)", "sum")
.where("user.id = :id", { id: 1 })
.getRawOne()
const photosSums = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.select("user.id")
.addSelect("SUM(user.photosCount)", "sum")
.groupBy("user.id")
.getRawMany()
// result will be like this: [{ id: 1, sum: 25 }, { id: 2, sum: 13 }, ...]
What are aliases for?
We used createQueryBuilder("user"). But what is "user"?
It's just a regular SQL alias.
We use aliases everywhere, except when we work with selected data.
createQueryBuilder("user") is equivalent to:
createQueryBuilder().select("user").from(User, "user")
Which will result in the following SQL query:
SELECT ... FROM users user
In this SQL query, users is the table name, and user is an alias we assign to this table.
Later we use this alias to access the table:
createQueryBuilder()
.select("user")
.from(User, "user")
.where("user.name = :name", { name: "Timber" })
Which produces the following SQL query:
SELECT ... FROM users user WHERE user.name = 'Timber'
See, we used the users table by using the user alias we assigned when we created a query builder.
One query builder is not limited to one alias, they can have multiple aliases. Each select can have its own alias, you can select from multiple tables each with its own alias, you can join multiple tables each with its own alias. You can use those aliases to access tables are you selecting (or data you are selecting).
Using parameters to escape data
We used where("user.name = :name", { name: "Timber" }).
What does { name: "Timber" } stand for? It's a parameter we used to prevent SQL injection.
We could have written: where("user.name = '" + name + "'),
however this is not safe, as it opens the code to SQL injections.
The safe way is to use this special syntax: where("user.name = :name", { name: "Timber" }),
where :name is a parameter name and the value is specified in an object: { name: "Timber" }.
.where("user.name = :name", { name: "Timber" })
is a shortcut for:
.where("user.name = :name")
.setParameter("name", "Timber")
Note: do not use the same parameter name for different values across the query builder. Values will be overridden if you set them multiple times.
You can also supply an array of values, and have them transformed into a list of values in the SQL statement, by using the special expansion syntax:
.where("user.name IN (:...names)", { names: [ "Timber", "Cristal", "Lina" ] })
Which becomes:
WHERE user.name IN ('Timber', 'Cristal', 'Lina')
Adding WHERE expression
Adding a WHERE expression is as easy as:
createQueryBuilder("user").where("user.name = :name", { name: "Timber" })
Which will produce:
SELECT ... FROM users user WHERE user.name = 'Timber'
You can add AND into an existing WHERE expression:
createQueryBuilder("user")
.where("user.firstName = :firstName", { firstName: "Timber" })
.andWhere("user.lastName = :lastName", { lastName: "Saw" })
Which will produce the following SQL query:
SELECT ... FROM users user WHERE user.firstName = 'Timber' AND user.lastName = 'Saw'
You can add OR into an existing WHERE expression:
createQueryBuilder("user")
.where("user.firstName = :firstName", { firstName: "Timber" })
.orWhere("user.lastName = :lastName", { lastName: "Saw" })
Which will produce the following SQL query:
SELECT ... FROM users user WHERE user.firstName = 'Timber' OR user.lastName = 'Saw'
You can do an IN query with the WHERE expression:
createQueryBuilder("user").where("user.id IN (:...ids)", { ids: [1, 2, 3, 4] })
Which will produce the following SQL query:
SELECT ... FROM users user WHERE user.id IN (1, 2, 3, 4)
You can add a complex WHERE expression into an existing WHERE using Brackets
createQueryBuilder("user")
.where("user.registered = :registered", { registered: true })
.andWhere(
new Brackets((qb) => {
qb.where("user.firstName = :firstName", {
firstName: "Timber",
}).orWhere("user.lastName = :lastName", { lastName: "Saw" })
}),
)
Which will produce the following SQL query:
SELECT ... FROM users user WHERE user.registered = true AND (user.firstName = 'Timber' OR user.lastName = 'Saw')
You can add a negated complex WHERE expression into an existing WHERE using NotBrackets
createQueryBuilder("user")
.where("user.registered = :registered", { registered: true })
.andWhere(
new NotBrackets((qb) => {
qb.where("user.firstName = :firstName", {
firstName: "Timber",
}).orWhere("user.lastName = :lastName", { lastName: "Saw" })
}),
)
Which will produce the following SQL query:
SELECT ... FROM users user WHERE user.registered = true AND NOT((user.firstName = 'Timber' OR user.lastName = 'Saw'))
You can combine as many AND and OR expressions as you need.
If you use .where more than once you'll override all previous WHERE expressions.
Note: be careful with orWhere - if you use complex expressions with both AND and OR expressions,
keep in mind that they are stacked without any pretences.
Sometimes you'll need to create a where string instead, and avoid using orWhere.
Adding HAVING expression
Adding a HAVING expression is easy as:
createQueryBuilder("user").having("user.name = :name", { name: "Timber" })
Which will produce following SQL query:
SELECT ... FROM users user HAVING user.name = 'Timber'
You can add AND into an exist HAVING expression:
createQueryBuilder("user")
.having("user.firstName = :firstName", { firstName: "Timber" })
.andHaving("user.lastName = :lastName", { lastName: "Saw" })
Which will produce the following SQL query:
SELECT ... FROM users user HAVING user.firstName = 'Timber' AND user.lastName = 'Saw'
You can add OR into a exist HAVING expression:
createQueryBuilder("user")
.having("user.firstName = :firstName", { firstName: "Timber" })
.orHaving("user.lastName = :lastName", { lastName: "Saw" })
Which will produce the following SQL query:
SELECT ... FROM users user HAVING user.firstName = 'Timber' OR user.lastName = 'Saw'
You can combine as many AND and OR expressions as you need.
If you use .having more than once you'll override all previous HAVING expressions.
Adding ORDER BY expression
Adding an ORDER BY expression is easy as:
createQueryBuilder("user").orderBy("user.id")
Which will produce:
SELECT ... FROM users user ORDER BY user.id
You can change the ordering direction from ascending to descending (or versa):
createQueryBuilder("user").orderBy("user.id", "DESC")
createQueryBuilder("user").orderBy("user.id", "ASC")
You can add multiple order-by criteria:
createQueryBuilder("user").orderBy("user.name").addOrderBy("user.id")
You can also use a map of order-by fields:
createQueryBuilder("user").orderBy({
"user.name": "ASC",
"user.id": "DESC",
})
If you use .orderBy more than once you'll override all previous ORDER BY expressions.
Adding DISTINCT ON expression (Postgres only)
When using both distinct-on with an order-by expression, the distinct-on expression must match the leftmost order-by. The distinct-on expressions are interpreted using the same rules as order-by. Please note that, using distinct-on without an order-by expression means that the first row of each set is unpredictable.
Adding a DISTINCT ON expression is easy as:
createQueryBuilder("user").distinctOn(["user.id"]).orderBy("user.id")
Which will produce:
SELECT DISTINCT ON (user.id) ... FROM users user ORDER BY user.id
Adding GROUP BY expression
Adding a GROUP BY expression is easy as:
createQueryBuilder("user").groupBy("user.id")
Which will produce the following SQL query:
SELECT ... FROM users user GROUP BY user.id
To add more group-by criteria use addGroupBy:
createQueryBuilder("user").groupBy("user.name").addGroupBy("user.id")
If you use .groupBy more than once you'll override all previous GROUP BY expressions.
Adding LIMIT expression
Adding a LIMIT expression is easy as:
createQueryBuilder("user").limit(10)
Which will produce the following SQL query:
SELECT ... FROM users user LIMIT 10
The resulting SQL query depends on the type of database (SQL, mySQL, Postgres, etc).
Note: LIMIT may not work as you may expect if you are using complex queries with joins or subqueries.
If you are using pagination, it's recommended to use take instead.
Adding OFFSET expression
Adding an SQL OFFSET expression is easy as:
createQueryBuilder("user").offset(10)
Which will produce the following SQL query:
SELECT ... FROM users user OFFSET 10
The resulting SQL query depends on the type of database (SQL, mySQL, Postgres, etc).
Note: OFFSET may not work as you may expect if you are using complex queries with joins or subqueries.
If you are using pagination, it's recommended to use skip instead.
Joining relations
Let's say you have the following entities:
import { Entity, PrimaryGeneratedColumn, Column, OneToMany } from "typeorm"
import { Photo } from "./Photo"
@Entity()
export class User {
@PrimaryGeneratedColumn()
id: number
@Column()
name: string
@OneToMany((type) => Photo, (photo) => photo.user)
photos: Photo[]
}
import { Entity, PrimaryGeneratedColumn, Column, ManyToOne } from "typeorm"
import { User } from "./User"
@Entity()
export class Photo {
@PrimaryGeneratedColumn()
id: number
@Column()
url: string
@ManyToOne((type) => User, (user) => user.photos)
user: User
}
Now let's say you want to load user "Timber" with all of his photos:
const user = await createQueryBuilder("user")
.leftJoinAndSelect("user.photos", "photo")
.where("user.name = :name", { name: "Timber" })
.getOne()
You'll get the following result:
{
id: 1,
name: "Timber",
photos: [{
id: 1,
url: "me-with-chakram.jpg"
}, {
id: 2,
url: "me-with-trees.jpg"
}]
}
As you can see leftJoinAndSelect automatically loaded all of Timber's photos.
The first argument is the relation you want to load and the second argument is an alias you assign to this relation's table.
You can use this alias anywhere in query builder.
For example, let's take all Timber's photos which aren't removed.
const user = await createQueryBuilder("user")
.leftJoinAndSelect("user.photos", "photo")
.where("user.name = :name", { name: "Timber" })
.andWhere("photo.isRemoved = :isRemoved", { isRemoved: false })
.getOne()
This will generate following SQL query:
SELECT user.*, photo.* FROM users user
LEFT JOIN photos photo ON photo.user = user.id
WHERE user.name = 'Timber' AND photo.isRemoved = FALSE
You can also add conditions to the join expression instead of using "where":
const user = await createQueryBuilder("user")
.leftJoinAndSelect("user.photos", "photo", "photo.isRemoved = :isRemoved", {
isRemoved: false,
})
.where("user.name = :name", { name: "Timber" })
.getOne()
This will generate the following SQL query:
SELECT user.*, photo.* FROM users user
LEFT JOIN photos photo ON photo.user = user.id AND photo.isRemoved = FALSE
WHERE user.name = 'Timber'
Inner and left joins
If you want to use INNER JOIN instead of LEFT JOIN just use innerJoinAndSelect instead:
const user = await createQueryBuilder("user")
.innerJoinAndSelect(
"user.photos",
"photo",
"photo.isRemoved = :isRemoved",
{ isRemoved: false },
)
.where("user.name = :name", { name: "Timber" })
.getOne()
This will generate:
SELECT user.*, photo.* FROM users user
INNER JOIN photos photo ON photo.user = user.id AND photo.isRemoved = FALSE
WHERE user.name = 'Timber'
The difference between LEFT JOIN and INNER JOIN is that INNER JOIN won't return a user if it does not have any photos.
LEFT JOIN will return you the user even if it doesn't have photos.
To learn more about different join types, refer to the SQL documentation.
Join without selection
You can join data without its selection.
To do that, use leftJoin or innerJoin:
const user = await createQueryBuilder("user")
.innerJoin("user.photos", "photo")
.where("user.name = :name", { name: "Timber" })
.getOne()
This will generate:
SELECT user.* FROM users user
INNER JOIN photos photo ON photo.user = user.id
WHERE user.name = 'Timber'
This will select Timber if he has photos, but won't return his photos.
Joining any entity or table
You can join not only relations, but also other unrelated entities or tables. Examples:
const user = await createQueryBuilder("user")
.leftJoinAndSelect(Photo, "photo", "photo.userId = user.id")
.getMany()
const user = await createQueryBuilder("user")
.leftJoinAndSelect("photos", "photo", "photo.userId = user.id")
.getMany()
Joining and mapping functionality
Add profilePhoto to User entity and you can map any data into that property using QueryBuilder:
export class User {
/// ...
profilePhoto: Photo
}
const user = await createQueryBuilder("user")
.leftJoinAndMapOne(
"user.profilePhoto",
"user.photos",
"photo",
"photo.isForProfile = TRUE",
)
.where("user.name = :name", { name: "Timber" })
.getOne()
This will load Timber's profile photo and set it to user.profilePhoto.
If you want to load and map a single entity use leftJoinAndMapOne.
If you want to load and map multiple entities use leftJoinAndMapMany.
Getting the generated query
Sometimes you may want to get the SQL query generated by QueryBuilder.
To do so, use getSql:
const sql = createQueryBuilder("user")
.where("user.firstName = :firstName", { firstName: "Timber" })
.orWhere("user.lastName = :lastName", { lastName: "Saw" })
.getSql()
For debugging purposes you can use printSql:
const users = await createQueryBuilder("user")
.where("user.firstName = :firstName", { firstName: "Timber" })
.orWhere("user.lastName = :lastName", { lastName: "Saw" })
.printSql()
.getMany()
This query will return users and print the used sql statement to the console.
Getting raw results
There are two types of results you can get using select query builder: entities and raw results.
Most of the time, you need to select real entities from your database, for example, users.
For this purpose, you use getOne and getMany.
However, sometimes you need to select specific data, like the sum of all user photos.
Such data is not a entity, it's called raw data.
To get raw data, you use getRawOne and getRawMany.
Examples:
const { sum } = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.select("SUM(user.photosCount)", "sum")
.where("user.id = :id", { id: 1 })
.getRawOne()
const photosSums = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.select("user.id")
.addSelect("SUM(user.photosCount)", "sum")
.groupBy("user.id")
.getRawMany()
// result will be like this: [{ id: 1, sum: 25 }, { id: 2, sum: 13 }, ...]
Streaming result data
You can use stream which returns you a stream.
Streaming returns you raw data and you must handle entity transformation manually:
const stream = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.where("user.id = :id", { id: 1 })
.stream()
Using pagination
Most of the time when you develop an application, you need pagination functionality. This is used if you have pagination, page slider, or infinite scroll components in your application.
const users = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.leftJoinAndSelect("user.photos", "photo")
.take(10)
.getMany()
This will give you the first 10 users with their photos.
const users = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.leftJoinAndSelect("user.photos", "photo")
.skip(10)
.getMany()
This will give you all except the first 10 users with their photos. You can combine those methods:
const users = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.leftJoinAndSelect("user.photos", "photo")
.skip(5)
.take(10)
.getMany()
This will skip the first 5 users and take 10 users after them.
take and skip may look like we are using limit and offset, but they aren't.
limit and offset may not work as you expect once you have more complicated queries with joins or subqueries.
Using take and skip will prevent those issues.
Set locking
QueryBuilder supports both optimistic and pessimistic locking. To use pessimistic read locking use the following method:
const users = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.setLock("pessimistic_read")
.getMany()
To use pessimistic write locking use the following method:
const users = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.setLock("pessimistic_write")
.getMany()
To use dirty read locking use the following method:
const users = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.setLock("dirty_read")
.getMany()
To use optimistic locking use the following method:
const users = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.setLock("optimistic", existUser.version)
.getMany()
Optimistic locking works in conjunction with both @Version and @UpdatedDate decorators.
Use custom index
You can provide a certain index for database server to use in some cases. This feature is only supported in MySQL.
const users = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.useIndex("my_index") // name of index
.getMany()
Max execution time
We can drop slow query to avoid crashing the server.
const users = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.maxExecutionTime(1000) // milliseconds.
.getMany()
Partial selection
If you want to select only some entity properties, you can use the following syntax:
const users = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.select(["user.id", "user.name"])
.getMany()
This will only select the id and name of User.
Using subqueries
You can easily create subqueries. Subqueries are supported in FROM, WHERE and JOIN expressions.
Example:
const qb = await dataSource.getRepository(Post).createQueryBuilder("post")
const posts = qb
.where(
"post.title IN " +
qb
.subQuery()
.select("user.name")
.from(User, "user")
.where("user.registered = :registered")
.getQuery(),
)
.setParameter("registered", true)
.getMany()
A more elegant way to do the same:
const posts = await dataSource
.getRepository(Post)
.createQueryBuilder("post")
.where((qb) => {
const subQuery = qb
.subQuery()
.select("user.name")
.from(User, "user")
.where("user.registered = :registered")
.getQuery()
return "post.title IN " + subQuery
})
.setParameter("registered", true)
.getMany()
Alternatively, you can create a separate query builder and use its generated SQL:
const userQb = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.select("user.name")
.where("user.registered = :registered", { registered: true })
const posts = await dataSource
.getRepository(Post)
.createQueryBuilder("post")
.where("post.title IN (" + userQb.getQuery() + ")")
.setParameters(userQb.getParameters())
.getMany()
You can create subqueries in FROM like this:
const userQb = await dataSource
.getRepository(User)
.createQueryBuilder("user")
.select("user.name", "name")
.where("user.registered = :registered", { registered: true })
const posts = await dataSource
.createQueryBuilder()
.select("user.name", "name")
.from("(" + userQb.getQuery() + ")", "user")
.setParameters(userQb.getParameters())
.getRawMany()
or using a more elegant syntax:
const posts = await dataSource
.createQueryBuilder()
.select("user.name", "name")
.from((subQuery) => {
return subQuery
.select("user.name", "name")
.from(User, "user")
.where("user.registered = :registered", { registered: true })
}, "user")
.getRawMany()
If you want to add a subselect as a "second from" use addFrom.
You can use subselects in SELECT statements as well:
const posts = await dataSource
.createQueryBuilder()
.select("post.id", "id")
.addSelect((subQuery) => {
return subQuery.select("user.name", "name").from(User, "user").limit(1)
}, "name")
.from(Post, "post")
.getRawMany()
Hidden Columns
If the model you are querying has a column with a select: false column, you must use the addSelect function in order to retrieve the information from the column.
Let's say you have the following entity:
import { Entity, PrimaryGeneratedColumn, Column } from "typeorm"
@Entity()
export class User {
@PrimaryGeneratedColumn()
id: number
@Column()
name: string
@Column({ select: false })
password: string
}
Using a standard find or query, you will not receive the password property for the model. However, if you do the following:
const users = await dataSource
.getRepository(User)
.createQueryBuilder()
.select("user.id", "id")
.addSelect("user.password")
.getMany()
You will get the property password in your query.
Querying Deleted rows
If the model you are querying has a column with the attribute @DeleteDateColumn set, the query builder will automatically query rows which are 'soft deleted'.
Let's say you have the following entity:
import { Entity, PrimaryGeneratedColumn, Column } from "typeorm"
@Entity()
export class User {
@PrimaryGeneratedColumn()
id: number
@Column()
name: string
@DeleteDateColumn()
deletedAt?: Date
}
Using a standard find or query, you will not receive the rows which have a value in that row. However, if you do the following:
const users = await dataSource
.getRepository(User)
.createQueryBuilder()
.select("user.id", "id")
.withDeleted()
.getMany()
You will get all the rows, including the ones which are deleted.