- 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
The possibility of searching through the contents of the database is a very common feature. There are great solutions built with that use case in mind, such as Elasticsearch. Even though that’s the case, PostgreSQL also has the functionality of matching a given string pattern. In this article, we explore what PostgreSQL offers and use this in our NestJS project.
The code from this article is in this repository.
Pattern matching with LIKE
The idea behind pattern matching is to check if a given string has specific characteristics. The most straightforward way of doing that in PostgreSQL is by using the LIKE operator.
1 |
SELECT 'Hi! This is my 1st post.' LIKE 'Hi! This is my 1st post.' -- true |
Besides regular text, our pattern can contain the percent sign – %. It matches a sequence of zero or more characters.
1 2 3 4 |
SELECT 'Hi! This is my 1st post.' LIKE 'Hi!%'; -- true SELECT 'I wrote this post.' LIKE '%post.'; -- true SELECT 'Hi! This is my favourite post.' LIKE 'Hi! % post.'; -- true SELECT 'This is the 1st time I am writing.' LIKE '%1st%'; -- true |
When using the LIKE operator, we can also take advantage of the underscore sign – _. It matches a single character.
1 2 3 |
SELECT 'Hi! This is my 1st post.' LIKE 'Hi! This is my ___ post.'; -- true SELECT 'Hi! This was a 2nd post.' LIKE 'Hi! This _____ ___ post.'; -- true SELECT 'Hi! This is my 1st post.' LIKE 'Hi! This _____ ___ post.'; -- true |
We can also use multiple percentages and underscore signs in a single pattern.
1 2 |
SELECT 'This is my 1st post.' LIKE 'This % my ___ %.'; -- true SELECT 'This was my 2nd article.' LIKE 'This % my ___ %.'; -- true |
Using pattern matching in a real use-case
Pattern matching is especially useful when performing a SELECT on a table and using WHERE.
1 2 |
SELECT * FROM posts WHERE title LIKE '%post%'; |
Above, we use the % sign on both the left and right sides of the post string when looking through the title column. This means we are looking for rows that use the post string in any way in the title column. The above is a very common case.
Finding rows that don’t match a pattern
We can also use NOT LIKE to find rows that don’t match a particular pattern.
1 2 |
SELECT * FROM posts WHERE title NOT LIKE '%content%'; |
Above, we look for posts with a title that does not contain the word “content”.
Implementing searching in NestJS
Let’s use the approach with the LIKE operator and two % signs in practice. To do that, let’s expect the user to provide a query parameter.
searchPostsQuery.ts
1 2 3 4 5 6 7 8 9 10 |
import { IsString, IsNotEmpty, IsOptional } from 'class-validator'; class SearchPostsQuery { @IsString() @IsNotEmpty() @IsOptional() search?: string; } export default SearchPostsQuery; |
Once we have the above class, we need to use it 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 |
import { ClassSerializerInterceptor, Controller, Get, Query, UseInterceptors, } from '@nestjs/common'; import { PostsService } from './posts.service'; import GetPostsByAuthorQuery from './getPostsByAuthorQuery'; import PaginationParams from '../utils/paginationParams'; import SearchPostsQuery from "./searchPostsQuery"; @Controller('posts') @UseInterceptors(ClassSerializerInterceptor) export default class PostsController { constructor(private readonly postsService: PostsService) {} @Get() getPosts( @Query() { authorId }: GetPostsByAuthorQuery, @Query() { search }: SearchPostsQuery, @Query() { offset, limit, idsToSkip }: PaginationParams, ) { return this.postsService.getPosts(authorId, offset, limit, idsToSkip, search); } // ... } |
We can rely on PostsService to call the correct methods from our repositories.
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 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 |
import { Injectable } from '@nestjs/common'; import PostsRepository from './posts.repository'; import PostsStatisticsRepository from './postsStatistics.repository'; import PostsSearchRepository from './postsSearch.repository'; @Injectable() export class PostsService { constructor( private readonly postsRepository: PostsRepository, private readonly postsStatisticsRepository: PostsStatisticsRepository, private readonly postsSearchRepository: PostsSearchRepository, ) {} getPosts( authorId?: number, offset?: number, limit?: number, idsToSkip?: number, searchQuery?: string, ) { if (authorId && searchQuery) { return this.postsSearchRepository.searchByAuthor( authorId, offset, limit, idsToSkip, searchQuery, ); } if (authorId) { return this.postsRepository.getByAuthorId( authorId, offset, limit, idsToSkip, ); } if (searchQuery) { return this.postsSearchRepository.search( offset, limit, idsToSkip, searchQuery, ); } return this.postsRepository.get(offset, limit, idsToSkip); } // ... } |
We can delegate the logic of searching through the posts to a separate repository to avoid creating one big file that’s difficult to read.
postsSearch.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 { Injectable } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import PostModel from './post.model'; @Injectable() class PostsSearchRepository { constructor(private readonly databaseService: DatabaseService) {} async search( offset = 0, limit: number | null = null, idsToSkip = 0, searchQuery: string, ) { const databaseResponse = await this.databaseService.runQuery( ` WITH selected_posts AS ( SELECT * FROM posts WHERE id > $3 AND concat(post_content, title) LIKE concat('%', $4::text, '%') ORDER BY id ASC OFFSET $1 LIMIT $2 ), total_posts_count_response AS ( SELECT COUNT(*)::int AS total_posts_count FROM posts WHERE concat(post_content, title) LIKE concat('%', $4::text, '%') ) SELECT * FROM selected_posts, total_posts_count_response `, [offset, limit, idsToSkip, searchQuery], ); const items = databaseResponse.rows.map( (databaseRow) => new PostModel(databaseRow), ); const count = databaseResponse.rows[0]?.total_posts_count || 0; return { items, count, }; } // ... } export default PostsSearchRepository; |
Above, we implement pagination. If you want to know more, check out API with NestJS #77. Offset and keyset pagination with raw SQL queries
A few significant things are happening above. We use pattern matching with both title and post_content columns. We wrap the query provided by the user with the % signs on both ends. To do that, we use the concat function.
It is important to acknowledge that our query might work in an unexpected way if the users puts % or _ characters in their search input. To prevent this, we could sanitize the provided string by prepending all special characters with the \ sign.
We also indicate that we want the $4 argument to be treated as a string because the concat() function works with different data types. Without it, PostgreSQL would throw an error.
The ILIKE operator
The ILIKE operator works in a similar way to LIKE. However, an essential thing about ILIKE is that it is case-insensitive.
1 |
SELECT 'Hi! This is my favourite post.' ILIKE 'hI! % pOsT.'; -- true |
Since we let the user search for any occurrence of a given string, let’s make it case-insensitive.
postsSearch.repository.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 |
import { Injectable } from '@nestjs/common'; import DatabaseService from '../database/database.service'; import PostModel from './post.model'; @Injectable() class PostsSearchRepository { constructor(private readonly databaseService: DatabaseService) {} // ... async searchByAuthor( authorId: number, offset = 0, limit: number | null = null, idsToSkip = 0, searchQuery: string, ) { const databaseResponse = await this.databaseService.runQuery( ` WITH selected_posts AS ( SELECT * FROM posts WHERE author_id=$1 AND id > $4 AND (title ILIKE concat('%', $5::text, '%') OR post_content ILIKE concat('%', $5::text, '%')) ORDER BY id ASC OFFSET $2 LIMIT $3 ), total_posts_count_response AS ( SELECT COUNT(*)::int AS total_posts_count FROM posts WHERE author_id=$1 AND id > $4 AND (title ILIKE concat('%', $5::text, '%') OR post_content ILIKE concat('%', $5::text, '%')) ) SELECT * FROM selected_posts, total_posts_count_response `, [authorId, offset, limit, idsToSkip, searchQuery], ); const items = databaseResponse.rows.map( (databaseRow) => new PostModel(databaseRow), ); const count = databaseResponse.rows[0]?.total_posts_count || 0; return { items, count, }; } } export default PostsSearchRepository; |
Using regular expressions
Using LIKE and ILIKE can cover a lot of use cases with pattern matching. But, unfortunately, not all of them. Sometimes we might need to be more specific when describing the pattern.
Fortunately, PostgreSQL allows us to use regular expressions with the ~ operator.
1 2 |
SELECT 'Hi!' ~ '^[0-9]*$'; -- false SELECT '123' ~ '^[0-9]*$'; -- true |
If you want to know more about regular expressions, check out my series abour regex.
We can also make it case-insensitive by using the ~* operator.
1 |
SELECT 'Admin' ~* 'admin|user|moderator'; -- true |
To check if a string does not match the regular expression, we can use the !~ operator.
1 2 |
SELECT 'admin' !~ 'admin|user|moderator'; -- false SELECT 'editor' !~ 'admin|user|moderator'; -- true |
We can also mix it up and check if a string does not match the regular expression and keep it case-insensitive.
1 |
SELECT 'ADMIN' !~* 'admin|user|moderator'; -- false |
Regular expressions can be handy when the LIKE operator is not enough. Unfortunately, we need to ensure we are writing an expression that does not cause issues with the performance. If you want to know more, check out Regex course – part four. Avoiding catastrophic backtracking using lookahead.
The SIMILAR TO operator
The SQL standard also contains the SIMILAR TO operator. It is a blend of the LIKE operator and regular expressions. Patterns used with SIMILAR TO are similar to regex but use _ and % instead of . and .*.
1 |
SELECT '123' SIMILAR TO '[0-9]{1,}'; -- true |
The interesting thing is that PostgreSQL translates the patterns from the SIMILAR TO format to regular expressions.
1 2 |
EXPLAIN ANALYZE SELECT * FROM posts WHERE title SIMILAR TO '[0-9]{1,}'; |
Because of the above, I suggest writing regular expressions instead of using the SIMILAR TO operator when the LIKE keyword is not enough.
Summary
In this article, we’ve gone through pattern matching with PostgreSQL. We’ve used it to implement a search feature with NestJS. We also compared the LIKE and SIMILAR TO operators and regular expressions to get a better picture.
There is still more to learn when it comes to searching through text in PostgreSQL, such as the text search types. Stay tuned for more content!