- 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
- 174. API with NestJS #174. Multiple PostgreSQL schemas with Drizzle ORM
- 175. API with NestJS #175. PUT and PATCH requests with PostgreSQL and Drizzle ORM
- 176. API with NestJS #176. Database migrations with the Drizzle ORM
- 177. API with NestJS #177. Response serialization with the Drizzle ORM
As our database grows, so do the results of our queries. Returning a lot of data in our API might not be the best approach performance-wise. Dividing our content into multiple pages and solutions like infinite scrolling have been around for quite some time. In this article, we explore ways of implementing pagination and point out their pros and cons.
You can find all of the code from this series in this repository.
Offset and Limit
Let’s start with the following, straightforward query:
1 2 |
SELECT * FROM post ORDER BY id ASC |
The above returns all of the records from the post table. To be sure about the order of the results, we sort them by id.
The first step in implementing pagination would be to limit the number of results. We can do that using the LIMIT statement.
1 2 3 |
SELECT * FROM post ORDER BY id ASC LIMIT 10 |
Now, instead of getting all of the posts, we get just the first ten of them. This results in getting elements with ids from 1 to 10.
To have fully functional pagination, we need to specify the starting point of our query. To do that, we can use the OFFSET keyword. With it, we can say how many rows we want to skip.
1 2 3 4 |
SELECT * FROM post ORDER BY id ASC OFFSET 10 LIMIT 10 |
We omit the first ten posts with the above while still getting just ten posts as a result. This gives us elements with ids from 11 to 20.
If we would like to change the way we order elements while paginating, we need to modify our ORDER BY clause.
Implementing offset and limit with TypeORM
We want the users to provide the offset and the limit through query params. To implement this, let’s use the knowledge we’ve gained in previous parts of this series. This includes the usage of the class-validator and the class-transformer.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 |
import { IsNumber, Min, IsOptional } from 'class-validator'; import { Type } from 'class-transformer'; export class PaginationParams { @IsOptional() @Type(() => Number) @IsNumber() @Min(0) offset?: number; @IsOptional() @Type(() => Number) @IsNumber() @Min(1) limit?: number; } |
We can now use the @Query() decorator to inject the above parameters into our controller.
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 { Controller, Get, UseInterceptors, ClassSerializerInterceptor, Query, } from '@nestjs/common'; import PostsService from './posts.service'; import { PaginationParams } from '../utils/types/paginationParams'; @Controller('posts') @UseInterceptors(ClassSerializerInterceptor) export default class PostsController { constructor( private readonly postsService: PostsService ) {} @Get() async getPosts( @Query('search') search: string, @Query() { offset, limit }: PaginationParams ) { if (search) { return this.postsService.searchForPosts(search, offset, limit); } return this.postsService.getAllPosts(offset, limit); } // ... } |
Implementing offset-based pagination is very easy with TypeORM. Aside from returning an array of posts, we also want to return a number of them. Thanks to that, our frontend can estimate the number of pages available.
Although we could use the postsRepository.count() and postsRepository.find() methods separately, this would result in making two queries to the database. We can improve that by using postsRepository.findAndCount.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 |
async getAllPosts(offset?: number, limit?: number) { const [items, count] = await this.postsRepository.findAndCount({ relations: ['author'], order: { id: 'ASC' }, skip: offset, take: limit }); return { items, count } } |
Implementing offset and limit with Elasticsearch
In one of the previous parts of this series, we’ve integrated our posts with Elasticsearch. Fortunately, it is effortless to add the offset-based pagination to it. We need to pass the additional offset and size parameters.
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 |
async search(text: string, offset?: number, limit?: number) { const { body } = await this.elasticsearchService.search<PostSearchResult>({ index: this.index, from: offset, size: limit, body: { query: { multi_match: { query: text, fields: ['title', 'paragraphs'] } }, sort: { id: { order: 'asc' } } } }) const count = body.hits.total.value; const hits = body.hits.hits; const results = hits.map((item) => item._source); return { count, results } } |
Disadvantages
The solution with offset and limit seems to be the most widely used. Unfortunately, its performance might fall short of our expectations.
An essential thing to keep in mind is that the database still needs to compute the rows skipped by the OFFSET. First, the database sorts all of the rows according to our ORDER BY clause. Then, Postgres drops the number of rows specified in the OFFSET. This might require quite a bit of work.
Aside from the performance, another important thing to consider is consistency. We want an element to appear in the results exactly once. Let’s imagine the following situation:
- one user fetches page number one with posts
- meanwhile, the second user creates a new post – after sorting, it ends up on page number one
- the first user fetches the second page
The last element of the first page is now again seen on the second page because of the above. What’s even worse, the user missed the element that has been added to the first page.
Advantages
While the offset approach has its cons, it is still common. Due to its simplicity, it is straightforward to implement. Also, it is easy to change the column that we use for sorting, including the usage of multiple columns. Because of that, it is a viable solution in many cases. Especially if the offset is expected not to be big, and the result inconsistencies are acceptable.
Keyset pagination
While the offset-based pagination can be useful, its performance might not be the best. Sometimes we might want to avoid it.
One of the ways to do so is to implement keyset pagination. Instead of using the OFFSET clause, we use the WHERE command to select the data we haven’t fetched yet.
Let’s start with a simple query:
1 2 3 |
SELECT * FROM post ORDER BY id ASC LIMIT 10 |
The above query gets us the first ten posts. Let’s assume that the id of the last post was 20. With this assumption, we can run this query:
1 2 3 4 |
SELECT * FROM post WHERE id > 20 ORDER BY id ASC LIMIT 10 |
The above query gets us ten posts with id bigger than 20. Now, we can take the last post and rerun the query, changing the id. Doing that creates us simple and efficient pagination mechanism.
This exposes the biggest drawback of the keyset pagination, though. To get a page, we need to know the last element of the previous set of results. This makes traversing multiple pages at once impossible.
Fortunately, most of the time, the users got straight to the next page. To cover all of the cases, we can implement both the offset-based approach and the keyset pagination.
If we would like to change the column that we order our elements by, we need to change both the ORDER BY and WHERE clauses.
Implementing keyset pagination with TypeORM
Adding keyset pagination is not difficult with TypeORM. First, let’s add another query parameter called startId to our PaginationParams.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 |
import { IsNumber, Min, IsOptional } from 'class-validator'; import { Type } from 'class-transformer'; export class PaginationParams { @IsOptional() @Type(() => Number) @IsNumber() @Min(1) startId?: number; @IsOptional() @Type(() => Number) @IsNumber() @Min(0) offset?: number; @IsOptional() @Type(() => Number) @IsNumber() @Min(1) limit?: number; } |
Along the way, we will face a small issue with the count of our elements. The postsRepository.findAndCount with a WHERE clause will return only the number of matching posts. We need to count them separately.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 |
async getAllPosts(offset?: number, limit?: number, startId?: number) { const where: FindManyOptions<Post>['where'] = {}; let separateCount = 0; if (startId) { where.id = MoreThan(startId); separateCount = await this.postsRepository.count(); } const [items, count] = await this.postsRepository.findAndCount({ where, relations: ['author'], order: { id: 'ASC' }, skip: offset, take: limit }); return { items, count: startId ? separateCount : count } } |
Implementing keyset pagination with Elasticsearch
We can also achieve the above result with Elasticsearch by adding the id of a post to our query.
In this very simple example, we separately count the matching posts. If you feel like using other pagination approaches due to performance reasons, Elasticsearch has other built-in methods of pagination.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 |
async count(query: string, fields: string[]) { const { body } = await this.elasticsearchService.count<PostCountResult>({ index: this.index, body: { query: { multi_match: { query, fields } } } }) return body.count; } |
The last thing to do is to perform a boolean query:
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 |
async search( text: string, offset?: number, limit?: number, startId = 0 ) { let separateCount = 0; if (startId) { separateCount = await this.count(text, ['title', 'paragraphs']); } const { body } = await this.elasticsearchService.search<PostSearchResult>({ index: this.index, from: offset, size: limit, body: { query: { bool: { should: { multi_match: { query: text, fields: ['title', 'paragraphs'] } }, filter: { range: { id: { gt: startId } } } } }, sort: { id: { order: 'asc' } } } }) const count = body.hits.total.value; const hits = body.hits.hits; const results = hits.map((item) => item._source); return { count: startId ? separateCount : count, results } } |
Disadvantages
The most apparent drawback of the keyset pagination is that we need to know the element that we want to start with. Fortunately, we can overcome it by mixing in some offset-base pagination as in the examples above.
Another consideration is that the column we use in the WHERE clause should have an index to experience an extra performance boost. Fortunately, in the documentation, we can see that Postgres creates an index for every primary key constraint automatically. Therefore, the keyset pagination should be fast with ids out of the box.
If you want to know more about creating indexes, check out API with NestJS #14. Improving performance of our Postgres database with indexes
Also, ordering the results by text fields might be tricky if we want to implement natural sorting. If you want to read more about using the < operator with strings, read this answer on StackOverflow.
Advantages
One of the main advantages of keyset pagination is a performance improvement over the offset-based approach. Also, it solves the inconsistency issue that we experience with the offset-based approach. If the user adds or removes elements between fetching pages, it does not cause element duplicates or omissions.
Summary
In this article, we’ve implemented two types of pagination with PostgreSQL and TypeORM. We’ve pointed out the advantages and disadvantages of both the offset-based approach and the keyset pagination. While neither of them are ideal, they make a good combination that covers a variety of cases.
Since in this series we’ve also used Elasticsearch, we didn’t forget about it when implementing the pagination. While keyset pagination might not be a perfect fit with Elasticsearch, it also has other built-in methods of pagination.