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.
1npx knex migrate:make add_categories_table1import { Knex } from 'knex';
2
3export async function up(knex: Knex): Promise<void> {
4 return knex.raw(`
5 CREATE TABLE categories (
6 id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
7 name text NOT NULL
8 );
9 CREATE TABLE categories_posts (
10 category_id int REFERENCES categories(id),
11 post_id int REFERENCES posts(id),
12 PRIMARY KEY (category_id, post_id)
13 );
14 `);
15}
16
17export async function down(knex: Knex): Promise<void> {
18 return knex.raw(`
19 DROP TABLE categories, categories_posts;
20 `);
21}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 "title": "My first post",
3 "content": "Hello world!",
4 "categoryIds": [1, 2]
5}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:
1INSERT INTO categories_posts (
2 post_id, category_id
3)
4 SELECT 1 as post_id, unnest(ARRAY[1,2]) AS category_id
5 FROM created_postTo understand the above code, we need to take a closer look at this SELECT query:
1SELECT 1 as post_id, unnest(ARRAY[1,2]) AS category_idAbove, 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.
1import { Injectable } from '@nestjs/common';
2import DatabaseService from '../database/database.service';
3import PostDto from './post.dto';
4import PostWithCategoryIdsModel from './postWithCategoryIds.model';
5
6@Injectable()
7class PostsRepository {
8 constructor(private readonly databaseService: DatabaseService) {}
9
10 async createWithCategories(postData: PostDto, authorId: number) {
11 const databaseResponse = await this.databaseService.runQuery(
12 `
13 WITH created_post AS (
14 INSERT INTO posts (
15 title,
16 post_content,
17 author_id
18 ) VALUES (
19 $1,
20 $2,
21 $3
22 ) RETURNING *
23 ),
24 created_relationships AS (
25 INSERT INTO categories_posts (
26 post_id, category_id
27 )
28 SELECT created_post.id AS post_id, unnest($4::int[]) AS category_id
29 FROM created_post
30 )
31 SELECT *, $4 as category_ids FROM created_post
32 `,
33 [postData.title, postData.content, authorId, postData.categoryIds],
34 );
35 return new PostWithCategoryIdsModel(databaseResponse.rows[0]);
36 }
37
38 // ...
39}
40
41export default PostsRepository;We also need to create a model that includes the categoryIds property.
1import PostModel, { PostModelData } from './post.model';
2
3interface PostWithCategoryIdsModelData extends PostModelData {
4 category_ids: number[] | null;
5}
6class PostWithCategoryIdsModel extends PostModel {
7 categoryIds: number[];
8 constructor(postData: PostWithCategoryIdsModelData) {
9 super(postData);
10 this.categoryIds = postData.category_ids || [];
11 }
12}
13
14export 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.
1SELECT category_id FROM categories_posts
2WHERE post_id = 3We can parse it into a single array to make it easier to work with.
1SELECT ARRAY(
2 SELECT category_id FROM categories_posts
3 WHERE post_id = 3
4) AS category_idsLet’s prepare a new model to handle the above data.
1import PostModel, { PostModelData } from './post.model';
2import UserModel from '../users/user.model';
3
4interface PostWithDetailsModelData extends PostModelData {
5 user_id: number;
6 user_email: string;
7 user_name: string;
8 user_password: string;
9 address_id: number | null;
10 address_street: string | null;
11 address_city: string | null;
12 address_country: string | null;
13 category_ids: number[] | null;
14}
15class PostWithDetails extends PostModel {
16 author: UserModel;
17 categoryIds: number[];
18 constructor(postData: PostWithDetailsModelData) {
19 super(postData);
20 this.author = new UserModel({
21 ...postData,
22 id: postData.user_id,
23 email: postData.user_email,
24 name: postData.user_name,
25 password: postData.user_password,
26 });
27 this.categoryIds = postData.category_ids || [];
28 }
29}
30
31export default PostWithDetails;We now have everything we need to fetch a post with its author and category ids.
1import { Injectable, NotFoundException } from '@nestjs/common';
2import DatabaseService from '../database/database.service';
3import PostWithDetails from './postWithDetails.model';
4
5@Injectable()
6class PostsRepository {
7 constructor(private readonly databaseService: DatabaseService) {}
8
9 async getWithDetails(postId: number) {
10 const postResponse = await this.databaseService.runQuery(
11 `
12 SELECT
13 posts.id AS id, posts.title AS title, posts.post_content AS post_content, posts.author_id as author_id,
14 users.id AS user_id, users.email AS user_email, users.name AS user_name, users.password AS user_password,
15 addresses.id AS address_id, addresses.street AS address_street, addresses.city AS address_city, addresses.country AS address_country
16 FROM posts
17 JOIN users ON posts.author_id = users.id
18 LEFT JOIN addresses ON users.address_id = addresses.id
19 WHERE posts.id=$1
20 `,
21 [postId],
22 );
23 const postEntity = postResponse.rows[0];
24 if (!postEntity) {
25 throw new NotFoundException();
26 }
27
28 const categoryIdsResponse = await this.databaseService.runQuery(
29 `
30 SELECT ARRAY(
31 SELECT category_id FROM categories_posts
32 WHERE post_id = $1
33 ) AS category_ids
34 `,
35 [postId],
36 );
37
38 return new PostWithDetails({
39 ...postEntity,
40 category_ids: categoryIdsResponse.rows[0].category_ids,
41 });
42 }
43 // ...
44}
45
46export 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.
1SELECT post_id
2FROM categories_posts
3WHERE category_id = 1Since we know the ids of all the posts, we can use the JOIN statement to match them with the rows from the posts table.
1SELECT posts.id AS post_id, posts.title AS post_title, posts.post_content AS post_content, posts.author_id AS author_id
2FROM categories_posts
3JOIN posts ON posts.id=categories_posts.post_id
4WHERE category_id = 1Let’s create a new model to prepare for the above data.
1import CategoryModel, { CategoryModelData } from './category.model';
2import PostModel, { PostModelData } from '../posts/post.model';
3
4export interface CategoryWithPostsModelData extends CategoryModelData {
5 posts: PostModelData[];
6}
7class CategoryWithPostsModel extends CategoryModel {
8 posts: PostModel[];
9 constructor(categoryData: CategoryWithPostsModelData) {
10 super(categoryData);
11 this.posts = categoryData.posts.map((postData) => {
12 return new PostModel(postData);
13 });
14 }
15}
16
17export 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.
1import { Injectable, NotFoundException } from '@nestjs/common';
2import DatabaseService from '../database/database.service';
3import CategoryWithPostsModel from './categoryWithPosts.model';
4
5@Injectable()
6class CategoriesRepository {
7 constructor(private readonly databaseService: DatabaseService) {}
8
9 async getCategoryWithPosts(categoryId: number) {
10 const categoriesDatabaseResponse = await this.databaseService.runQuery(
11 `
12 SELECT * FROM categories WHERE id=$1
13 `,
14 [categoryId],
15 );
16 if (!categoriesDatabaseResponse.rows[0]) {
17 throw new NotFoundException();
18 }
19
20 const postsDatabaseResponse = await this.databaseService.runQuery(
21 `
22 SELECT posts.id AS id, posts.title AS title, posts.post_content AS post_content, posts.author_id AS author_id
23 FROM categories_posts
24 JOIN posts ON posts.id=categories_posts.post_id
25 WHERE category_id = $1
26 `,
27 [categoryId],
28 );
29
30 return new CategoryWithPostsModel({
31 ...categoriesDatabaseResponse.rows[0],
32 posts: postsDatabaseResponse.rows,
33 });
34 }
35
36 // ...
37}
38
39export 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!