- 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
The complexity of our database queries grows together with our application. Due to that, the time necessary to complete the queries. A common way to address this problem is using indexes. In this article, we explore indexes both through MikroORM and SQL queries.
The idea behind indexes
Across the last few articles, we’ve defined a table where we keep posts. Among others, it contains the author_id field.
We might need a routine query to look for posts written by a specific author.
1 | SELECT * FROM post_entity WHERE author_id = 1; |
We must be aware that the above query needs to scan the entire post_entity table to find matching entities. Sometimes iterating a table from cover to cover might not be good enough performance-wise. We can deal with this issue by creating an index.
The goal of the index is to make our queries faster by creating a data structure that organizes a table using a particular column.
1 | CREATE INDEX post_entity_author_id_index ON post_entity (author_id); |
The above command creates an index using the author_id column of the post_entity table. We can imagine the index as key and value pairs. In our case, the keys are the author ids, and the values point to particular posts.
author_id | post_id |
---|---|
1 | 1 |
1 | 2 |
1 | 3 |
2 | 4 |
3 | 5 |
In real life, the data structures used by PostgreSQL for indexing are more elaborate to maximze the performance. By default, PostgreSQL uses the B-tree data structure when creating indexes where each leaf contains a pointer to a particular table row.
Thanks to the sorted data structure, we can quickly find all posts written by a particular author. However, besides the noticeable advantage when fetching data, there are some crucial downsides.
Every time we insert or update data, PostgreSQL also needs to update the indexes. While indexes can speed up our SELECT queries, they slow down our inserts and updates. Besides the performance, indexes create data structures that need additional space.
Creating indexes with MikroORM
To create an index using MikroORM, we need to use the @Index() decorator.
post.entity.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 | import { Entity, PrimaryKey, ManyToOne, Index, } from '@mikro-orm/core'; import User from '../users/user.entity'; import WithSoftDelete from '../utils/withSoftDelete'; @Entity() @WithSoftDelete() class PostEntity { @PrimaryKey() id: number; @ManyToOne() @Index() author: User; // ... } export default PostEntity; |
Adding the above to our schema and running npx mikro-orm migration:create results in the following migration:
Migration20220614231701.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 | import { Migration } from '@mikro-orm/migrations'; export class Migration20220614231701 extends Migration { async up(): Promise<void> { this.addSql('create index "post_entity_author_id_index" on "post_entity" ("author_id");'); } async down(): Promise<void> { this.addSql('drop index "post_entity_author_id_index";'); } } |
We can use the name option in the @Index() decorator to change the auto-generated name of the index to something else.
Multi-column indexes
Sometimes we might notice that we often make queries with multiple conditions. For example, let’s look for posts authored by a certain user and deleted during the last month.
1 2 | SELECT * FROM post_entity WHERE author_id = 1 AND deleted_at > NOW() - interval '1 month' |
We can easily create a multi-column index using an SQL query.
1 2 | CREATE INDEX post_entity_author_id_deleted_at_index ON post_entity (author_id, deleted_at); |
We can achieve the same thing with MikroORM by using the @Index() decorator with the properties argument.
post.entity.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 | import { Entity, Property, PrimaryKey, ManyToOne, Collection, ManyToMany, Index, } from '@mikro-orm/core'; import User from '../users/user.entity'; import Category from '../categories/category.entity'; import WithSoftDelete from '../utils/withSoftDelete'; @Entity() @WithSoftDelete() @Index({ properties: ['author', 'deletedAt'] }) class PostEntity { @PrimaryKey() id: number; @Property() title: string; @Property() content: string; @ManyToOne() @Index() author: User; @ManyToMany(() => Category) categories: Collection<Category>; @Index() @Property({ nullable: true, type: 'timestamptz' }) deletedAt?: Date; } export default PostEntity; |
Creating the above index and running npx mikro-orm migration:create generates the following migration:
Migration20220615230639.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 | import { Migration } from '@mikro-orm/migrations'; export class Migration20220615230639 extends Migration { async up(): Promise<void> { this.addSql('create index "post_entity_author_id_deleted_at_index" on "post_entity" ("author_id", "deleted_at");'); } async down(): Promise<void> { this.addSql('drop index "post_entity_author_id_deleted_at_index";'); } } |
Unique indexes
In one of the previous articles, we’ve defined a table for a user.
One of the columns of the above table is email, which we’ve declared as unique.
1 | CONSTRAINT user_email_unique UNIQUE (email) |
Whenever we define a unique constraint, PostgreSQL automatically creates a unique index to enforce the constraint.
1 | CREATE UNIQUE INDEX user_email_unique ON "user" (email); |
We don’t need to manualy create indexes on unique columns, PostgtreSQL does that for us when we define the constraint.
Remember that PostgreSQL also creates the unique constraint and index for primary keys. Because of that, every table has at least one index if it contains a primary key.
Creating unique indexes with MikroORM
To create a unique constraint and index with MikroORM, we can use unique: true along with the @Property() decorator.
user.entity.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 | import { Entity, Property, PrimaryKey, } from '@mikro-orm/core'; @Entity() class User { @PrimaryKey() id: number; @Property({ unique: true }) email: string; // ... } export default User; |
An alternative approach to the above is using the @Unique() decorator.
user.entity.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 | import { Entity, Property, PrimaryKey, Unique } from '@mikro-orm/core'; @Entity() class User { @PrimaryKey() id: number; @Property() @Unique() email: string; // ... } export default User; |
Defining the above schema and running npx mikro-orm migration:create causes the following migration to be created:
Migration20220615013946.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 | import { Migration } from '@mikro-orm/migrations'; export class Migration20220615013946 extends Migration { async up(): Promise<void> { this.addSql('alter table "user" add constraint "user_email_unique" unique ("email");'); } async down(): Promise<void> { this.addSql('alter table "user" drop constraint "user_email_unique";'); } } |
Types of indexes
So far, all the indexes we’ve created in this article used the B-tree data structure. While it fits most of the cases, there are some other options. For example, we can use the expression property of the @Index() decorator to provide an SQL query used to create the index.
Generalized Inverted Indexes (GIN)
GIN indexes fit best where the values contain more than one key. A good example would be the array data type. However, they can also come in handy when implementing text searching.
1 2 3 4 5 6 | @Property() @Index({ expression: 'CREATE INDEX post_entity_title_index ON post_entity USING GIN (title)', }) title: string; |
Please notice that GIN indexes might not work out of the box.
Hash indexes
Hash index uses the hash table data structure and might come in handy in some specific use-cases.
1 2 3 4 5 6 | @Property() @Index({ expression: 'CREATE INDEX post_entity_title_index ON post_entity USING hash (title)', }) title: string; |
Block Range Indexes (BRIN)
The Block Range Indexes can come in handy when used with data types that have a linear sort order.
1 2 3 4 5 6 | @Property() @Index({ expression: 'CREATE INDEX post_entity_title_index ON post_entity USING BRIN (title)', }) title: string; |
Generalized Search Tree (GIST)
The GIST indexes can be helpful when indexing geometric data and implementing text search. In some cases, it might be preferable over GIN.
1 2 3 4 5 6 | @Property() @Index({ expression: 'CREATE INDEX post_entity_title_index ON post_entity USING GIN (title)', }) title: string; |
Summary
In this article, we’ve gone through indexes and how they can affect the performance of our queries. The above includes improving the performance and, in some cases, making it worse. We’ve also learned how to create indexes through SQL queries and MikroORM. Besides regular indexes, we’ve also created multi-column indexes and used index types other than B-tree. All of the above gives us a solid introduction to how indexes work and what are their pros and cons.