- 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
Having significant control over the data we store in our database is crucial. One of the ways to do that is to choose suitable column types. We can also use constraints to go further and reject the data that does not match our guidelines. By doing that, we can have an additional layer of security that ensures the integrity of our data.
Not null constraint
With the not-null constraint, we can enforce a column to have a value other than null. For example, let’s look at the table we’ve implemented in one of the previous parts of this series.
1 2 3 4 5 6 7 8 9 |
export async function up(knex: Knex): Promise<void> { return knex.raw(` CREATE TABLE posts ( id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, title text NOT NULL, post_content text NOT NULL ) `); } |
Above, we’re using an identity column. If you want to know more, check out Serial type versus identity columns in PostgreSQL and TypeORM
Error handling for non-null constraints
When using the NOT NULL constraint, PostgreSQL throws an error when trying to save a null value for the constrained column. When using try...catch with TypeScript, the type of the error is unknown.
If you want to know more about the unknown type, check out Understanding any and unknown in TypeScript. Difference between never and void
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 |
import { Injectable } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import PostModel from './post.model'; import PostDto from './post.dto'; @Injectable() class PostsRepository { constructor(private readonly databaseService: DatabaseService) {} async create(postData: PostDto, authorId: number) { try { const databaseResponse = await this.databaseService.runQuery( ` INSERT INTO posts ( title, post_content, author_id ) VALUES ( $1, $2, $3 ) RETURNING * `, [postData.title, postData.content, authorId], ); return new PostModel(databaseResponse.rows[0]); } catch (error) { // the error is unknown } } // ... } export default PostsRepository; |
Because of the above, we need a way to narrow the type down. The best way to do that is to implement a type guard.
If you want to read more about type guards, check out Structural type system and polymorphism in TypeScript. Type guards with predicates
databaseError.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 |
import PostgresErrorCode from '../database/postgresErrorCode.enum'; import isRecord from '../utils/isRecord'; interface DatabaseError { code: PostgresErrorCode; detail: string; table: string; column?: string; } export function isDatabaseError(value: unknown): value is DatabaseError { if (!isRecord(value)) { return false; } const { code, detail, table } = value; return Boolean(code && detail && table); } export default DatabaseError; |
Above we also use the isRecord type guard function that helps us determine if the value is a valid object and not an array. If you want to check it out, see the file in the repository.
PostgreSQL uses a set of error codes to let us know what constraint was violated. Let’s put the not-null violation error code in an enum.
postgresErrorCode.enum.ts
1 2 3 4 5 |
enum PostgresErrorCode { NotNullViolation = '23502', } export default PostgresErrorCode; |
Thanks to all of the above, we can use the isDatabaseError function to determine if a particular value matches the DatabaseError database.
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 |
import { BadRequestException, Injectable, } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import PostModel from './post.model'; import PostDto from './post.dto'; import { isDatabaseError } from '../types/databaseError'; import PostgresErrorCode from '../database/postgresErrorCode.enum'; @Injectable() class PostsRepository { constructor(private readonly databaseService: DatabaseService) {} async create(postData: PostDto, authorId: number) { try { const databaseResponse = await this.databaseService.runQuery( ` INSERT INTO posts ( title, post_content, author_id ) VALUES ( $1, $2, $3 ) RETURNING * `, [postData.title, postData.content, authorId], ); return new PostModel(databaseResponse.rows[0]); } catch (error) { if ( !isDatabaseError(error) || !['title', 'post_content'].includes(error.column) ) { throw error; } if (error.code === PostgresErrorCode.NotNullViolation) { throw new BadRequestException( `A null value can't be set for the ${error.column} column`, ); } throw error; } } // ... } export default PostsRepository; |
Unique constraint
The unique constraint ensures that all values in a particular column are unique across the table. A good example is the users table we created in one of the previous parts of this series.
1 2 3 4 5 6 7 8 9 10 |
export async function up(knex: Knex): Promise<void> { return knex.raw(` CREATE TABLE users ( id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, email text NOT NULL UNIQUE, name text NOT NULL, password text NOT NULL ) `); } |
Thanks to using the UNIQUE constraint above, PostgreSQL throws an error if we try to create two users with the same email.
Error handling for unique constraints
To handle the unique constraint, we should add it to our PostgresErrorCode enum.
postgresErrorCode.enum.ts
1 2 3 4 5 6 |
enum PostgresErrorCode { UniqueViolation = '23505', NotNullViolation = '23502', } export default PostgresErrorCode; |
We can now use it in our repository.
users.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 |
import { Injectable } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import UserModel from './user.model'; import { CreateUserDto } from './dto/createUser.dto'; import PostgresErrorCode from '../database/postgresErrorCode.enum'; import UserAlreadyExistsException from './exceptions/userAlreadyExists.exception'; import { isDatabaseError } from '../types/databaseError'; @Injectable() class UsersRepository { constructor(private readonly databaseService: DatabaseService) {} async create(userData: CreateUserDto) { if (userData.address) { return this.createUserWithAddress(userData); } try { const databaseResponse = await this.databaseService.runQuery( ` INSERT INTO users ( email, name, password ) VALUES ( $1, $2, $3 ) RETURNING * `, [userData.email, userData.name, userData.password], ); return new UserModel(databaseResponse.rows[0]); } catch (error) { if ( isDatabaseError(error) && error.code === PostgresErrorCode.UniqueViolation ) { throw new UserAlreadyExistsException(userData.email); } throw error; } } // ... } export default UsersRepository; |
Above, we throw a custom error using the UserAlreadyExistsException extending the BadRequestException.
userAlreadyExists.exception.ts
1 2 3 4 5 6 7 8 9 |
import { BadRequestException } from '@nestjs/common'; class UserAlreadyExistsException extends BadRequestException { constructor(email: string) { super(`User with ${email} email already exists`); } } export default UserAlreadyExistsException; |
Using the unique constraint with a group of columns
Using different syntax allows us to expect a group of columns to have a unique value.
1 2 3 4 5 6 |
CREATE TABLE users ( id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, first_name text, last_name text, UNIQUE (first_name, last_name) ) |
Above, we expect users to have a unique combination of their first and last names. However, they can still share the same first name if their last name differs.
Primary key constraint
The primary key is a very common constraint. When using it, we indicate that a particular column serves as a unique identifier for the rows in the table.
1 2 3 4 5 6 7 8 9 |
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 ); // ... `); } |
When we use the PRIMARY KEY constraint, we indicate that all values in a particular column should be unique and not equal to null. To ensure that, PostgreSQL creates a unique index to keep track of all of the values.
If you want to know more about indexes, read API with NestJS #82. Introduction to indexes with raw SQL queries
Error handling for primary keys
In the case of the primary keys, we need to worry about the unique violation and not-null violation. Fortunately, we already have them as part of our PostgresErrorCode enum.
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 |
import { BadRequestException, Injectable } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import CategoryModel from './category.model'; import CategoryDto from './category.dto'; import { isDatabaseError } from '../types/databaseError'; import PostgresErrorCode from '../database/postgresErrorCode.enum'; @Injectable() class CategoriesRepository { constructor(private readonly databaseService: DatabaseService) {} async create(categoryData: CategoryDto) { try { const databaseResponse = await this.databaseService.runQuery( ` INSERT INTO categories ( name ) VALUES ( $1 ) RETURNING * `, [categoryData.name], ); return new CategoryModel(databaseResponse.rows[0]); } catch (error) { if (!isDatabaseError(error) || error.column !== 'id') { throw error; } if ( error.code === PostgresErrorCode.UniqueViolation || error.code === PostgresErrorCode.NotNullViolation ) { throw new BadRequestException( 'The value for the id column violates the primary key constraint', ); } throw error; } } // ... } export default CategoriesRepository; |
In a lot of the cases there isn’t a high chance of violating the primary key constraint because we usually let PostgreSQL to generate it for us.
Using a group of columns as a primary key
We can’t have a table that has more than one primary key. However, we can have a primary key that consists of multiple columns.
1 2 3 4 5 |
CREATE TABLE users ( first_name text, last_name text, PRIMARY KEY (first_name, last_name) ) |
Due to how the above constraint is designed, we can’t have two users with the same combination of first and last names.
Foreign key constraint
We use the foreign key constraint when defining relations. To do that, we need to use the REFERENCES keyword.
1 2 3 4 5 6 7 8 9 10 11 12 13 |
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) ); `); } |
Above, we define a many-to-many relation. If you want to know more, read API with NestJS #75. Many-to-many relationships using raw SQL queries
Because of the foreign keys in the categories_posts table, each post needs to refer to a valid category.
Error handling for foreign key constraints
A good example of a foreign key constraint violation is referring to an entity that does not exist. To be able to handle it, let’s add the appropriate code to our enum.
postgresErrorCode.enum.ts
1 2 3 4 5 6 7 |
enum PostgresErrorCode { UniqueViolation = '23505', NotNullViolation = '23502', ForeignKeyViolation = '23503', } export default PostgresErrorCode; |
Thanks to the above, we can now handle the constraint violation appropriately.
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 |
import { BadRequestException, Injectable } from '@nestjs/common'; import { PoolClient } from 'pg'; import PostgresErrorCode from '../database/postgresErrorCode.enum'; import { isDatabaseError } from '../types/databaseError'; @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 ( isDatabaseError(error) && error.code === PostgresErrorCode.ForeignKeyViolation ) { throw new BadRequestException('Category not found'); } throw error; } } // ... } export default PostsRepository; |
Check constraint
The check constraint is more generic than the previous examples. We can use it to specify the requirements for a value in a particular column. Let’s inspect the migration we wrote in one of the previous parts of this series.
1 2 3 4 5 6 7 8 9 10 11 |
export async function up(knex: Knex): Promise<void> { return knex.raw(` CREATE TABLE comments ( id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, content text NOT NULL, post_id int REFERENCES posts(id) NOT NULL, author_id int REFERENCES posts(id) NOT NULL, deletion_date timestamptz ); `); } |
We can modify the above table and add a constraint to an existing column by creating a new migration.
1 |
npx knex migrate:make add_comment_length_constraint |
20221201022319_add_comment_length_constraint.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 |
import { Knex } from 'knex'; export async function up(knex: Knex): Promise<void> { return knex.raw(` ALTER TABLE comments ADD CONSTRAINT comment_length_constraint CHECK ( length(content) > 0 ) `); } export async function down(knex: Knex): Promise<void> { return knex.raw(` ALTER TABLE comments DROP CONSTRAINT comment_length_constraint; `); } |
With the above constraint, we specify that the content column can’t hold an empty string.
Handling the check constraint violation
To handle the violation of the above constraint, we need to add the appropriate code to our enum.
postgresErrorCode.enum.ts
1 2 3 4 5 6 7 8 |
enum PostgresErrorCode { UniqueViolation = '23505', NotNullViolation = '23502', ForeignKeyViolation = '23503', CheckViolation = '23514' } export default PostgresErrorCode; |
We can now use the code to check if the constraint was violated.
comments.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 |
import { BadRequestException, Injectable } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import CommentModel from './comment.model'; import CommentDto from './comment.dto'; import { isDatabaseError } from '../types/databaseError'; import PostgresErrorCode from '../database/postgresErrorCode.enum'; @Injectable() class CommentsRepository { constructor(private readonly databaseService: DatabaseService) {} async create(commentData: CommentDto, authorId: number) { try { const databaseResponse = await this.databaseService.runQuery( ` INSERT INTO comments ( content, post_id, author_id ) VALUES ( $1, $2, $3 ) RETURNING * `, [commentData.content, commentData.postId, authorId], ); return new CommentModel(databaseResponse.rows[0]); } catch (error) { if ( isDatabaseError(error) && error.code === PostgresErrorCode.CheckViolation ) { throw new BadRequestException( 'The length of the content needs to be greater than 0', ); } throw error; } } // ... } export default CommentsRepository; |
Summary
In this article, we’ve gone through constraints in PostgreSQL. We’ve learned how to apply them to our tables and how they can help manage our database. When doing that, we’ve also implemented error handling so that we can react accordingly when a particular constraint is violated.