Nest.js Tutorial

Arrays with PostgreSQL and the Drizzle ORM

Marcin Wanago
NestJS

Thanks to some of its features, PostgreSQL sets itself apart from other SQL databases. Unlike many SQL databases that limit columns to single entries, PostgreSQL lets us store multiple values in a single column. This simplifies database design and can improve performance. In this article, we will explore the practical uses of arrays in PostgreSQL and show how to use them with the Drizzle ORM.

The array column

In earlier sections of this series, we created the structure for a table that holds articles.

database-schema.ts
1export const articles = pgTable('articles', {
2  id: serial('id').primaryKey(),
3  title: text('title').notNull(),
4  content: text('content').notNull(),
5  authorId: integer('author_id')
6    .references(() => users.id)
7    .notNull(),
8});

This time, instead of a plain text column for the article’s content, let’s use an array. To do that, we need the array() function.

database-schema.ts
1export const articles = pgTable('articles', {
2  id: serial('id').primaryKey(),
3  title: text('title').notNull(),
4  paragraphs: text('paragraphs').array().notNull(),
5  authorId: integer('author_id')
6    .references(() => users.id)
7    .notNull(),
8});
9 
10// ...

We can now use the Drizzle ORM Kit to create a migration.

1npx drizzle-kit generate --name change-article-content-to-paragraphs

Drizzle ORM Kit will ask if you want to rename the content column to paragraphs or create a new column from scratch. We, however, want to do something a bit more advanced since the type of our column changes from a simple string to an array of strings.

To avoid losing the data already stored in the content array, let’s set it as the first element of the paragraphs array and then remove the content column.

0005_change-article-content-to-paragraphs.sql
1ALTER TABLE articles
2ADD COLUMN paragraphs TEXT[];
3 
4UPDATE articles
5SET paragraphs = ARRAY[content];
6 
7ALTER TABLE articles
8DROP COLUMN content;

Thanks to this approach, we don’t lose the data stored in our database when we run our migration.

Working with arrays using the Drizzle ORM

It’s very straightforward to insert a record into the table that contains an array.

1await this.drizzleService.db
2  .insert(databaseSchema.articles)
3  .values({
4    authorId: 1,
5    title: 'My article',
6    paragraphs: [
7      'First paragraph',
8      'Second paragraph'
9    ],
10  })
11  .returning();

To achieve that in a NestJS application, we need to adjust the Data Transfer Objects so that users can send arrays to our REST API.

create-article.dto.ts
1import { IsString, IsNotEmpty, IsOptional, IsNumber } from 'class-validator';
2 
3export class CreateArticleDto {
4  @IsString()
5  @IsNotEmpty()
6  content: string;
7 
8  @IsString({ each: true })
9  @IsNotEmpty({ each: true })
10  paragraphs: string[];
11 
12  @IsOptional()
13  @IsNumber({}, { each: true })
14  categoryIds: number[] = [];
15}
Above, we use the class-validator library to ensure that the user provides a valid array of strings.

We can now adjust our service and use the paragraphs property from our DTO.

articles.service.ts
1import { BadRequestException, Injectable } from '@nestjs/common';
2import { DrizzleService } from '../database/drizzle.service';
3import { databaseSchema } from '../database/database-schema';
4import { CreateArticleDto } from './dto/create-article.dto';
5import { isDatabaseError } from '../database/databse-error';
6import { PostgresErrorCode } from '../database/postgres-error-code.enum';
7 
8@Injectable()
9export class ArticlesService {
10  constructor(private readonly drizzleService: DrizzleService) {}
11 
12  async create(article: CreateArticleDto, authorId: number) {
13    try {
14      const createdArticles = await this.drizzleService.db
15        .insert(databaseSchema.articles)
16        .values({
17          authorId,
18          title: article.title,
19          paragraphs: article.paragraphs,
20        })
21        .returning();
22 
23      return createdArticles.pop();
24    } catch (error) {
25      if (!isDatabaseError(error)) {
26        throw error;
27      }
28      if (error.code === PostgresErrorCode.NotNullViolation) {
29        throw new BadRequestException(
30          `The value of ${error.column} can not be null`,
31        );
32      }
33      if (error.code === PostgresErrorCode.CheckViolation) {
34        throw new BadRequestException('The title can not be an empty string');
35      }
36      throw error;
37    }
38  }
39 
40  // ...
41}

Updating existing records

The most straightforward way of modifying an array is to provide a brand-new one, even if we want to change only some elements.

1await this.drizzleService.db
2  .update(databaseSchema.articles)
3  .set({
4    title: 'My article',
5    paragraphs: [
6      'New first paragraph',
7      'Second paragraph'
8    ],
9  })
10  .where(eq(databaseSchema.articles.id, id))
11  .returning();

Aside from allowing us to set the entire array’s contents when modifying it, PostgreSQL provides various functions. However, we need to write raw SQL to achieve that.

For example, using array_append, we can add a new element at the end of an existing array.

1await this.drizzleService.db
2  .update(databaseSchema.articles)
3  .set({
4    title: 'My article',
5    paragraphs: sql`array_append(${databaseSchema.articles.paragraphs}, ${'Final paragraph'})`,
6  })
7  .where(eq(databaseSchema.articles.id, id))
8  .returning();
The sql tagged template is imported from the drizzle-orm library. If you want to know more about tagged templates, check out Concatenating strings with template literals. Tagged templates

Similarly, the array_prepend function adds an element to the beginning of the array.

1await this.drizzleService.db
2  .update(databaseSchema.articles)
3  .set({
4    title: 'My article',
5    paragraphs: sql`array_prepend(${databaseSchema.articles.paragraphs}, ${'Initial paragraph'})`,
6  })
7  .where(eq(databaseSchema.articles.id, id))
8  .returning();

With the trim_array function, we can remove a particular number of elements from the end of an array. For example, let’s use it to delete the last element.

1await this.drizzleService.db
2  .update(databaseSchema.articles)
3  .set({
4    title: 'My article',
5    paragraphs: sql`trim_array(${databaseSchema.articles.paragraphs}, 1)`,
6  })
7  .where(eq(databaseSchema.articles.id, id))
8  .returning();

Searching through arrays

With PostgreSQL, we can search through arrays with the ALL and ANY operators.

For example, we can find articles where all paragraphs equal a particular string using the ALL keyword.

1this.drizzleService.db
2  .select()
3  .from(databaseSchema.articles)
4  .where(
5    sql`
6      ${'Lorem ipsum'} = ALL(${databaseSchema.articles.paragraphs})
7    `,
8  );

What might be more practical is that we can use the ANY operator to get the articles where any paragraph equals a particular string.

1this.drizzleService.db
2  .select()
3  .from(databaseSchema.articles)
4  .where(
5    sql`
6      ${'Lorem ipsum'} = ANY(${databaseSchema.articles.paragraphs})
7    `,
8  );

In addition to the above, we can use the array_length function to filter the records based on the number of elements in the array. For example, we can find all articles with at least one paragraph.

1this.drizzleService.db
2  .select()
3  .from(databaseSchema.articles)
4  .where(
5    sql`
6      array_length(${databaseSchema.articles.paragraphs}, 1) > 1
7    `,
8  );
With the second argument of the array_length function we specify which dimension of the array we want to measure. It can be useful for multi-dimensional arrays.

Summary

In this article, we explored the use of array columns and implemented examples using the Drizzle ORM. Array columns can store multiple related values within a single column in PostgreSQL, aided by built-in functions and operators for various tasks. Unfortunately, though, arrays aren’t always the best solution.

Indexing and querying arrays can be inefficient with large datasets. In such cases, creating a separate table and defining relationships might be a better approach, especially if we want to enforce specific data constraints. Evaluating your application’s needs and weighing the advantages and disadvantages before opting for array columns in PostgreSQL is crucial. However, having an extra tool in your toolbox is always beneficial.