It is very common to implement a feature of searching through the contents of the database. In one of the previous articles, we learned how to implement it in a simple way using pattern matching.
Today we take it a step further and learn about the data types explicitly designed for full-text search.
Text Search Types
PostgreSQL provides two data types that help us implement full-text search. They allow us to search through a collection of texts and find the ones that match a given query the most.
tsvector
The tsvector column stores the text in a format optimized for search. To parse a string into the tsvector format, we need the to_tsvector function.
1SELECT to_tsvector('english', 'The quick brown fox quickly jumps over the lazy dog');When we look at the result of the above query, we notice a set of optimizations. One of the most apparent is grouping duplicates. Thanks to using the English dictionary, PostgreSQL noticed that “quick” and “quickly” are two variants of the same word.
Also, using the tsvector type can help us filter out stop words. They are very common, appear in almost every sentence, and don’t have much value when searching through text. Since we used the English dictionary in the above example, PostgreSQL filtered out the words “the” and “over”.
tsquery
The tsquery data type stores the text we want to search for. To transform a string into the tsquery format, we can use the to_tsquery function.
1SELECT to_tsquery('fox');To check if a certain tsvector matches the tsquery, we need to use the @@ operator.
1SELECT to_tsvector('english', 'The quick brown fox quickly jumps over the lazy dog') @@ to_tsquery('fox');true
When doing the above, we can play with the &, |, and ! boolean operators. For example, we can use the ! operator to make sure a given text does not contain a particular word.
1SELECT to_tsvector('english', 'The quick brown fox quickly jumps over the lazy dog') @@ to_tsquery('!cat');true
Check out the official documentation for a good explanation of all available operators.
Another handy function is plainto_tsquery. It takes an unformatted phrase and inserts the & operator between words. Because of that, it is an excellent choice to handle the input from the user.
1SELECT to_tsvector('english', 'The quick brown fox quickly jumps over the lazy dog') @@ plainto_tsquery('brown fox');true
Transforming the existing data
Let’s take a look at our posts table.
1CREATE TABLE posts (
2 id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
3 title text NOT NULL,
4 post_content text NOT NULL,
5 author_id int REFERENCES users(id) NOT NULL
6)Unfortunately, it does not contain a tsvector column. The most straightforward solution to the above problem is to convert our data to tsvector on the fly.
1SELECT * FROM posts
2WHERE to_tsvector('english', post_content) @@ plainto_tsquery('fox');We can take the above even further and combine the contents of the title and post_content columns to search through both.
1SELECT * FROM posts
2WHERE to_tsvector('english', post_content || ' ' || title) @@ plainto_tsquery('fox');The crucial issue with the above approach is that it causes PostgreSQL to transform the text from every record of the posts database, which can take a substantial amount of time.
Instead, I suggest defining a generated column that contains the data transformed into the tsvector format.
1ALTER TABLE posts
2ADD COLUMN text_tsvector tsvector GENERATED ALWAYS AS (
3 to_tsvector('english', post_content || ' ' || title)
4) STOREDIf you want to know moure about generated columns, check out Defining generated columns with PostgreSQL and TypeORM
Since we use the STORED keyword, we define a stored generated column that is saved in our database. PostgreSQL updates it automatically every time we modify the post_content and title columns.
We can now use our generated column when making a SELECT query to improve its performance drastically.
1SELECT * FROM posts
2WHERE text_tsvector @@ plainto_tsquery('fox');Ordering the results
So far, we haven’t paid attention to the order of the results of our SELECT query. Sorting the search results based on relevance could help the users quite a bit.
For example, we can indicate that the text from the title column is more important than the post_content column. To do that, let’s change how we create our text_tsvector column and use the setweight function.
1ALTER TABLE posts
2ADD COLUMN text_tsvector tsvector GENERATED ALWAYS AS (
3 setweight(to_tsvector('english', title), 'A') ||
4 setweight(to_tsvector('english', post_content), 'B')
5) STOREDLet’s compare the two following posts after modifying the text_tsvector column:
The combined value of the title and post_content is the same in both posts. However, the text_tsvector takes into account that the title column is more important.
Thanks to the above, we can now use the ts_rank function to order our results based on the weight of each column.
1SELECT * FROM posts
2WHERE text_tsvector @@ plainto_tsquery('brown fox')
3ORDER BY ts_rank(text_tsvector, plainto_tsquery('brown fox')) DESCImplementing full-text search with NestJS
Let’s create a migration first to implement the above functionalities in our NestJS project.
1npx knex migrate:make add_post_tsvector1import { Knex } from 'knex';
2
3export async function up(knex: Knex): Promise<void> {
4 await knex.raw(`
5 ALTER TABLE posts
6 ADD COLUMN text_tsvector tsvector GENERATED ALWAYS AS (
7 setweight(to_tsvector('english', title), 'A') ||
8 setweight(to_tsvector('english', post_content), 'B')
9 ) STORED
10 `);
11
12 return knex.raw(`
13 CREATE INDEX post_text_tsvector_index ON posts USING GIN (text_tsvector)
14 `);
15}
16
17export async function down(knex: Knex): Promise<void> {
18 return knex.raw(`
19 ALTER TABLE posts
20 DROP COLUMN text_tsvector
21 `);
22}The crucial thing to notice above is that we are creating a Generalized Inverted Index (GIN). It works well with text searching and is appropriate when a column contains more than one value. Doing that can speed up our SELECT queries very significantly.
If you want to know more about indexes, check out API with NestJS #82. Introduction to indexes with raw SQL queries
In one of the previous parts of this series, we implemented the support for the search query parameter.
1import {
2 ClassSerializerInterceptor,
3 Controller,
4 Get,
5 Query,
6 UseInterceptors,
7} from '@nestjs/common';
8import { PostsService } from './posts.service';
9import GetPostsByAuthorQuery from './getPostsByAuthorQuery';
10import PaginationParams from '../utils/paginationParams';
11import SearchPostsQuery from './searchPostsQuery';
12
13@Controller('posts')
14@UseInterceptors(ClassSerializerInterceptor)
15export default class PostsController {
16 constructor(private readonly postsService: PostsService) {}
17
18 @Get()
19 getPosts(
20 @Query() { authorId }: GetPostsByAuthorQuery,
21 @Query() { search }: SearchPostsQuery,
22 @Query() { offset, limit, idsToSkip }: PaginationParams,
23 ) {
24 return this.postsService.getPosts(
25 authorId,
26 offset,
27 limit,
28 idsToSkip,
29 search,
30 );
31 }
32
33 // ...
34}Finally, we need to modify the SQL queries that we make in our repository.
1import { Injectable } from '@nestjs/common';
2import DatabaseService from '../database/database.service';
3import PostModel from './post.model';
4
5@Injectable()
6class PostsSearchRepository {
7 constructor(private readonly databaseService: DatabaseService) {}
8
9 async search(
10 offset = 0,
11 limit: number | null = null,
12 idsToSkip = 0,
13 searchQuery: string,
14 ) {
15 const databaseResponse = await this.databaseService.runQuery(
16 `
17 WITH selected_posts AS (
18 SELECT * FROM posts
19 WHERE id > $3 AND text_tsvector @@ plainto_tsquery($4)
20 ORDER BY id ASC
21 OFFSET $1
22 LIMIT $2
23 ),
24 total_posts_count_response AS (
25 SELECT COUNT(*)::int AS total_posts_count FROM posts
26 WHERE text_tsvector @@ plainto_tsquery($4)
27 )
28 SELECT * FROM selected_posts, total_posts_count_response
29 `,
30 [offset, limit, idsToSkip, searchQuery],
31 );
32 const items = databaseResponse.rows.map(
33 (databaseRow) => new PostModel(databaseRow),
34 );
35 const count = databaseResponse.rows[0]?.total_posts_count || 0;
36 return {
37 items,
38 count,
39 };
40 }
41
42 // ...
43}
44
45export default PostsSearchRepository;Above, we use the keyset pagination that prevents us from sorting the results in a straightforward way. If you want to know more, check out API with NestJS #77. Offset and keyset pagination with raw SQL queries
Summary
In this article, we’ve gone through implementing full-text search in PostgreSQL. To do that, we had to learn about the tsvector and tsquery data types. In addition, we’ve created a stored generated column and a Generalized Inverted Index to improve the performance. By doing all of the above, we’ve created a fast search mechanism that is a good fit for many applications.