- 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
When designing a database, the tables we define often relate to each other. Managing those relationships is one of the essential parts of working with databases. The previous article taught us how to use raw SQL queries to set up our NestJS project to work with PostgreSQL. In this article, we go a step further and start writing more complex SQL queries involving the one-to-one relationship.
You can find the code from this article in this repository.
The idea behind one-to-one relationship
When designing a one-to-one relationship, a row from the first table has one matching row from the second table and the other way around.
In our case, the address is optional. A one-to-one relationship that is optional might be also referred to as one-to-zero-or-one relationship.
Instead of creating the addresses table, we could add the address_street, address_city, and address_country to the users table. However, as the table grows, it might sometimes make sense to split it into more than one table if we can separate a particular group of columns. This might not be the most popular type of relationship, but we might encounter it when working with various databases. Because of that, we go through how to set it up and work with it.
When deciding on whether to create a one-to-one relationship we can take a lot of factors into consideration. If you want to read more, check out this question on StackOverflow.
Working with a one-to-one relationship
A very straightforward example involves a user and an address. Let’s start by creating a new migration to define the addresses table and connect it to the users.
20220831115100_add_addresses_table.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 |
import { Knex } from 'knex'; export async function up(knex: Knex): Promise<void> { return knex.raw(` CREATE TABLE addresses ( id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, street text, city text, country text ); ALTER TABLE users ADD COLUMN address_id int UNIQUE REFERENCES addresses(id); `); } export async function down(knex: Knex): Promise<void> { return knex.raw(` DROP TABLE addresses; ALTER TABLE users DROP COLUMN address_id; `); } |
Above, we add the address_id column to the users table. In our application, a particular address can belong only to one user. Because of that, we add the unique constraint to the address_id column. When we do that, we ensure that only one user can refer to a particular address. Trying to tie more than one user to the same address would result in an error.
We also make the address_id column a foreign key that refers to the primary key of the addresses table. Thanks to that, we make sure that PostgreSQL knows there is a connection.
Inserting two entities in a single query
We want to be able to insert the user and the address into the database at the same time. A good way to do that is by using the WITH statement.
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 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 |
import { Injectable } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import { plainToInstance } from 'class-transformer'; import UserModel from './user.model'; import { CreateUserDto } from './dto/createUser.dto'; import isRecord from '../utils/isRecord'; import PostgresErrorCode from '../database/postgresErrorCode.enum'; import UserAlreadyExistsException from './exceptions/userAlreadyExists.exception'; @Injectable() class UsersRepository { constructor(private readonly databaseService: DatabaseService) {} private async createUserWithAddress(userData: CreateUserDto) { try { const databaseResponse = await this.databaseService.runQuery( ` WITH created_address AS ( INSERT INTO addresses ( street, city, country ) VALUES ( $1, $2, $3 ) RETURNING * ) INSERT INTO users ( email, name, password, address_id ) VALUES ( $4, $5, $6, (SELECT id FROM created_address) ) RETURNING * `, [ userData.address.street, userData.address.city, userData.address.country, userData.email, userData.name, userData.password, ], ); return new UserModel(databaseResponse.rows[0]); } catch (error) { if (isRecord(error) && error.code === PostgresErrorCode.UniqueViolation) { throw new UserAlreadyExistsException(userData.email); } throw error; } } async create(userData: CreateUserDto) { if (userData.address) { return this.createUserWithAddress(userData); } // ... } // ... } export default UsersRepository; |
In this article, we use authentication with JWT. If you want to know more, check out API with NestJS #3. Authenticating users with bcrypt, Passport, JWT, and cookies
Above, we create a Common Table Expression query using the WITH statement. Thanks to that, we create both the address and the user in a single SQL that is atomic. If something goes wrong when creating the user, the address won’t be persisted in the database.
Expanding the models
As our queries get more complex, the models grow bigger too. So let’s first create a model for the address.
address.model.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 |
interface AddressModelData { id: number; street: string; city: string; country: string; } class AddressModel { id: number; street: string; city: string; country: string; constructor(data: AddressModelData) { this.id = data.id; this.street = data.street; this.city = data.city; this.country = data.country; } } export default AddressModel; |
Above, I create the model and define the constructor manually. You can use the class-transformer library for that, if you prefer.
The last step in creating the models is to use the above class in the model of the user.
user.model.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 33 34 35 36 37 38 |
import { Exclude } from 'class-transformer'; import AddressModel from './address.model'; type UserModelData = { id: number; name: number; email: string; password: string; address_id?: number; address_street?: string; address_city?: string; address_country?: string; }; class UserModel { id: number; name: number; email: string; @Exclude() password: string; address?: AddressModel; constructor(data: UserModelData) { this.id = data.id; this.name = data.name; this.email = data.email; this.password = data.password; if (data.address_id) { this.address = new AddressModel({ id: data.address_id, street: data.address_street, city: data.address_city, country: data.address_country, }); } } } export default UserModel; |
Querying two tables
Our queries can fetch rows from multiple tables at once and match them. A good way of doing that is with a JOIN query.
1 2 3 4 5 |
SELECT users.*, addresses.street as address_street, addresses.city as address_city, addresses.country as address_country FROM users JOIN addresses ON users.address_id = addresses.id WHERE email=$1 |
When we use the JOIN keyword, we perform the inner join. The crucial thing is that it returns records with matching values in both tables. In our case, the address is optional. Running the above query for a user that does not have the address would return nothing.
To fix the issue, we need to perform the outer join. Outer joins preserve the rows that don’t have matching values. In our case, we want to use the LEFT JOIN that returns all records from the left table and the matched records from the right table. In our case, the left table is users, and the right table is the addresses.
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 |
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; |
Thanks to the above approach, our query works correctly for users that don’t have the address.
Returning the related entity when inserting
Before, we used the WITH statement to create the user and the address in a single query. We can use two WITH statements to return the data from both tables.
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 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 |
import { Injectable } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import UserModel from './user.model'; import { CreateUserDto } from './dto/createUser.dto'; import isRecord from '../utils/isRecord'; import PostgresErrorCode from '../database/postgresErrorCode.enum'; import UserAlreadyExistsException from './exceptions/userAlreadyExists.exception'; @Injectable() class UsersRepository { constructor(private readonly databaseService: DatabaseService) {} private async createUserWithAddress(userData: CreateUserDto) { try { const databaseResponse = await this.databaseService.runQuery( ` WITH created_address AS ( INSERT INTO addresses ( street, city, country ) VALUES ( $1, $2, $3 ) RETURNING * ), created_user AS ( INSERT INTO users ( email, name, password, address_id ) VALUES ( $4, $5, $6, (SELECT id FROM created_address) ) RETURNING * ) SELECT created_user.id AS id, created_user.email AS email, created_user.name AS name, created_user.password AS password, created_address.id AS address_id, street AS address_street, city AS address_city, country AS address_country FROM created_user, created_address `, [ userData.address.street, userData.address.city, userData.address.country, userData.email, userData.name, userData.password, ], ); return new UserModel(databaseResponse.rows[0]); } catch (error) { if (isRecord(error) && error.code === PostgresErrorCode.UniqueViolation) { throw new UserAlreadyExistsException(userData.email); } throw error; } } // ... } export default UsersRepository; |
Thanks to the above, our API returns the user together with the address when signing up.
Summary
In this article, we’ve gone through the idea behind one-to-one relationships. We’ve also learned to work with them using PostgreSQL and raw SQL queries. When doing that, we had to write common table expressions to make sure we created two entities in a single query. We’ve also identified the difference between inner and outer joins. There is still much to learn regarding relationships in PostgreSQL, so stay tuned!