- 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
Designing relationships between tables is one of the crucial parts of working with databases. In this article, we look into a more complex relationship called many-to-many.
You can find the code from this article in this repository.
The many-to-many relationship
A many-to-many relationship happens when many records in one table relate to many records in another table. A good example is a connection between posts and categories. A particular post can be published under multiple categories. For example, this article falls under both the SQL and JavaScript categories. On the other hand, a single category can be related to numerous different posts.
So far, we’ve worked with one-to-one or many-to-one relationships using raw SQL queries. In the above approaches, we use a simple column containing a foreign key that matches a row from a different table.
The case gets complicated when we want to create a connection between one post and multiple categories. We shouldn’t put multiple values in the category_id column. To implement a many-to-many relationship, we create a joining table.
Creating the categories_posts table allows us to store the relationships between particular categories and posts.
Creating the many-to-many relationship
Let’s define a migration that creates the categories and categories_posts tables.
1 |
npx knex migrate:make add_categories_table |
20220914233800_add_categories_table.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 |
import { Knex } from 'knex'; export async function up(knex: Knex): Promise<void> { return knex.raw(` CREATE TABLE categories ( id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, name text NOT NULL ); CREATE TABLE categories_posts ( category_id int REFERENCES categories(id), post_id int REFERENCES posts(id), PRIMARY KEY (category_id, post_id) ); `); } export async function down(knex: Knex): Promise<void> { return knex.raw(` DROP TABLE categories, categories_posts; `); } |
An important thing to notice in how we created the categories_posts table is that it doesn’t have a separate id column. Instead, we specify a composite primary key. This approach has some advantages. First, we save a bit of disk space thanks to not creating the id column. But more importantly, we make sure it is unique thanks to marking a combination of the category_id and post_id as the primary key. All rows in a table should have a different primary key. Thanks to that, the following data would never appear in our table:
By the above, we ensure that a particular post might relate to a particular category only once.
Connecting posts to categories
When a user publishes a post, it can be related to multiple categories. For example, we might accept the following data through our API:
1 2 3 4 5 |
{ "title": "My first post", "content": "Hello world!", "categoryIds": [1, 2] } |
The above means that we want to add two rows to the categories_posts table:
Fortunately, we can insert multiple rows into a table simultaneously. One way of doing that is inserting a result of a SELECT query:
1 2 3 4 5 |
INSERT INTO categories_posts ( post_id, category_id ) SELECT 1 as post_id, unnest(ARRAY[1,2]) AS category_id FROM created_post |
To understand the above code, we need to take a closer look at this SELECT query:
1 |
SELECT 1 as post_id, unnest(ARRAY[1,2]) AS category_id |
Above, we use the unnest function to expand an array to a set of rows. Thanks to that, our SELECT query returns multiple rows that the INSERT statement saves into the database.
We can now use all of the above knowledge to create a post and connect it to categories in the same query.
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 33 34 35 36 37 38 39 40 41 |
import { Injectable } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import PostDto from './post.dto'; import PostWithCategoryIdsModel from './postWithCategoryIds.model'; @Injectable() class PostsRepository { constructor(private readonly databaseService: DatabaseService) {} async createWithCategories(postData: PostDto, authorId: number) { const databaseResponse = await this.databaseService.runQuery( ` WITH created_post AS ( INSERT INTO posts ( title, post_content, author_id ) VALUES ( $1, $2, $3 ) RETURNING * ), created_relationships AS ( INSERT INTO categories_posts ( post_id, category_id ) SELECT created_post.id AS post_id, unnest($4::int[]) AS category_id FROM created_post ) SELECT *, $4 as category_ids FROM created_post `, [postData.title, postData.content, authorId, postData.categoryIds], ); return new PostWithCategoryIdsModel(databaseResponse.rows[0]); } // ... } export default PostsRepository; |
We also need to create a model that includes the categoryIds property.
postWithCategoryIds.model.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 |
import PostModel, { PostModelData } from './post.model'; interface PostWithCategoryIdsModelData extends PostModelData { category_ids: number[] | null; } class PostWithCategoryIdsModel extends PostModel { categoryIds: number[]; constructor(postData: PostWithCategoryIdsModelData) { super(postData); this.categoryIds = postData.category_ids || []; } } export default PostWithCategoryIdsModel; |
Thanks to the above, we can now create posts and connect them to categories in a single query.
Fetching the ids of categories of a certain post
So far, when fetching the details of a certain post, we’ve attached the details of an author. Let’s take it a step further, and attach the ids of the categories related to the post. Let’s break down this problem into a simple set of steps to perform.
First, we need to get all the rows from the categories_posts table related to a particular post.
1 2 |
SELECT category_id FROM categories_posts WHERE post_id = 3 |
We can parse it into a single array to make it easier to work with.
1 2 3 4 |
SELECT ARRAY( SELECT category_id FROM categories_posts WHERE post_id = 3 ) AS category_ids |
Let’s prepare a new model to handle the above data.
postWithDetails.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 |
import PostModel, { PostModelData } from './post.model'; import UserModel from '../users/user.model'; interface PostWithDetailsModelData extends PostModelData { user_id: number; user_email: string; user_name: string; user_password: string; address_id: number | null; address_street: string | null; address_city: string | null; address_country: string | null; category_ids: number[] | null; } class PostWithDetails extends PostModel { author: UserModel; categoryIds: number[]; constructor(postData: PostWithDetailsModelData) { super(postData); this.author = new UserModel({ ...postData, id: postData.user_id, email: postData.user_email, name: postData.user_name, password: postData.user_password, }); this.categoryIds = postData.category_ids || []; } } export default PostWithDetails; |
We now have everything we need to fetch a post with its author and category ids.
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 33 34 35 36 37 38 39 40 41 42 43 44 45 46 |
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, addresses.id AS address_id, addresses.street AS address_street, addresses.city AS address_city, addresses.country AS address_country FROM posts JOIN users ON posts.author_id = users.id LEFT JOIN addresses ON users.address_id = addresses.id WHERE posts.id=$1 `, [postId], ); const postEntity = postResponse.rows[0]; if (!postEntity) { throw new NotFoundException(); } const categoryIdsResponse = await this.databaseService.runQuery( ` SELECT ARRAY( SELECT category_id FROM categories_posts WHERE post_id = $1 ) AS category_ids `, [postId], ); return new PostWithDetails({ ...postEntity, category_ids: categoryIdsResponse.rows[0].category_ids, }); } // ... } export default PostsRepository; |
Fetching all posts from a certain category
There is a big chance that we will want to get a list of all the posts from a certain category. To achieve this, we need to join the data from the posts table with categories_posts.
Let’s break down this problem into smaller chunks. First, we must fetch all post ids from a certain category.
1 2 3 |
SELECT post_id FROM categories_posts WHERE category_id = 1 |
Since we know the ids of all the posts, we can use the JOIN statement to match them with the rows from the posts table.
1 2 3 4 |
SELECT posts.id AS post_id, posts.title AS post_title, posts.post_content AS post_content, posts.author_id AS author_id FROM categories_posts JOIN posts ON posts.id=categories_posts.post_id WHERE category_id = 1 |
Let’s create a new model to prepare for the above data.
categoryWithPosts.model.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 |
import CategoryModel, { CategoryModelData } from './category.model'; import PostModel, { PostModelData } from '../posts/post.model'; export interface CategoryWithPostsModelData extends CategoryModelData { posts: PostModelData[]; } class CategoryWithPostsModel extends CategoryModel { posts: PostModel[]; constructor(categoryData: CategoryWithPostsModelData) { super(categoryData); this.posts = categoryData.posts.map((postData) => { return new PostModel(postData); }); } } export default CategoryWithPostsModel; |
We now can use all of the above to:
- fetch the data of a particular category,
- match it with related posts,
- fit the data into the model.
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 |
import { Injectable, NotFoundException } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import CategoryWithPostsModel from './categoryWithPosts.model'; @Injectable() class CategoriesRepository { constructor(private readonly databaseService: DatabaseService) {} async getCategoryWithPosts(categoryId: number) { const categoriesDatabaseResponse = await this.databaseService.runQuery( ` SELECT * FROM categories WHERE id=$1 `, [categoryId], ); if (!categoriesDatabaseResponse.rows[0]) { throw new NotFoundException(); } const postsDatabaseResponse = 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 FROM categories_posts JOIN posts ON posts.id=categories_posts.post_id WHERE category_id = $1 `, [categoryId], ); return new CategoryWithPostsModel({ ...categoriesDatabaseResponse.rows[0], posts: postsDatabaseResponse.rows, }); } // ... } export default CategoriesRepository; |
We can use the above logic to fetch the details of the category when it is requested.
Summary
In this article, we’ve gone through the many-to-many relationship. When doing that, we implemented an example with posts and categories. To do that, we learned how to manage a joining table and insert multiple entities into the database with one query. There is still more to learn about using NestJS with raw SQL queries, so stay tuned!
Great article, thanks! Please, address the common issue of how to update post-category relations when we add some new categories, some remain unchanged, and remove the others (within the single request)
Thank you. I cover this topic in the next article in the series:
API with NestJS #76. Working with transactions using raw SQL queries
I hope this helps 🙂