- 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
One of the challenges when working with databases is keeping the integrity of the data. In this article, we learn how to deal with it using transactions.
A transaction can contain multiple different instructions. The crucial thing about a transaction is that it either runs entirely or doesn’t run at all. Let’s revisit the most common example to understand the need for transactions.
Transferring money from one bank account to another consist of two steps:
- withdrawing money from the first account,
- adding the same amount of money to the second account.
The whole operation failing means the integrity of the data is still intact. The amount of money on both of the accounts remains intact. The worst scenario happens when just half of the above steps run successfully. Imagine the following situation:
- withdrawing the money reduces the amount of money in the first account,
- adding the money to the second account fails because the account was recently closed.
The above scenario causes us to lose the integrity of our data. A specific sum of the money disappeared from the bank and is in neither of the accounts.
ACID properties
Fortunately, we can deal with the above issue using transactions. It guarantees us the following properties:
Atomicity
The operations in the transaction form a single unit. Therefore, it either entirely succeeds or fails completely.
Consistency
A transaction progresses the database from one valid state to another.
Isolation
More than one transaction could occur in our database at the same time without having an invalid state of the data. For example, another transaction should detect the money in one bank account, but not in neither nor both.
Durability
When we commit the changes from the transaction, they need to persist permanently.
Writing transactions with PostgreSQL
Whenever we run a single query, PostgreSQL wraps it in a transaction that ensures all of the ACID properties. Besides that, we can run multiple queries in a transaction. To do that, we can use the BEGIN and COMMIT statements.
With the BEGIN statement, we initiate the transaction block. PostgreSQL executes all queries after the BEGIN statement in a single transaction. When we run the COMMIT statement, PostgreSQL stores our changes in the database.
1 2 3 4 5 6 7 8 |
BEGIN; --Disconnecting posts from a given category DELETE FROM categories_posts WHERE category_id=1; --Deleting the category from the database DELETE FROM categories WHERE id=1; COMMIT; |
In the above code, we first disconnect all posts from a given category. Then, we delete the category.
If deleting the category fails for any reason, the posts are not removed from the category. When that happens, we should discard the transaction using the ROLLBACK statement. But, of course, we can also do that anytime we want to abort the current transaction.
Using transactions with node-postgres
We’ve used the node-postgres library in this series of articles to create a connection pool. This means that we have a pool of multiple clients connected to our database.
Using the same client instance for all of our queries within a transaction is crucial. To do that, we need to modify our DatabaseService class.
database.service.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 |
import { Inject, Injectable } from '@nestjs/common'; import { Pool } from 'pg'; import { CONNECTION_POOL } from './database.module-definition'; @Injectable() class DatabaseService { constructor(@Inject(CONNECTION_POOL) private readonly pool: Pool) {} async runQuery(query: string, params?: unknown[]) { return this.pool.query(query, params); } async getPoolClient() { return this.pool.connect(); } } export default DatabaseService; |
When running this.pool.query(), our query runs on any available client in the pool. This is fine if we don’t write transactions. To run a set of operations using a particular client, we need to get it using this.pool.connect() function.
Let’s use the above knowledge to delete rows from both categories and posts_categories tables.
categories.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 |
import { Injectable, NotFoundException } from '@nestjs/common'; import DatabaseService from '../database/database.service'; @Injectable() class CategoriesRepository { constructor(private readonly databaseService: DatabaseService) {} async delete(id: number) { const poolClient = await this.databaseService.getPoolClient(); try { await poolClient.query('BEGIN;'); // Disconnecting posts from a given category await poolClient.query( ` DELETE FROM categories_posts WHERE category_id=$1; `, [id], ); // Disconnecting posts from a given category const categoriesResponse = await poolClient.query( ` DELETE FROM categories WHERE id=$1; `, [id], ); if (categoriesResponse.rowCount === 0) { throw new NotFoundException(); } await poolClient.query(` COMMIT; `); } catch (error) { await poolClient.query(` ROLLBACK; `); throw error; } finally { poolClient.release(); } } // ... } export default CategoriesRepository; |
A significant thing above is that we call the release() method when we don’t need a particular client anymore. Thanks to that, it returns to the pool and becomes available again.
Passing the client instance between methods
As our logic gets more complex, our transactions might occupy more than one method. To deal with this, we can pass the client instance as an argument.
In the previous article, we learned how to work with many-to-many relationships. When creating posts, we sent the following data through the API:
1 2 3 4 5 |
{ "title": "My first post", "content": "Hello world!", "categoryIds": [1, 2, 3] } |
Let’s write a method that allows us to modify the above post. For example, imagine sending the following PUT request:
1 2 3 4 5 |
{ "title": "My modified post", "content": "Hello world!", "categoryIds": [2, 4] } |
After analyzing the above payload, we can notice the following differences:
- we need to remove the post from the 1 and 3 categories,
- we have to add the post to the category with id 4.
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 47 48 49 50 51 52 53 |
import { Injectable, NotFoundException } 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 update(id: number, postData: PostDto) { const client = await this.databaseService.getPoolClient(); try { await client.query('BEGIN;'); const databaseResponse = await client.query( ` UPDATE posts SET title = $2, post_content = $3 WHERE id = $1 RETURNING * `, [id, postData.title, postData.content], ); const entity = databaseResponse.rows[0]; if (!entity) { throw new NotFoundException(); } const newCategoryIds = postData.categoryIds || []; const categoryIds = await this.updateCategories( client, id, newCategoryIds, ); return new PostWithCategoryIdsModel({ ...entity, category_ids: categoryIds, }); } catch (error) { await client.query('ROLLBACK;'); throw error; } finally { client.release(); } } // ... } export default PostsRepository; |
In the above function, we use the this.updateCategories method that modifies the relationship between the post and the categories.
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 47 48 49 50 51 52 53 54 55 56 57 |
import { Injectable, } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import { PoolClient } from 'pg'; import getDifferenceBetweenArrays from '../utils/getDifferenceBetweenArrays'; @Injectable() class PostsRepository { constructor(private readonly databaseService: DatabaseService) {} private async getCategoryIdsRelatedToPost( client: PoolClient, postId: number, ): Promise<number[]> { const categoryIdsResponse = await client.query( ` SELECT ARRAY( SELECT category_id FROM categories_posts WHERE post_id = $1 ) AS category_ids `, [postId], ); return categoryIdsResponse.rows[0].category_ids; } private async updateCategories( client: PoolClient, postId: number, newCategoryIds: number[], ) { const existingCategoryIds = await this.getCategoryIdsRelatedToPost( client, postId, ); const categoryIdsToRemove = getDifferenceBetweenArrays( existingCategoryIds, newCategoryIds, ); const categoryIdsToAdd = getDifferenceBetweenArrays( newCategoryIds, existingCategoryIds, ); await this.removeCategoriesFromPost(client, postId, categoryIdsToRemove); await this.addCategoriesToPost(client, postId, categoryIdsToAdd); return this.getCategoryIdsRelatedToPost(client, postId); } // ... } export default PostsRepository; |
A few important things are happening above:
- we determine what categories we need to link and unlink from a post using the getDifferenceBetweenArrays method,
- we remove and add categories associated with the post,
- we return the list of categories related to the post after the above operations.
First, let’s take a look at the getDifferenceBetweenArrays method.
getDifferenceBetweenArrays.ts
1 2 3 4 5 6 7 8 9 10 |
function getDifferenceBetweenArrays<ListType extends unknown>( firstArray: ListType[], secondArray: unknown[], ): ListType[] { return firstArray.filter((arrayElement) => { return !secondArray.includes(arrayElement); }); } export default getDifferenceBetweenArrays; |
Above, we return the elements present in the first array but absent from the second one.
The last part we need to analyze is how we remove and add categories to the post. Removing categories is very straightforward and involves a simple SQL 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 |
import { BadRequestException, Injectable, } from '@nestjs/common'; import { PoolClient } from 'pg'; import PostgresErrorCode from '../database/postgresErrorCode.enum'; import isRecord from '../utils/isRecord'; @Injectable() class PostsRepository { private async removeCategoriesFromPost( client: PoolClient, postId: number, categoryIdsToRemove: number[], ) { if (!categoryIdsToRemove.length) { return; } return client.query( ` DELETE FROM categories_posts WHERE post_id = $1 AND category_id = ANY($2::int[]) `, [postId, categoryIdsToRemove], ); } // ... } export default PostsRepository; |
On the other hand, adding categories to a post has a catch. If the user tries to use the id of a category that does not exist, PostgreSQL throws the foreign key violation error. In this example, we catch this error and assume that the user provided the wrong id.
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 |
import { BadRequestException, Injectable, } from '@nestjs/common'; import { PoolClient } from 'pg'; import PostgresErrorCode from '../database/postgresErrorCode.enum'; import isRecord from '../utils/isRecord'; @Injectable() class PostsRepository { private async addCategoriesToPost( client: PoolClient, postId: number, categoryIdsToAdd: number[], ) { if (!categoryIdsToAdd.length) { return; } try { await client.query( ` INSERT INTO categories_posts ( post_id, category_id ) SELECT $1 AS post_id, unnest($2::int[]) AS category_id `, [postId, categoryIdsToAdd], ); } catch (error) { if ( isRecord(error) && error.code === PostgresErrorCode.ForeignKeyViolation ) { throw new BadRequestException('Category not found'); } throw error; } } // ... } export default PostsRepository; |
If you want to see the whole PostsRepository, check it out on GitHub.
To catch the above issue elegantly, we’ve added the appropriate error code to our PostgresErrorCode enum.
postgresErrorCode.enum.ts
1 2 3 4 5 6 |
enum PostgresErrorCode { UniqueViolation = '23505', ForeignKeyViolation = '23503', } export default PostgresErrorCode; |
Thanks to all of the above, we can do the following actions in a single transaction:
- update the title and content of the post
- check the categories currently tied to the post,
- remove and add categories to the post if necessary,
- return the modified post together with the updated list of categories.
Summary
In this article, we’ve gone through the idea of transactions and learned why we might need them. We’ve also learned that we need to use a particular client from the connection pool for all queries in a particular transaction. To practice that, we first implemented a simple example. Then, we went through a more complicated transaction that involved passing the client between multiple methods. The above knowledge is crucial when caring about the integrity of our database.