- 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
- 169. API with NestJS #169. Unique IDs with UUIDs using Drizzle ORM and PostgreSQL
- 170. API with NestJS #170. Polymorphic associations with PostgreSQL and Drizzle ORM
- 171. API with NestJS #171. Recursive relationships with Drizzle ORM and PostgreSQL
- 172. API with NestJS #172. Database normalization with Drizzle ORM and PostgreSQL
- 173. API with NestJS #173. Storing money with Drizzle ORM and PostgreSQL
Object-Relational Mapping (ORM) libraries can often help us write our code faster. The ORM allows us not to write raw SQL. Instead, we can manipulate the data using an object-oriented paradigm.
Using ORM can ease the learning curve of working with databases because we don’t need to go deep into learning SQL. Instead, we write the data model in the programming language we use to develop the application. On top of that, ORM should have security mechanisms that deal with issues such as SQL injection.
Unfortunately, ORMs have disadvantages too. For example, depending on ORM to generate the database structure based on our models can lead to not grasping the intricacies of the underlying architecture. Also, ORM automatically generates SQL queries for fetching, inserting or modifying data. Therefore, they are not always optimal and can lead to performance issues. Also, ORMs can have problems and bugs too.
It is fine to use ORM if we don’t need a lot of control over our SQL queries. If we develop a big project, though, we might prefer to deal with database management through raw SQL queries. In this article, we figure out how to structure our NestJS project to use raw SQL queries with a PostgreSQL database.
You can find the code from this article in this repository.
Connecting to the database
As usual in this series, we use Docker to create an instance of the PostgreSQL database for us.
docker-compose.yml
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 |
version: "3" services: postgres: container_name: postgres-nestjs image: postgres:latest ports: - "5432:5432" volumes: - /data/postgres:/data/postgres env_file: - docker.env networks: - postgres pgadmin: links: - postgres:postgres container_name: pgadmin-nestjs image: dpage/pgadmin4 ports: - "8080:80" volumes: - /data/pgadmin:/root/.pgadmin env_file: - docker.env networks: - postgres networks: postgres: driver: bridge |
To provide Docker with the necessary environment variables, we need to create the docker.env file.
docker.env
1 2 3 4 5 |
POSTGRES_USER=admin POSTGRES_PASSWORD=admin POSTGRES_DB=nestjs PGADMIN_DEFAULT_EMAIL=admin@admin.com PGADMIN_DEFAULT_PASSWORD=admin |
We must also provide a similar set of variables for our NestJS application.
.env
1 2 3 4 5 |
POSTGRES_HOST=localhost POSTGRES_PORT=5432 POSTGRES_USER=admin POSTGRES_PASSWORD=admin POSTGRES_DB=nestjs |
It is also a good idea to validate if the environment variables are provided when the application starts.
app.module.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 |
import { Module } from '@nestjs/common'; import { ConfigModule } from '@nestjs/config'; import * as Joi from 'joi'; @Module({ imports: [ ConfigModule.forRoot({ validationSchema: Joi.object({ POSTGRES_HOST: Joi.string().required(), POSTGRES_PORT: Joi.number().required(), POSTGRES_USER: Joi.string().required(), POSTGRES_PASSWORD: Joi.string().required(), POSTGRES_DB: Joi.string().required(), }), }), ], }) export class AppModule {} |
Establishing the connection
In this article, we use the node-postgres library to establish a connection to our PostgreSQL database and run queries.
1 |
npm install pg @types/pg |
To manage a database connection, we can create a dynamic module. Thanks to that, we could easily copy and paste it to a different project or keep it in a separate library.
If you are not familiar with dynamic modules, check out API with NestJS #70. Defining dynamic modules
database.module-definition.ts
1 2 3 4 5 6 7 8 9 10 11 |
import { ConfigurableModuleBuilder } from '@nestjs/common'; import DatabaseOptions from './databaseOptions'; export const CONNECTION_POOL = 'CONNECTION_POOL'; export const { ConfigurableModuleClass: ConfigurableDatabaseModule, MODULE_OPTIONS_TOKEN: DATABASE_OPTIONS, } = new ConfigurableModuleBuilder<DatabaseOptions>() .setClassMethodName('forRoot') .build(); |
We use forRoot above because we want our DatabaseModule to be global.
When the DatabaseModule is imported, we expect a particular set of options to be provided.
databaseOptions.ts
1 2 3 4 5 6 7 8 9 |
interface DatabaseOptions { host: string; port: number; user: string; password: string; database: string; } export default DatabaseOptions; |
Using a connection pool
The node-postgres library recommends we use a connection pool. Since we are creating a dynamic module, we can define our pool as a provider.
database.module.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 { Global, Module } from '@nestjs/common'; import { ConfigurableDatabaseModule, CONNECTION_POOL, DATABASE_OPTIONS, } from './database.module-definition'; import DatabaseOptions from './databaseOptions'; import { Pool } from 'pg'; import DatabaseService from './database.service'; @Global() @Module({ exports: [DatabaseService], providers: [ DatabaseService, { provide: CONNECTION_POOL, inject: [DATABASE_OPTIONS], useFactory: (databaseOptions: DatabaseOptions) => { return new Pool({ host: databaseOptions.host, port: databaseOptions.port, user: databaseOptions.user, password: databaseOptions.password, database: databaseOptions.database, }); }, }, ], }) export default class DatabaseModule extends ConfigurableDatabaseModule {} |
There is an advantage to defining the connection pool as a provider. If we want to specify some additional asynchronous configuration, this is a very good place to do so. You can find a proper example in a repository created by Jay McDoniel from the NestJS team.
Thanks to the fact that above we define a provider using the CONNECTION_POOL string, we now can use it in our service.
database.service.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 |
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); } } export default DatabaseService; |
Managing migrations using Knex
We could manage migrations manually, but using an existing tool might save us time and trouble. Therefore, in this article, we use Knex.
1 |
npm install knex |
The first step in using Knex is to create the configuration file.
knexfile.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 |
import type { Knex } from 'knex'; import { ConfigService } from '@nestjs/config'; import { config } from 'dotenv'; config(); const configService = new ConfigService(); const knexConfig: Knex.Config = { client: 'postgresql', connection: { host: configService.get('POSTGRES_HOST'), port: configService.get('POSTGRES_PORT'), user: configService.get('POSTGRES_USER'), password: configService.get('POSTGRES_PASSWORD'), database: configService.get('POSTGRES_DB'), }, }; module.exports = knexConfig; |
Above we use dotenv to make sure that our .env is loaded before using the ConfigService.
We can now create our first migration using the migration CLI.
1 |
npx knex migrate:make add_posts_table |
Running the above command creates a file where we can define our migration.
20220825173451_add_posts_table.ts
1 2 3 4 5 |
import { Knex } from 'knex'; export async function up(knex: Knex): Promise<void> {} export async function down(knex: Knex): Promise<void> {} |
We need to fill the up and down methods with the SQL queries Knex will run when running migrations and rolling them back.
20220825173451_add_posts_table.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 |
import { Knex } from 'knex'; 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 ) `); } export async function down(knex: Knex): Promise<void> { return knex.raw(` DROP TABLE posts `); } |
If you want to know more about identity columns, check out Serial type versus identity columns in PostgreSQL and TypeORM
We must execute one last command if we want Knex to run our migration.
1 |
npx knex migrate:latest |
Running migrations creates the knex_migrations table that contains information about which migrations Knex has already executed.
Knex also creates the knex_migrations_lock table to prevent multiple procsses from running the same migrations in the same time.
The official documentation is a good resource if you want to know more about managing migrations with Knex.
The repository pattern and working with models
It might be a good idea to keep the logic of accessing data in a single place for a particular table. A very popular way of doing that is using the repository pattern.
posts.repository.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 |
import { Injectable } from '@nestjs/common'; import DatabaseService from '../database/database.service'; @Injectable() class PostsRepository { constructor(private readonly databaseService: DatabaseService) {} async getAll() { const databaseResponse = await this.databaseService.runQuery(` SELECT * FROM posts `); return databaseResponse.rows; } } export default PostsRepository; |
When running the getAll method, we get the data in the following format:
1 2 3 4 5 6 7 |
[ { id: 1, title: 'Hello world', post_content: 'Lorem ipsum' } ] |
We often might want to transform the raw data we get from the database. A fitting way to do that is to use the class-transformer library, a popular choice when working with NestJS.
post.model.ts
1 2 3 4 5 6 7 8 9 10 |
import { Expose } from 'class-transformer'; class PostModel { id: number; title: string; @Expose({ name: 'post_content' }) content: string; } export default PostModel; |
We need to call the plainToInstance function in our repository to use the above model.
posts.repository.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 |
import { Injectable } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import { plainToInstance } from 'class-transformer'; import PostModel from './post.model'; @Injectable() class PostsRepository { constructor(private readonly databaseService: DatabaseService) {} async getAll() { const databaseResponse = await this.databaseService.runQuery(` SELECT * FROM posts `); return plainToInstance(PostModel, databaseResponse.rows); } } export default PostsRepository; |
Thanks to doing the above, the data returned by the getAll function contains the instances of the PostModel class. Now, instead of post_content we have the content property.
1 2 3 4 5 6 7 |
[ { id: 1, title: 'Hello world', content: 'Lorem ipsum' } ] |
Using parametrized queries
We often need to use the input provided by the user as a part of our SQL query. When doing that carelessly, we open ourselves to SQL injections. The SQL injection can happen if we treat the user’s input as a part of the query. Let’s take a look at a simple example:
1 2 3 4 5 6 7 8 9 10 11 12 |
async getById(id: unknown) { const databaseResponse = await this.databaseService.runQuery( ` SELECT * FROM posts WHERE id=${id} ` ); const entity = databaseResponse.rows[0]; if (!entity) { throw new NotFoundException(); } return plainToInstance(PostModel, entity); } |
Because in the getById function, we concatenate a string, we open ourselves to the following SQL injection:
1 |
getById('1; DROP TABLE posts;'); |
Running the getById method with the above string causes the following SQL query to run:
1 |
SELECT * FROM posts WHERE id=1; DROP TABLE posts; |
Unfortunately, it destroys our posts table.
One one of dealing with the above problem is using parameterized queries. When we use it, we send the parameters separately from the query, and our database knows to treat them as parameters.
To use parameters, we need to provide the second argument to the runQuery method we’ve defined in the DatabaseService.
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 |
import { Injectable, NotFoundException } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import { plainToInstance } from 'class-transformer'; import PostModel from './post.model'; @Injectable() class PostsRepository { constructor(private readonly databaseService: DatabaseService) {} async getById(id: number) { const databaseResponse = await this.databaseService.runQuery( ` SELECT * FROM posts WHERE id=$1 `, [id], ); const entity = databaseResponse.rows[0]; if (!entity) { throw new NotFoundException(); } return plainToInstance(PostModel, entity); } async delete(id: number) { const databaseResponse = await this.databaseService.runQuery( `DELETE FROM posts WHERE id=$1`, [id], ); if (databaseResponse.rowCount === 0) { throw new NotFoundException(); } } // ... } export default PostsRepository; |
Validating incoming data
To validate the data provided by the users, we can take advantage of the class-validator library that’s popular among people using the NestJS framework.
post.dto.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 |
import { IsString, IsNotEmpty } from 'class-validator'; class PostDto { @IsString() @IsNotEmpty() title: string; @IsString() @IsNotEmpty() content: string; } export default PostDto; |
We can use the above class in our repository when creating and updating posts.
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 |
import { Injectable, NotFoundException } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import { plainToInstance } from 'class-transformer'; import PostModel from './post.model'; import PostDto from './post.dto'; @Injectable() class PostsRepository { constructor(private readonly databaseService: DatabaseService) {} async create(postData: PostDto) { const databaseResponse = await this.databaseService.runQuery( ` INSERT INTO posts ( title, post_content ) VALUES ( $1, $2 ) RETURNING * `, [postData.title, postData.content], ); return plainToInstance(PostModel, databaseResponse.rows[0]); } async update(id: number, postData: PostDto) { const databaseResponse = await this.databaseService.runQuery( ` 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(); } return plainToInstance(PostModel, entity); } // ... } export default PostsRepository; |
If you want to see the full repository, check out this repository.
We also need to use the PostDto class in our controller.
posts.controller.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 |
import { Body, Controller, Delete, Get, Param, Post, Put, } from '@nestjs/common'; import { PostsService } from './posts.service'; import FindOneParams from '../utils/findOneParams'; import PostDto from './post.dto'; @Controller('posts') export default class PostsController { constructor(private readonly postsService: PostsService) {} @Get() getPosts() { return this.postsService.getPosts(); } @Get(':id') getPostById(@Param() { id }: FindOneParams) { return this.postsService.getPostById(id); } @Put(':id') updatePost(@Param() { id }: FindOneParams, @Body() postData: PostDto) { return this.postsService.updatePost(id, postData); } @Post() createPost(@Body() postData: PostDto) { return this.postsService.createPost(postData); } @Delete(':id') deletePost(@Param() { id }: FindOneParams) { return this.postsService.deletePost(id); } } |
The FindOneParams class takes care of parsing the id from the string to a number.
For validation to take place, we also need to use the ValidationPipe. To do that globally, we can add it to the providers array in our AppModule.
app.module.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 |
import { Module, ValidationPipe } from '@nestjs/common'; import { APP_PIPE } from '@nestjs/core'; @Module({ providers: [ { provide: APP_PIPE, useValue: new ValidationPipe({ transform: true, }), }, ], // ... }) export class AppModule {} |
Using services
You might have noticed that the PostsController uses the PostsService, a straightforward service that uses the PostsRepository.
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 |
import { Injectable } from '@nestjs/common'; import PostsRepository from './posts.repository'; import PostDto from './post.dto'; @Injectable() export class PostsService { constructor(private readonly postsRepository: PostsRepository) {} getPosts() { return this.postsRepository.getAll(); } getPostById(id: number) { return this.postsRepository.getById(id); } createPost(postData: PostDto) { return this.postsRepository.create(postData); } updatePost(id: number, postData: PostDto) { return this.postsRepository.update(id, postData); } deletePost(id: number) { return this.postsRepository.delete(id); } } |
A service is a great place to write additional logic. A good example would be caching or using ElasticSearch.
If you want to know more about ElasticSearch, check out API with NestJS #12. Introduction to Elasticsearch
Summary
There could be many reasons we might not want to use ORM, and we’ve covered some of them in this article. To deal with that, we’ve implemented a way to write raw SQL queries when working with PostgreSQL and NestJS. To increase the development experience, we’ve decided to rely on Knex for managing migrations. The repository created in this article can serve as a good starting point for a more complex project.
Hi Marcin, great article – very helpful as I’m starting a new project with Nest. Just wanted to mention that the app.module.ts file should also import the PostModule and DatabaseModule. Without this I wasn’t able to connect to Postgres. I found this by comparing with your completed file.
Below is the code that worked for me, I’ve commented out the sections on auth which come later.
Hi Marcin, great article x2. FYI, this creates a non iterable object which defeats the purpose of a getAll
Type ‘PostModel’ must have a ‘[Symbol.iterator]()’ method that returns an iterator.
can we use prisma for migration since it have good migration than using knex then use query builder for query