- 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
Relational databases such as PostgreSQL are great for storing structured data. This approach has many advantages, but it can lack flexibility. On the other hand, databases such as MongoDB that store JSON-like documents might give you more flexibility than you would like. Fortunately, PostgreSQL offers support for storing and querying loosely-structured JSON data. This article explores the features and benefits of using the JSON and JSONB columns.
Using the json column type
The first column type to look into is JSON. It stores the provided data as is in a text format.
1 2 3 4 5 |
CREATE TABLE products ( id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, name text NOT NULL, properties json ) |
When we insert data, PostgreSQL ensures that it is a valid JSON. If not, it throws an error.
1 2 3 4 5 6 7 8 |
INSERT INTO products ( name, properties ) VALUES ( 'Introduction to Algorithms', '{ "publicationYear": 1990, "authors": ["Thomas H. Cormen", "Charles E. Leiserson", "Ronald L. Rivest", "Clifford Stein"] }' ) |
Above, we’ve added our first record to the products column. Since it is a book, it has the publication year and a list of authors. Thanks to using a JSON column, we don’t need to add the publication_year and authors columns to our table. Since the properties column is flexible, we can use it to store any product.
1 2 3 4 5 6 7 8 |
INSERT INTO products ( name, properties ) VALUES ( 'A8', '{ "brand": "Audi", "engine": { "numberOfCylinders": 6, "fuel": "petrol" } }' ) |
When working with PostgreSQL, we can make parts of our data flexible while putting constraints on other columns. For example, we could add the category_id column to group our products.
If we would only have two types of products, it would make sense to create separate books and cars tables. However, it would get complicated if we had tens of different product types.
Defining a json column with Prisma
To add the json column with Prisma, we need the @db.Json annotation.
productSchema.prisma
1 2 3 4 5 |
model Product { id Int @id @default(autoincrement()) name String properties Json? @db.Json } |
Creating the above schema and generating a migration yields the following result:
migrations/20230523001250_products/migration.sql
1 2 3 4 5 6 7 8 |
-- CreateTable CREATE TABLE "Product" ( "id" SERIAL NOT NULL, "name" TEXT NOT NULL, "properties" JSON, CONSTRAINT "Product_pkey" PRIMARY KEY ("id") ); |
It’s crucial to acknowledge that when inserting values into a json column, Prisma expects us to provide the data matching the InputJsonValue interface. When we look under the hood of Prisma, we can see that it includes any valid JSON value.
1 |
export type InputJsonValue = string | number | boolean | InputJsonObject | InputJsonArray |
Since we want properties to be an object, we need to enforce the InputJsonObject interface built into Prisma.
createProduct.dto.ts
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 |
import { Prisma } from '@prisma/client'; import { IsString, IsNotEmpty, IsOptional } from 'class-validator'; import IsJsonObject from '../../utils/isJsonObject'; export class CreateProductDto { @IsString() @IsNotEmpty() name: string; @IsJsonObject() @IsOptional() properties?: Prisma.InputJsonObject; } export default CreateProductDto; |
To achieve the above with the class-validator library, we need to create a custom decorator that checks if the provided value is a valid object.
isJsonObject.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 { registerDecorator, ValidationArguments } from 'class-validator'; function IsJsonObject() { return function (object: object, propertyName: string) { registerDecorator({ name: 'isJsonObject', target: object.constructor, propertyName: propertyName, validator: { validate(value: unknown) { return ( typeof value === 'object' && value !== null && !Array.isArray(value) ); }, defaultMessage(validationArguments?: ValidationArguments): string { return `${validationArguments.property} must be a valid object`; }, }, }); }; } export default IsJsonObject; |
Thanks to all of the above, we can now insert JSON data through an API created with NestJS.
Handling null values
Our properties column is nullable and does not need to contain any value. Unfortunately, this can cause confusion because the JSON format can store a null value.
1 |
JSON.stringify(null); // 'null' |
To differentiate between null as a lack of value in the database and as a null value stored in the json column, Prisma introduced the Prisma.JsonNull and Prisma.DbNull constants.
Let’s assume that whenever the user sends null as the value for our properties column, they want to remove the data from the column altogether. To achieve that, we need Prisma.DbNull.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 |
async updateProduct(id: number, product: UpdateProductDto) { try { return await this.prismaService.product.update({ data: { ...product, id: undefined, properties: product.properties ?? Prisma.DbNull, }, where: { id, }, }); } catch (error) { if ( error instanceof PrismaClientKnownRequestError && error.code === PrismaError.RecordDoesNotExist ) { throw new NotFoundException(); } throw error; } } |
Manipulating the JSON data
PostgreSQL is equipped with quite a few different operators that help us query JSON data. One of the most important ones is ->>, which allows us to get a value of a particular property as text.
1 2 |
SELECT * FROM "Product" WHERE (properties->>'publicationYear')::int < 2000 |
We can achieve the same thing with Prisma thanks to the path option.
1 2 3 4 5 6 7 8 |
this.prismaService.product.findMany({ where: { properties: { path: ['publicationYear'], lt: 2000, }, }, }); |
We can access nested properties by providing the path array with multiple strings such as ['user', 'address', 'street']
Prisma offers a wide variety of filters besides the lt filter, which means “less than”.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 |
export type JsonNullableFilterBase = { equals?: InputJsonValue | JsonNullValueFilter path?: string[] string_contains?: string string_starts_with?: string string_ends_with?: string array_contains?: InputJsonValue | null array_starts_with?: InputJsonValue | null array_ends_with?: InputJsonValue | null lt?: InputJsonValue lte?: InputJsonValue gt?: InputJsonValue gte?: InputJsonValue not?: InputJsonValue | JsonNullValueFilter } |
The jsonb column
The json column type offers fast insertion because the data we store in the database is stored as text. But, unfortunately, PostgreSQL has to parse the value whenever we perform operations on it, and it causes a performance hit.
To deal with the above issue, PostgreSQL introduced the jsonb column type, which stands for “JSON Binary”. Whenever we store data in the jsonb column, PostgreSQL parses our JSON into a binary format. While this can cause the INSERT operations to be slightly slower, it significantly improves the querying performance. It also doesn’t preserve whitespaces and the order of properties.
Besides the performance improvements the jsonb column provides, it also gives us more operators we can use. It also provides us with additional indexing capabilities.
1 2 3 4 5 |
CREATE TABLE products ( id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, name text NOT NULL, properties json ) |
To create a jsonb column with Prisma, we can use the @db.JsonB annotation.
productSchema.prisma
1 2 3 4 5 |
model Product { id Int @id @default(autoincrement()) name String properties Json? @db.JsonB } |
Since jsonb is the default column used for storing JSON in Prisma we can omit using the @db.JsonB annotation.
Creating the above schema and generating the migration gives us the following code:
migrations/20230524030331_products/migration.sql
1 2 3 4 5 6 7 |
CREATE TABLE "Product" ( "id" SERIAL NOT NULL, "name" TEXT NOT NULL, "properties" JSONB, CONSTRAINT "Product_pkey" PRIMARY KEY ("id") ); |
Using the jsonb column gives us all of the functionalities of the json type and more.
Summary
In this article, we’ve gone through storing JSON in a PostgreSQL database through raw SQL and Prisma. We also compared the json and jsonb column types. While the above approach gives us a lot of flexibility, it forces us to give up some of the benefits of relational databases. Therefore, we should avoid overusing it and think twice before choosing it as our solution.