Skip to content

Commit

Permalink
feat: add distinct on() support for postgres (#4954)
Browse files Browse the repository at this point in the history
* Added distinct on property to query builder exp map.
* Initial distinct on implementation for postgres
* Move distinct on to postgres only enabled test run.
* Added documentation for distinct-on, formatting.
  • Loading branch information
swim authored and pleerock committed Nov 22, 2019
1 parent 231dadf commit 1293065
Show file tree
Hide file tree
Showing 7 changed files with 304 additions and 50 deletions.
114 changes: 66 additions & 48 deletions docs/select-query-builder.md
Original file line number Diff line number Diff line change
Expand Up @@ -27,7 +27,7 @@

## What is `QueryBuilder`

`QueryBuilder` is one of the most powerful features of TypeORM -
`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.

Expand All @@ -41,12 +41,12 @@ const firstUser = await connection
.getOne();
```

It builds the following SQL query:
It builds the following SQL query:

```sql
SELECT
user.id as userId,
user.firstName as userFirstName,
SELECT
user.id as userId,
user.firstName as userFirstName,
user.lastName as userLastName
FROM users user
WHERE user.id = 1
Expand All @@ -60,17 +60,17 @@ User {
firstName: "Timber",
lastName: "Saw"
}
```
```

## How to create and use a `QueryBuilder`

There are several ways how you can create a `Query Builder`:

* Using connection:

```typescript
import {getConnection} from "typeorm";

const user = await getConnection()
.createQueryBuilder()
.select("user")
Expand All @@ -80,21 +80,21 @@ There are several ways how you can create a `Query Builder`:
```

* Using entity manager:

```typescript
import {getManager} from "typeorm";

const user = await getManager()
.createQueryBuilder(User, "user")
.where("user.id = :id", { id: 1 })
.getOne();
```

* Using repository:

```typescript
import {getRepository} from "typeorm";

const user = await getRepository(User)
.createQueryBuilder("user")
.where("user.id = :id", { id: 1 })
Expand All @@ -107,7 +107,7 @@ There are 5 different `QueryBuilder` types available:

```typescript
import {getConnection} from "typeorm";

const user = await getConnection()
.createQueryBuilder()
.select("user")
Expand All @@ -120,23 +120,23 @@ There are 5 different `QueryBuilder` types available:

```typescript
import {getConnection} from "typeorm";

await getConnection()
.createQueryBuilder()
.insert()
.into(User)
.values([
{ firstName: "Timber", lastName: "Saw" },
{ firstName: "Timber", lastName: "Saw" },
{ firstName: "Phantom", lastName: "Lancer" }
])
.execute();
```

* `UpdateQueryBuilder` - used to build and execute `UPDATE` queries. Example:

```typescript
import {getConnection} from "typeorm";

await getConnection()
.createQueryBuilder()
.update(User)
Expand All @@ -145,10 +145,10 @@ There are 5 different `QueryBuilder` types available:
.execute();
```
* `DeleteQueryBuilder` - used to build and execute `DELETE` queries. Example:

```typescript
import {getConnection} from "typeorm";

await getConnection()
.createQueryBuilder()
.delete()
Expand All @@ -157,24 +157,24 @@ There are 5 different `QueryBuilder` types available:
.execute();
```

* `RelationQueryBuilder` - used to build and execute relation-specific operations [TBD].
* `RelationQueryBuilder` - used to build and execute relation-specific operations [TBD].

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,
To get a single result from the database,
for example to get a user by id or name, you must use `getOne`:

```typescript
const timber = await getRepository(User)
.createQueryBuilder("user")
.where("user.id = :id OR user.name = :name", { id: 1, name: "Timber" })
.getOne();
```
```

To get multiple results from the database,
To get multiple results from the database,
for example, to get all users from the database, use `getMany`:

```typescript
Expand All @@ -184,9 +184,9 @@ const users = await getRepository(User)
```

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.
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*.
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:
Expand All @@ -213,7 +213,7 @@ const photosSums = await getRepository(User)
## What are aliases for?

We used `createQueryBuilder("user")`. But what is "user"?
It's just a regular SQL alias.
It's just a regular SQL alias.
We use aliases everywhere, except when we work with selected data.

`createQueryBuilder("user")` is equivalent to:
Expand Down Expand Up @@ -250,15 +250,15 @@ See, we used the users table by using the `user` alias we assigned when we creat

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 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).
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 + "')`,
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" }`.
Expand Down Expand Up @@ -353,8 +353,8 @@ 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`.
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

Expand Down Expand Up @@ -422,7 +422,7 @@ You can change the ordering direction from ascending to descending (or versa):
```typescript
createQueryBuilder("user")
.orderBy("user.id", "DESC")

createQueryBuilder("user")
.orderBy("user.id", "ASC")
```
Expand All @@ -447,6 +447,24 @@ createQueryBuilder("user")

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:

```typescript
createQueryBuilder("user")
.distinctOn(["user.id"])
.orderBy("user.id")
```

Which will produce:

```sql
SELECT DISTINCT ON (user.id) ... FROM users user ORDER BY user.id
```

## Adding `GROUP BY` expression

Adding a `GROUP BY` expression is easy as:
Expand Down Expand Up @@ -519,13 +537,13 @@ import {Photo} from "./Photo";

@Entity()
export class User {

@PrimaryGeneratedColumn()
id: number;

@Column()
name: string;

@OneToMany(type => Photo, photo => photo.user)
photos: Photo[];
}
Expand All @@ -537,13 +555,13 @@ import {User} from "./User";

@Entity()
export class Photo {

@PrimaryGeneratedColumn()
id: number;

@Column()
url: string;

@ManyToOne(type => User, user => user.photos)
user: User;
}
Expand Down Expand Up @@ -590,7 +608,7 @@ const user = await createQueryBuilder("user")
This will generate following sql query:

```sql
SELECT user.*, photo.* FROM users user
SELECT user.*, photo.* FROM users user
LEFT JOIN photos photo ON photo.user = user.id
WHERE user.name = 'Timber' AND photo.isRemoved = FALSE
```
Expand All @@ -607,7 +625,7 @@ const user = await createQueryBuilder("user")
This will generate the following sql query:

```sql
SELECT user.*, photo.* FROM users user
SELECT user.*, photo.* FROM users user
LEFT JOIN photos photo ON photo.user = user.id AND photo.isRemoved = FALSE
WHERE user.name = 'Timber'
```
Expand All @@ -626,7 +644,7 @@ const user = await createQueryBuilder("user")
This will generate:

```sql
SELECT user.*, photo.* FROM users user
SELECT user.*, photo.* FROM users user
INNER JOIN photos photo ON photo.user = user.id AND photo.isRemoved = FALSE
WHERE user.name = 'Timber'
```
Expand All @@ -650,12 +668,12 @@ const user = await createQueryBuilder("user")
This will generate:

```sql
SELECT user.* FROM users user
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.
This will select Timber if he has photos, but won't return his photos.

## Joining any entity or table

Expand All @@ -682,7 +700,7 @@ Add `profilePhoto` to `User` entity and you can map any data into that property
export class User {
/// ...
profilePhoto: Photo;

}
```

Expand Down Expand Up @@ -724,9 +742,9 @@ 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.
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*.
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:
Expand Down Expand Up @@ -965,10 +983,10 @@ import {Entity, PrimaryGeneratedColumn, Column} from "typeorm";

@Entity()
export class User {

@PrimaryGeneratedColumn()
id: number;

@Column()
name: string;

Expand Down
8 changes: 7 additions & 1 deletion src/query-builder/QueryExpressionMap.ts
Original file line number Diff line number Diff line change
Expand Up @@ -51,6 +51,11 @@ export class QueryExpressionMap {
*/
selectDistinct: boolean = false;

/**
* SELECT DISTINCT ON query (postgres).
*/
selectDistinctOn: string[] = [];

/**
* FROM-s to be selected.
*/
Expand Down Expand Up @@ -80,7 +85,7 @@ export class QueryExpressionMap {
/**
* Optional on ignore statement used in insertion query in databases.
*/
onIgnore: string | boolean = false;
onIgnore: string|boolean = false;

/**
* Optional on update statement used in insertion query in databases.
Expand Down Expand Up @@ -379,6 +384,7 @@ export class QueryExpressionMap {
map.queryType = this.queryType;
map.selects = this.selects.map(select => select);
map.selectDistinct = this.selectDistinct;
map.selectDistinctOn = this.selectDistinctOn;
this.aliases.forEach(alias => map.aliases.push(new Alias(alias)));
map.mainAlias = this.mainAlias;
map.valuesSet = this.valuesSet;
Expand Down
Loading

0 comments on commit 1293065

Please sign in to comment.