- 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
As applications grow, the number of different entities also increases. A crucial part of learning how to design a database is creating relationships between them. This is because our entities will often relate to each other in some way.
Relational databases such as PostgreSQL are an industry standard for quite some time now. Although there are NoSQL alternatives such as MongoDB, SQL might still be considered a better choice, especially for structured data that contains a lot of relations.
In this article, we learn about various types of relationships and implement them with Postgres. Instead of using TypeORM as we did in the seventh part of this series, we use Prisma.
Throughout the article, we often use functionalities developed in other parts of this series. If you want to see the full code, you can find it in this repository.
One-To-One
The simplest relationship is called one-to-one. Here, a row from the first table matches just one row from the second table and vice versa.
To represent it, let’s create the user and the address.
userSchema.prisma
1 2 3 4 5 6 |
model User { id Int @default(autoincrement()) @id email String @unique name String password String } |
Above, we use the @unique attribute. It creates a constraint, making it impossible to create two users with the same email.
After creating the above schema, let’s generate a migration for it.
If you want to know more about this process, check out API with NestJS #32. Introduction to Prisma with PostgreSQL
1 |
npm run generate-schema |
1 |
npx prisma migrate dev --name user --preview-feature |
1 |
npx prisma generate |
Above, we can see that migrating and generating a new Prisma Client takes us three commands. Instead of that, let’s create a command that merges those.
package.json
1 2 3 4 5 6 7 8 9 |
{ "name": "nestjs-prisma", "scripts": { // ... "generate-schema": "cat src/*/*.prisma > prisma/schema.prisma", "migrate": "npm run generate-schema && prisma migrate dev --preview-feature --name $npm_config_name && prisma generate", }, // ... } |
Now we need to run npm run migrate --name=user.
Above, NPM gets --name=user and gives us the access to it as $npm_config_name. We could do it with any variable name, such as --x=Hello and $npm_config_x.
Now we can do the same thing when creating the address model.
addressSchema.prisma
1 2 3 4 5 6 |
model Address { id Int @default(autoincrement()) @id street String city String country String } |
1 |
npm run migrate --name=address |
Defining the relationship
To define the relationship, one of the sides of the relationship needs to hold the other side’s id. In our example, we add the addressId to the user model.
userSchema.prisma
1 2 3 4 5 6 7 8 |
model User { id Int @default(autoincrement()) @id email String @unique name String password String address Address? @relation(fields: [addressId], references: [id]) addressId Int? } |
Using the ? sign above makes the address optional for the user.
Above, we’ve also used the @relation attribute. We pass two arguments to it:
- the addressId field from the user model is the foreign key and points to an address,
- the id field from the address model that we want to reference with the addressId field.
We also need to add information about the relation to the address model.
addressSchema.prisma
1 2 3 4 5 6 7 |
model Address { id Int @default(autoincrement()) @id street String city String country String user User? } |
The address table in the database does not hold any information tying it to a certain user. Therefore, there is a possibility that a certain address is not related to any user. Because of that, we need to mark the user property as nullable.
1 |
npm run migrate --name=address_user_relation |
By doing all of the above, we achieve the following:
- the user can have an address but does not need to,
- the address can but does not have to be associated with a user.
Alternatively, we could also add the userId to the address model to invert the relation.
Let’s look into how Prisma generates the above migration:
migration.sql
1 2 3 4 5 6 7 8 |
-- AlterTable ALTER TABLE "User" ADD COLUMN "addressId" INTEGER; -- CreateIndex CREATE UNIQUE INDEX "User_addressId_unique" ON "User"("addressId"); -- AddForeignKey ALTER TABLE "User" ADD FOREIGN KEY ("addressId") REFERENCES "Address"("id") ON DELETE SET NULL ON UPDATE CASCADE; |
The crucial thing above is that we create a unique index. Because of that, there can’t be two users pointing to the same address.
Creating related records
With Prisma, we can easily create both a user entity and the address and create a relationship between them at once. To do that, we need to use the create property.
users.service.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 |
import { Injectable } from '@nestjs/common'; import { PrismaService } from '../prisma/prisma.service'; import { CreateUserDto } from './dto/createUser.dto'; @Injectable() export class UsersService { constructor(private readonly prismaService: PrismaService) {} // ... async create(user: CreateUserDto) { const address = user.address; return this.prismaService.user.create({ data: { ...user, address: { create: address, }, }, }); } } |
We can see that we didn’t receive the full address in the response, just the id. We can improve that by using the include property.
users.service.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 |
import { Injectable } from '@nestjs/common'; import { PrismaService } from '../prisma/prisma.service'; import { CreateUserDto } from './dto/createUser.dto'; @Injectable() export class UsersService { constructor(private readonly prismaService: PrismaService) {} // ... async create(user: CreateUserDto) { const address = user.address; return this.prismaService.user.create({ data: { ...user, address: { create: address, }, }, include: { address: true, }, }); } } |
One-to-Many and Many-To-One
With the One-To-Many relationship, a row from the first table can be related to multiple rows from the second table. The row from the second table can be linked to just one row of the first table, though.
A good example could be posts and users. A user can write multiple posts in our implementation, but a post is authored by just a single user.
postSchema.prisma
1 2 3 4 5 6 7 |
model Post { id Int @default(autoincrement()) @id title String content String author User @relation(fields: [authorId], references: [id]) authorId Int } |
Above, we store the information about the author in the post model. We can see that a post can have only one author.
We also need to add information about the relationship to the user model.
userSchema.prisma
1 2 3 4 5 6 7 8 9 |
model User { id Int @default(autoincrement()) @id email String @unique name String password String address Address? @relation(fields: [addressId], references: [id]) addressId Int? posts Post[] } |
Let’s run the migration and see what SQL script Prisma generated for us.
1 |
npm run migrate --name=user_post_relation |
migration.sql
1 2 3 4 5 |
-- AlterTable ALTER TABLE "Post" ADD COLUMN "authorId" INTEGER NOT NULL; -- AddForeignKey ALTER TABLE "Post" ADD FOREIGN KEY ("authorId") REFERENCES "User"("id") ON DELETE CASCADE ON UPDATE CASCADE; |
Above, we can see that we don’t use the unique indexes in the case of the One-To-Many relationship. This is how One-To-Many differs from One-To-One. Because of that, we achieve the following:
- the user can have zero or more posts,
- the post needs to have an author.
Let’s modify our PostsService in a way that allows us to assign an author to the post.
posts.service.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 |
import { Injectable } from '@nestjs/common'; import { PrismaService } from '../prisma/prisma.service'; import { CreatePostDto } from './dto/createPost.dto'; import { User } from '@prisma/client'; @Injectable() export class PostsService { constructor(private readonly prismaService: PrismaService) {} async createPost(post: CreatePostDto, user: User) { return this.prismaService.post.create({ data: { ...post, author: { connect: { id: user.id, }, }, }, }); } // ... } |
In this article, we depend on the authentication functionality described in API with NestJS #3. Authenticating users with bcrypt, Passport, JWT, and cookies
Above, the crucial part is that we need to import it from @prisma/client to get the user model interface. With the connect property, we attach the existing user to the newly created post.
Many-to-Many
With the Many-To-Many relationship, a row from the first table can relate to the second table’s multiple rows and vice versa.
A good example might be a post that can belong to multiple categories. A category, on the other hand, can contain multiple posts.
The easiest way to define a Many-To-Many relationship in Prisma is to create a so-called implicit relationship.
categorySchema.prisma
1 2 3 4 5 |
model Category { id Int @id @default(autoincrement()) name String posts Post[] } |
postSchema.prisma
1 2 3 4 5 6 7 8 |
model Post { id Int @default(autoincrement()) @id title String content String author User @relation(fields: [authorId], references: [id]) authorId Int categories Category[] } |
Now, let’s run the migration and check out the results.
1 |
npm run migrate --name=category_post_relation |
migration.sql
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 |
-- CreateTable CREATE TABLE "Category" ( "id" SERIAL NOT NULL, "name" TEXT NOT NULL, PRIMARY KEY ("id") ); -- CreateTable CREATE TABLE "_CategoryToPost" ( "A" INTEGER NOT NULL, "B" INTEGER NOT NULL ); -- CreateIndex CREATE UNIQUE INDEX "_CategoryToPost_AB_unique" ON "_CategoryToPost"("A", "B"); -- CreateIndex CREATE INDEX "_CategoryToPost_B_index" ON "_CategoryToPost"("B"); -- AddForeignKey ALTER TABLE "_CategoryToPost" ADD FOREIGN KEY ("A") REFERENCES "Category"("id") ON DELETE CASCADE ON UPDATE CASCADE; -- AddForeignKey ALTER TABLE "_CategoryToPost" ADD FOREIGN KEY ("B") REFERENCES "Post"("id") ON DELETE CASCADE ON UPDATE CASCADE; |
Above, we can see quite a lot going on. When migrating, Prisma defined a new table called _CategoryToPost. This is because to create a Many-To-Many relationship, we need to define a separate table.
In the _CategoryToPost table, the A column points to a row in the Category table. Let’s see the following example:
The above means that the category with id 1 is in relationship with the post with id 3.
As an alternative to doing an implicit Many-To-Many relationship, we could create the additional table manually. For an example, visit the official documentation.
Let’s also create an easy way to attach categories to the newly created posts.
posts.service.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 |
import { Injectable } from '@nestjs/common'; import { PrismaService } from '../prisma/prisma.service'; import { CreatePostDto } from './dto/createPost.dto'; import { User } from '@prisma/client'; @Injectable() export class PostsService { constructor(private readonly prismaService: PrismaService) {} async createPost(post: CreatePostDto, user: User) { const categories = post.categoryIds?.map((category) => ({ id: category, })); return this.prismaService.post.create({ data: { title: post.title, content: post.content, author: { connect: { id: user.id, }, }, categories: { connect: categories, }, }, include: { categories: true, }, }); } // ... } |
Above, we create an array of category ids based on the input sent by the user.
Summary
In this article, we’ve covered managing relationships in PostgreSQL with Prisma. It included learning about various types of relationships: One-To-One, One-To-Many, and Many-To-Many. We’ve also learned how to deal with them when creating new records in the database and querying them. So far, Prisma proves to be a capable alternative to TypeORM.
Awesome… 🙂️
I have a question about posts fetching data with many-to-many
So, we’re trying call getPosts() (github)
But there is no method getPost() in PostService. I can’t see example of how to create a connection between models.
Anyway. I have 3 models: Places, Tags and TagsOnPlaces (many-to-many relation)
PlaceService
I use include to connect places with tags via relation in my db
And my GET response to /places looks like this:
What should I do to see values instead of id’s?
Ok, I found a solution.
If you use explicit many-to-many you should add extra include
Modeling and querying many-to-many relations (prisma.io)