- 1. API with NestJS #1. Controllers, routing and the module structure
- 2. API with NestJS #2. Setting up a PostgreSQL database with TypeORM
- 3. API with NestJS #3. Authenticating users with bcrypt, Passport, JWT, and cookies
- 4. API with NestJS #4. Error handling and data validation
- 5. API with NestJS #5. Serializing the response with interceptors
- 6. API with NestJS #6. Looking into dependency injection and modules
- 7. API with NestJS #7. Creating relationships with Postgres and TypeORM
- 8. API with NestJS #8. Writing unit tests
- 9. API with NestJS #9. Testing services and controllers with integration tests
- 10. API with NestJS #10. Uploading public files to Amazon S3
- 11. API with NestJS #11. Managing private files with Amazon S3
- 12. API with NestJS #12. Introduction to Elasticsearch
- 13. API with NestJS #13. Implementing refresh tokens using JWT
- 14. API with NestJS #14. Improving performance of our Postgres database with indexes
- 15. API with NestJS #15. Defining transactions with PostgreSQL and TypeORM
- 16. API with NestJS #16. Using the array data type with PostgreSQL and TypeORM
- 17. API with NestJS #17. Offset and keyset pagination with PostgreSQL and TypeORM
- 18. API with NestJS #18. Exploring the idea of microservices
- 19. API with NestJS #19. Using RabbitMQ to communicate with microservices
- 20. API with NestJS #20. Communicating with microservices using the gRPC framework
- 21. API with NestJS #21. An introduction to CQRS
- 22. API with NestJS #22. Storing JSON with PostgreSQL and TypeORM
- 23. API with NestJS #23. Implementing in-memory cache to increase the performance
- 24. API with NestJS #24. Cache with Redis. Running the app in a Node.js cluster
- 25. API with NestJS #25. Sending scheduled emails with cron and Nodemailer
- 26. API with NestJS #26. Real-time chat with WebSockets
- 27. API with NestJS #27. Introduction to GraphQL. Queries, mutations, and authentication
- 28. API with NestJS #28. Dealing in the N + 1 problem in GraphQL
- 29. API with NestJS #29. Real-time updates with GraphQL subscriptions
- 30. API with NestJS #30. Scalar types in GraphQL
- 31. API with NestJS #31. Two-factor authentication
- 32. API with NestJS #32. Introduction to Prisma with PostgreSQL
- 33. API with NestJS #33. Managing PostgreSQL relationships with Prisma
- 34. API with NestJS #34. Handling CPU-intensive tasks with queues
- 35. API with NestJS #35. Using server-side sessions instead of JSON Web Tokens
- 36. API with NestJS #36. Introduction to Stripe with React
- 37. API with NestJS #37. Using Stripe to save credit cards for future use
- 38. API with NestJS #38. Setting up recurring payments via subscriptions with Stripe
- 39. API with NestJS #39. Reacting to Stripe events with webhooks
- 40. API with NestJS #40. Confirming the email address
- 41. API with NestJS #41. Verifying phone numbers and sending SMS messages with Twilio
- 42. API with NestJS #42. Authenticating users with Google
- 43. API with NestJS #43. Introduction to MongoDB
- 44. API with NestJS #44. Implementing relationships with MongoDB
- 45. API with NestJS #45. Virtual properties with MongoDB and Mongoose
- 46. API with NestJS #46. Managing transactions with MongoDB and Mongoose
- 47. API with NestJS #47. Implementing pagination with MongoDB and Mongoose
- 48. API with NestJS #48. Definining indexes with MongoDB and Mongoose
- 49. API with NestJS #49. Updating with PUT and PATCH with MongoDB and Mongoose
- 50. API with NestJS #50. Introduction to logging with the built-in logger and TypeORM
- 51. API with NestJS #51. Health checks with Terminus and Datadog
- 52. API with NestJS #52. Generating documentation with Compodoc and JSDoc
- 53. API with NestJS #53. Implementing soft deletes with PostgreSQL and TypeORM
- 54. API with NestJS #54. Storing files inside a PostgreSQL database
- 55. API with NestJS #55. Uploading files to the server
- 56. API with NestJS #56. Authorization with roles and claims
- 57. API with NestJS #57. Composing classes with the mixin pattern
- 58. API with NestJS #58. Using ETag to implement cache and save bandwidth
- 59. API with NestJS #59. Introduction to a monorepo with Lerna and Yarn workspaces
- 60. API with NestJS #60. The OpenAPI specification and Swagger
- 61. API with NestJS #61. Dealing with circular dependencies
- 62. API with NestJS #62. Introduction to MikroORM with PostgreSQL
- 63. API with NestJS #63. Relationships with PostgreSQL and MikroORM
- 64. API with NestJS #64. Transactions with PostgreSQL and MikroORM
- 65. API with NestJS #65. Implementing soft deletes using MikroORM and filters
- 66. API with NestJS #66. Improving PostgreSQL performance with indexes using MikroORM
- 67. API with NestJS #67. Migrating to TypeORM 0.3
- 68. API with NestJS #68. Interacting with the application through REPL
- 69. API with NestJS #69. Database migrations with TypeORM
- 70. API with NestJS #70. Defining dynamic modules
- 71. API with NestJS #71. Introduction to feature flags
- 72. API with NestJS #72. Working with PostgreSQL using raw SQL queries
- 73. API with NestJS #73. One-to-one relationships with raw SQL queries
- 74. API with NestJS #74. Designing many-to-one relationships using raw SQL queries
- 75. API with NestJS #75. Many-to-many relationships using raw SQL queries
- 76. API with NestJS #76. Working with transactions using raw SQL queries
- 77. API with NestJS #77. Offset and keyset pagination with raw SQL queries
- 78. API with NestJS #78. Generating statistics using aggregate functions in raw SQL
- 79. API with NestJS #79. Implementing searching with pattern matching and raw SQL
- 80. API with NestJS #80. Updating entities with PUT and PATCH using raw SQL queries
- 81. API with NestJS #81. Soft deletes with raw SQL queries
- 82. API with NestJS #82. Introduction to indexes with raw SQL queries
- 83. API with NestJS #83. Text search with tsvector and raw SQL
- 84. API with NestJS #84. Implementing filtering using subqueries with raw SQL
- 85. API with NestJS #85. Defining constraints with raw SQL
- 86. API with NestJS #86. Logging with the built-in logger when using raw SQL
- 87. API with NestJS #87. Writing unit tests in a project with raw SQL
- 88. API with NestJS #88. Testing a project with raw SQL using integration tests
- 89. API with NestJS #89. Replacing Express with Fastify
- 90. API with NestJS #90. Using various types of SQL joins
- 91. API with NestJS #91. Dockerizing a NestJS API with Docker Compose
- 92. API with NestJS #92. Increasing the developer experience with Docker Compose
- 93. API with NestJS #93. Deploying a NestJS app with Amazon ECS and RDS
- 94. API with NestJS #94. Deploying multiple instances on AWS with a load balancer
- 95. API with NestJS #95. CI/CD with Amazon ECS and GitHub Actions
- 96. API with NestJS #96. Running unit tests with CI/CD and GitHub Actions
- 97. API with NestJS #97. Introduction to managing logs with Amazon CloudWatch
- 98. API with NestJS #98. Health checks with Terminus and Amazon ECS
- 99. API with NestJS #99. Scaling the number of application instances with Amazon ECS
- 100. API with NestJS #100. The HTTPS protocol with Route 53 and AWS Certificate Manager
- 101. API with NestJS #101. Managing sensitive data using the AWS Secrets Manager
- 102. API with NestJS #102. Writing unit tests with Prisma
- 103. API with NestJS #103. Integration tests with Prisma
- 104. API with NestJS #104. Writing transactions with Prisma
- 105. API with NestJS #105. Implementing soft deletes with Prisma and middleware
- 106. API with NestJS #106. Improving performance through indexes with Prisma
- 107. API with NestJS #107. Offset and keyset pagination with Prisma
- 108. API with NestJS #108. Date and time with Prisma and PostgreSQL
- 109. API with NestJS #109. Arrays with PostgreSQL and Prisma
- 110. API with NestJS #110. Managing JSON data with PostgreSQL and Prisma
- 111. API with NestJS #111. Constraints with PostgreSQL and Prisma
- 112. API with NestJS #112. Serializing the response with Prisma
- 113. API with NestJS #113. Logging with Prisma
- 114. API with NestJS #114. Modifying data using PUT and PATCH methods with Prisma
- 115. API with NestJS #115. Database migrations with Prisma
- 116. API with NestJS #116. REST API versioning
- 117. API with NestJS #117. CORS – Cross-Origin Resource Sharing
- 118. API with NestJS #118. Uploading and streaming videos
- 119. API with NestJS #119. Type-safe SQL queries with Kysely and PostgreSQL
- 120. API with NestJS #120. One-to-one relationships with the Kysely query builder
- 121. API with NestJS #121. Many-to-one relationships with PostgreSQL and Kysely
It’s a very common case to need to combine multiple related tables. In SQL, we can do that using a join statement. Therefore, this article explains various types of joins along with real-life examples.
Inner joins
A few articles ago, we defined the users and posts tables.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 |
CREATE TABLE users ( id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, email text NOT NULL UNIQUE, name text NOT NULL, password text NOT NULL, address_id int UNIQUE REFERENCES addresses(id) ); CREATE TABLE posts ( id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, title text NOT NULL, post_content text NOT NULL, author_id int REFERENCES users(id) NOT NULL ); |
It’s typical to retrieve a particular post along with the details of its author. The easiest way of doing that is to perform an inner join. An inner join will return all rows from the posts table that have a corresponding row in the users table.
To find a corresponding row, we need to tell PostgreSQL to match the author_id column from the posts table and the id column from the users table.
1 2 3 4 |
SELECT posts.title AS post_title, users.email AS user_email FROM posts JOIN users ON posts.author_id = users.id LIMIT 2 |
We could write INNER JOIN instead of JOIN, but inner join is a default kind of join.
The diagram above shows that the inner join would disregard rows from the posts table without a matching user and rows from the users table without a matching post. It does not bother us in the above case because every post has an author.
In our application, we use the above approach when fetching the details of a particular post.
posts.repository.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 |
import { Injectable, NotFoundException } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import PostWithDetails from './postWithDetails.model'; @Injectable() class PostsRepository { constructor(private readonly databaseService: DatabaseService) {} async getWithDetails(postId: number) { const postResponse = await this.databaseService.runQuery( ` SELECT posts.id AS id, posts.title AS title, posts.post_content AS post_content, posts.author_id as author_id, users.id AS user_id, users.email AS user_email, users.name AS user_name, users.password AS user_password FROM posts JOIN users ON posts.author_id = users.id WHERE posts.id=$1 `, [postId], ); const postEntity = postResponse.rows[0]; if (!postEntity) { throw new NotFoundException(); } return new PostWithDetails(postEntity); } // ... } export default PostsRepository; |
There is also a special kind of an inner join called the self join. It occurs when we link a table to itself. It might come in handy when we have a hierarchical structure. A good example is an employee who is a manager of another employee.
Outer joins
In one of the recent articles, we’ve added the addresses table.
1 2 3 4 5 6 |
CREATE TABLE addresses ( id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, street text, city text, country text ); |
Let’s create one user with the address and one without it.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 |
WITH created_address AS ( INSERT INTO addresses ( street, city, country ) VALUES ( 'Amphitheatre Parkway', 'Mountain View', 'USA' ) RETURNING * ) INSERT INTO users ( email, name, password, address_id ) VALUES ( 'adam@wilson.com', 'Adam', 'strongPassword123', (SELECT id FROM created_address) ); INSERT INTO users ( email, name, password, address_id ) VALUES ( 'amanda@williams.com', 'Amanda', 'strongPassword123', null ); |
Now, let’s try using the inner join to find all users and their addresses.
1 2 3 |
SELECT users.name AS name, addresses.country AS country FROM users JOIN addresses ON users.address_id = addresses.id |
The above query does not return users that don’t have addresses. To fix this issue, we need to perform an outer join. An outer join can return both matched and unmatched values.
Left join
The left outer join returns all rows from the first table matched with the rows from the second table.
If we perform the left join on users and addresses, we get all of the users, regardless of whether they have the address.
1 2 3 |
SELECT users.name AS name, addresses.country AS country FROM users LEFT JOIN addresses ON users.address_id = addresses.id |
We use the above approach when fetching all of the details about a particular user.
users.repository.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 |
import { Injectable, NotFoundException } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import UserModel from './user.model'; @Injectable() class UsersRepository { constructor(private readonly databaseService: DatabaseService) {} async getByEmail(email: string) { const databaseResponse = await this.databaseService.runQuery( ` SELECT users.*, addresses.street AS address_street, addresses.city AS address_city, addresses.country AS address_country FROM users LEFT JOIN addresses ON users.address_id = addresses.id WHERE email=$1 `, [email], ); const entity = databaseResponse.rows[0]; if (!entity) { throw new NotFoundException(); } return new UserModel(entity); } // ... } export default UsersRepository; |
Right join
The right join works in reverse as compared to the left join. It returns all rows from the second table and the rows matched with the first table.
We could use it to reverse the query we use to fetch the users together with their addresses.
1 2 3 |
SELECT users.name AS name, addresses.country AS country FROM addresses RIGHT JOIN users ON users.address_id = addresses.id |
Please notice that in the above query, addresses is the name of the left table, and users is the name of the right table.
Full outer join
Let’s add a new address without assigning it to a user.
1 2 3 4 5 6 7 8 9 |
INSERT INTO addresses ( street, city, country ) VALUES ( 'Niagara Parkway', 'Niagara Falls', 'Canada' ) |
The outer joins we’ve done so far in this article will not return the above record.
1 2 3 |
SELECT users.name AS name, addresses.country AS country FROM users LEFT JOIN addresses ON users.address_id = addresses.id |
If we want to include our new address in the results, we can perform a full outer join. The full outer join returns rows from both tables, matching the results if possible.
If a particular row is not matched in the other table, it’s still included. If we run a full outer join on the users and addresses table, we get all the records from both tables.
1 2 3 |
SELECT users.name AS name, addresses.country AS country FROM addresses FULL JOIN users ON users.address_id = addresses.id |
As you can see in the above result, doing a full outer join can result in many null values, so we need to consider it.
Summary
In this article, we’ve gone through all the types of joins we might need when developing a NestJS application with raw SQL queries. It included the inner joins, which is the default type. Besides that, we went through various types of outer joins. All the above knowledge can help you choose the right join for a given situation.