- 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
- 122. API with NestJS #122. Many-to-many relationships with Kysely and PostgreSQL
- 123. API with NestJS #123. SQL transactions with Kysely
- 124. API with NestJS #124. Handling SQL constraints with Kysely
- 125. API with NestJS #125. Offset and keyset pagination with Kysely
- 126. API with NestJS #126. Improving the database performance with indexes and Kysely
- 127. API with NestJS #127. Arrays with PostgreSQL and Kysely
- 128. API with NestJS #128. Managing JSON data with PostgreSQL and Kysely
- 129. API with NestJS #129. Implementing soft deletes with SQL and Kysely
- 130. API with NestJS #130. Avoiding storing sensitive information in API logs
- 131. API with NestJS #131. Unit tests with PostgreSQL and Kysely
- 132. API with NestJS #132. Handling date and time in PostgreSQL with Kysely
- 133. API with NestJS #133. Introducing database normalization with PostgreSQL and Prisma
- 134. API with NestJS #134. Aggregating statistics with PostgreSQL and Prisma
- 135. API with NestJS #135. Referential actions and foreign keys in PostgreSQL with Prisma
- 136. API with NestJS #136. Raw SQL queries with Prisma and PostgreSQL range types
- 137. API with NestJS #137. Recursive relationships with Prisma and PostgreSQL
- 138. API with NestJS #138. Filtering records with Prisma
- 139. API with NestJS #139. Using UUID as primary keys with Prisma and PostgreSQL
- 140. API with NestJS #140. Using multiple PostgreSQL schemas with Prisma
- 141. API with NestJS #141. Getting distinct records with Prisma and PostgreSQL
- 142. API with NestJS #142. A video chat with WebRTC and React
- 143. API with NestJS #143. Optimizing queries with views using PostgreSQL and Kysely
- 144. API with NestJS #144. Creating CLI applications with the Nest Commander
- 145. API with NestJS #145. Securing applications with Helmet
- 146. API with NestJS #146. Polymorphic associations with PostgreSQL and Prisma
- 147. API with NestJS #147. The data types to store money with PostgreSQL and Prisma
- 148. API with NestJS #148. Understanding the injection scopes
- 149. API with NestJS #149. Introduction to the Drizzle ORM with PostgreSQL
- 150. API with NestJS #150. One-to-one relationships with the Drizzle ORM
- 151. API with NestJS #151. Implementing many-to-one relationships with Drizzle ORM
- 152. API with NestJS #152. SQL constraints with the Drizzle ORM
- 153. API with NestJS #153. SQL transactions with the Drizzle ORM
- 154. API with NestJS #154. Many-to-many relationships with Drizzle ORM and PostgreSQL
- 155. API with NestJS #155. Offset and keyset pagination with the Drizzle ORM
- 156. API with NestJS #156. Arrays with PostgreSQL and the Drizzle ORM
- 157. API with NestJS #157. Handling JSON data with PostgreSQL and the Drizzle ORM
- 158. API with NestJS #158. Soft deletes with the Drizzle ORM
- 159. API with NestJS #159. Date and time with PostgreSQL and the Drizzle ORM
- 160. API with NestJS #160. Using views with the Drizzle ORM and PostgreSQL
- 161. API with NestJS #161. Generated columns with the Drizzle ORM and PostgreSQL
- 162. API with NestJS #162. Identity columns with the Drizzle ORM and PostgreSQL
- 163. API with NestJS #163. Full-text search with the Drizzle ORM and PostgreSQL
- 164. API with NestJS #164. Improving the performance with indexes using Drizzle ORM
- 165. API with NestJS #165. Time intervals with the Drizzle ORM and PostgreSQL
- 166. API with NestJS #166. Logging with the Drizzle ORM
- 167. API with NestJS #167. Unit tests with the Drizzle ORM
- 168. API with NestJS #168. Integration tests with the Drizzle ORM
The integrity of our data should be one of the primary concerns of web developers. Thankfully, SQL databases equip us with tools that we can use to ensure the consistency and accuracy of our data.
You can see the complete code from this article in this repository.
One of the critical situations to consider is when two SQL queries depend on each other. A good example is transferring money from one bank account to another. Let’s imagine we have two bank accounts, each with $1000. Transferring $500 from one account to another consists of two steps:
- decreasing the amount of money in the first account by $500,
- increasing the second account’s balance by $500.
If the first operation fails, the data integrity remains intact, and the total sum of money in both accounts is $2000. The worst situation would be if half of the above steps run successfully:
- we withdraw the $500 from the first account,
- we fail to add the money to the second account because it was closed recently.
In the above scenario, we lose the integrity of our data. The money in the two accounts now adds up to only $1500, and the $500 we lost is in neither of the accounts.
Transactions and the ACID properties
Thankfully, we can solve the above issue with transactions. A transaction can consist of more than one SQL query and guarantees the following:
Atomicity
A particular transaction either succeeds completely or entirely fails.
Consistency
The transaction moves the database from one valid state to another
Isolation
Multiple transactions can run concurrently without the risk of losing the consistency of our data. In our case, the second transaction should see the transferred money in one of the accounts but not both.
Durability
The changes made to the database by the transaction persist permanently as soon as we commit them.
Writing transactions with PostgreSQL
To start the transaction block, we need to start with the BEGIN statement. Below, we should write the queries we want to contain in the transaction and finish with the COMMIT keyword to store our changes.
1 2 3 4 5 6 7 8 9 10 11 |
BEGIN; UPDATE bank_accounts SET balance = 500 WHERE id = 1; UPDATE bank_accounts SET balance = 1500 WHERE id = 2; COMMIT; |
Thanks to wrapping our queries in a transaction, we can revert the whole operation if transferring the money to the second account fails for any reason. To do that, we need the ROLLBACK keyword.
Transactions with Kysely
To wrap multiple queries in a transaction when using Kysely, we need the transaction() function. Let’s create a transaction that deletes rows both from the categories_articles and 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 |
import { Database } from '../database/database'; import { Injectable, NotFoundException } from '@nestjs/common'; import { Category } from './category.model'; @Injectable() export class CategoriesRepository { constructor(private readonly database: Database) {} async delete(id: number) { const databaseResponse = await this.database .transaction() .execute(async (transaction) => { await transaction .deleteFrom('categories_articles') .where('category_id', '=', id) .execute(); const deleteCategoryResponse = await transaction .deleteFrom('categories') .where('id', '=', id) .returningAll() .executeTakeFirst(); if (!deleteCategoryResponse) { throw new NotFoundException(); } return deleteCategoryResponse; }); return new Category(databaseResponse); } // ... } |
If any error is thrown inside the callback function we pass to execute, Kysely rolls back the transaction.
When working with PostgreSQL, we manage a pool of multiple clients connected to our database. It is essential to use the transaction instead of this.database when making the SQL queries that are part of the transaction. Thanks to that, we ensure that we use the same client instance for all our queries within the transaction.
Passing the transaction across different methods
As our application gets more complex, the transactions might span over more than one method in our repository. To deal with this, we can pass the transaction instance as an argument.
In the previous parts of this series, we implemented a many-to-many relationship. When creating articles, we send the following data through the API:
1 2 3 4 5 |
{ "title": "My first article", "content": "Hello world!", "categoryIds": [1, 2, 3] } |
Let’s implement a way to change the categories assigned to a particular article using a PUT request:
1 2 3 4 5 |
{ "title": "My modified article", "content": "Hello world!", "categoryIds": [2, 4] } |
After a closer inspection, we can notice the following differences between the initial data of the article and the modified version:
- the categories with IDs 1 and 3 are removed,
- the category with ID 4 is added.
To implement the above functionality, we need to adjust our update method.
articles.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 { Database } from '../database/database'; import { Injectable, NotFoundException } from '@nestjs/common'; import { ArticleDto } from './dto/article.dto'; import { ArticleWithCategoryIds } from './articleWithCategoryIds.model'; @Injectable() export class ArticlesRepository { constructor(private readonly database: Database) {} async update(id: number, data: ArticleDto) { const databaseResponse = await this.database .transaction() .execute(async (transaction) => { const updateArticleResponse = await transaction .updateTable('articles') .set({ title: data.title, article_content: data.content, }) .where('id', '=', id) .returningAll() .executeTakeFirst(); if (!updateArticleResponse) { throw new NotFoundException(); } const newCategoryIds = data.categoryIds || []; const categoryIds = await this.updateCategoryIds( transaction, id, newCategoryIds, ); return { ...updateArticleResponse, category_ids: categoryIds, }; }); return new ArticleWithCategoryIds(databaseResponse); } // ... } |
Above, we use the updateCategoryIds method that modifies the relationship between the article and categories.
articles.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 |
import { Database, Tables } from '../database/database'; import { Injectable } from '@nestjs/common'; import { Transaction } from 'kysely'; import { getDifferenceBetweenArrays } from '../utils/getDifferenceBetweenArrays'; @Injectable() export class ArticlesRepository { constructor(private readonly database: Database) {} private async getCategoryIdsRelatedToArticle( transaction: Transaction<Tables>, articleId: number, ): Promise<number[]> { const categoryIdsResponse = await transaction .selectFrom('categories_articles') .where('article_id', '=', articleId) .selectAll() .execute(); return categoryIdsResponse.map((response) => response.category_id); } private async updateCategoryIds( transaction: Transaction<Tables>, articleId: number, newCategoryIds: number[], ) { const existingCategoryIds = await this.getCategoryIdsRelatedToArticle( transaction, articleId, ); const categoryIdsToRemove = getDifferenceBetweenArrays( existingCategoryIds, newCategoryIds, ); const categoryIdsToAdd = getDifferenceBetweenArrays( newCategoryIds, existingCategoryIds, ); await this.removeCategoriesFromArticle( transaction, articleId, categoryIdsToRemove, ); await this.addCategoriesToArticle(transaction, articleId, categoryIdsToAdd); return this.getCategoryIdsRelatedToArticle(transaction, articleId); } // ... } |
In the updateCategoryIds method, we perform a series of actions:
- we check which categories we need to attach and detach from the article using the getDifferenceBetweenArrays function,
- we remove and add categories related to the article,
- we return the list of categories associated with the article after the above operations.
The getDifferenceBetweenArrays function returns the elements present in the first array but absent from the second one.
getDifferenceBetweenArrays.ts
1 2 3 4 5 6 7 8 |
export function getDifferenceBetweenArrays<ListType>( firstArray: ListType[], secondArray: unknown[], ): ListType[] { return firstArray.filter((arrayElement) => { return !secondArray.includes(arrayElement); }); } |
Detaching categories from articles is straightforward and involves a single SQL query.
articles.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 |
import { Database, Tables } from '../database/database'; import { Injectable } from '@nestjs/common'; import { sql, Transaction } from 'kysely'; @Injectable() export class ArticlesRepository { constructor(private readonly database: Database) {} private async removeCategoriesFromArticle( transaction: Transaction<Tables>, articleId: number, categoryIdsToRemove: number[], ) { if (!categoryIdsToRemove.length) { return; } return transaction .deleteFrom('categories_articles') .where((expressionBuilder) => { return expressionBuilder('article_id', '=', articleId).and( 'category_id', '=', sql`ANY(${categoryIdsToRemove}::int[])`, ); }) .execute(); } // ... } |
There is a catch when attaching the categories to the article. If the user provides the ID of the category that does not exist, PostgreSQL throws the foreign key violation error, and we need to handle it.
articles.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 |
import { Database, Tables } from '../database/database'; import { BadRequestException, Injectable } from '@nestjs/common'; import { Transaction } from 'kysely'; import { isRecord } from '../utils/isRecord'; import { PostgresErrorCode } from '../database/postgresErrorCode.enum'; @Injectable() export class ArticlesRepository { constructor(private readonly database: Database) {} private async addCategoriesToArticle( transaction: Transaction<Tables>, articleId: number, categoryIdsToAdd: number[], ) { if (!categoryIdsToAdd.length) { return; } try { await transaction .insertInto('categories_articles') .values( categoryIdsToAdd.map((categoryId) => { return { article_id: articleId, category_id: categoryId, }; }), ) .execute(); } catch (error) { if ( isRecord(error) && error.code === PostgresErrorCode.ForeignKeyViolation ) { throw new BadRequestException('Category not found'); } throw error; } } // ... } |
We must add the appropriate error code to our PostgresErrorCode enum to react to the foreign key violation.
articles.repository.ts
1 2 3 4 |
export enum PostgresErrorCode { UniqueViolation = '23505', ForeignKeyViolation = '23503', } |
Thanks to all of the above, we can update an article’s title, content, and categories in a single transaction.
Summary
In this article, we’ve gone through the concept of transactions and why we might need them. We also learned how to use them with Kysely by implementing both a simple and a more complex example that involves multiple methods.
Thanks to the above knowledge, we now know how to ensure the integrity of our database. We also learned how to handle a foreign key constraint violation when implementing the above examples. Managing constraints and error handling is an important topic for SQL and Kysely, and it deserves a separate article. Stay tuned!