When designing a database, the tables we define often relate to each other. Managing those relationships is one of the essential parts of working with databases. The previous article taught us how to use raw SQL queries to set up our NestJS project to work with PostgreSQL. In this article, we go a step further and start writing more complex SQL queries involving the one-to-one relationship.
You can find the code from this article in this repository.
The idea behind one-to-one relationship
When designing a one-to-one relationship, a row from the first table has one matching row from the second table and the other way around.
In our case, the address is optional. A one-to-one relationship that is optional might be also referred to as one-to-zero-or-one relationship.
Instead of creating the addresses table, we could add the address_street, address_city, and address_country to the users table. However, as the table grows, it might sometimes make sense to split it into more than one table if we can separate a particular group of columns. This might not be the most popular type of relationship, but we might encounter it when working with various databases. Because of that, we go through how to set it up and work with it.
When deciding on whether to create a one-to-one relationship we can take a lot of factors into consideration. If you want to read more, check out this question on StackOverflow.
Working with a one-to-one relationship
A very straightforward example involves a user and an address. Let’s start by creating a new migration to define the addresses table and connect it to the users.
1import { Knex } from 'knex';
2
3export async function up(knex: Knex): Promise<void> {
4 return knex.raw(`
5 CREATE TABLE addresses (
6 id int GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
7 street text,
8 city text,
9 country text
10 );
11 ALTER TABLE users
12 ADD COLUMN address_id int UNIQUE REFERENCES addresses(id);
13 `);
14}
15
16export async function down(knex: Knex): Promise<void> {
17 return knex.raw(`
18 DROP TABLE addresses;
19 ALTER TABLE users
20 DROP COLUMN address_id;
21 `);
22}Above, we add the address_id column to the users table. In our application, a particular address can belong only to one user. Because of that, we add the unique constraint to the address_id column. When we do that, we ensure that only one user can refer to a particular address. Trying to tie more than one user to the same address would result in an error.
We also make the address_id column a foreign key that refers to the primary key of the addresses table. Thanks to that, we make sure that PostgreSQL knows there is a connection.
Inserting two entities in a single query
We want to be able to insert the user and the address into the database at the same time. A good way to do that is by using the WITH statement.
1import { Injectable } from '@nestjs/common';
2import DatabaseService from '../database/database.service';
3import { plainToInstance } from 'class-transformer';
4import UserModel from './user.model';
5import { CreateUserDto } from './dto/createUser.dto';
6import isRecord from '../utils/isRecord';
7import PostgresErrorCode from '../database/postgresErrorCode.enum';
8import UserAlreadyExistsException from './exceptions/userAlreadyExists.exception';
9
10@Injectable()
11class UsersRepository {
12 constructor(private readonly databaseService: DatabaseService) {}
13
14 private async createUserWithAddress(userData: CreateUserDto) {
15 try {
16 const databaseResponse = await this.databaseService.runQuery(
17 `
18 WITH created_address AS (
19 INSERT INTO addresses (
20 street,
21 city,
22 country
23 ) VALUES (
24 $1,
25 $2,
26 $3
27 ) RETURNING *
28 )
29 INSERT INTO users (
30 email,
31 name,
32 password,
33 address_id
34 ) VALUES (
35 $4,
36 $5,
37 $6,
38 (SELECT id FROM created_address)
39 ) RETURNING *
40 `,
41 [
42 userData.address.street,
43 userData.address.city,
44 userData.address.country,
45 userData.email,
46 userData.name,
47 userData.password,
48 ],
49 );
50 return new UserModel(databaseResponse.rows[0]);
51 } catch (error) {
52 if (isRecord(error) && error.code === PostgresErrorCode.UniqueViolation) {
53 throw new UserAlreadyExistsException(userData.email);
54 }
55 throw error;
56 }
57 }
58
59 async create(userData: CreateUserDto) {
60 if (userData.address) {
61 return this.createUserWithAddress(userData);
62 }
63 // ...
64 }
65
66 // ...
67}
68
69export default UsersRepository;In this article, we use authentication with JWT. If you want to know more, check out API with NestJS #3. Authenticating users with bcrypt, Passport, JWT, and cookies
Above, we create a Common Table Expression query using the WITH statement. Thanks to that, we create both the address and the user in a single SQL that is atomic. If something goes wrong when creating the user, the address won’t be persisted in the database.
Expanding the models
As our queries get more complex, the models grow bigger too. So let’s first create a model for the address.
1interface AddressModelData {
2 id: number;
3 street: string;
4 city: string;
5 country: string;
6}
7class AddressModel {
8 id: number;
9 street: string;
10 city: string;
11 country: string;
12 constructor(data: AddressModelData) {
13 this.id = data.id;
14 this.street = data.street;
15 this.city = data.city;
16 this.country = data.country;
17 }
18}
19
20export default AddressModel;Above, I create the model and define the constructor manually. You can use the class-transformer library for that, if you prefer.
The last step in creating the models is to use the above class in the model of the user.
1import { Exclude } from 'class-transformer';
2import AddressModel from './address.model';
3
4type UserModelData = {
5 id: number;
6 name: number;
7 email: string;
8 password: string;
9 address_id?: number;
10 address_street?: string;
11 address_city?: string;
12 address_country?: string;
13};
14class UserModel {
15 id: number;
16 name: number;
17 email: string;
18 @Exclude()
19 password: string;
20 address?: AddressModel;
21
22 constructor(data: UserModelData) {
23 this.id = data.id;
24 this.name = data.name;
25 this.email = data.email;
26 this.password = data.password;
27 if (data.address_id) {
28 this.address = new AddressModel({
29 id: data.address_id,
30 street: data.address_street,
31 city: data.address_city,
32 country: data.address_country,
33 });
34 }
35 }
36}
37
38export default UserModel;Querying two tables
Our queries can fetch rows from multiple tables at once and match them. A good way of doing that is with a JOIN query.
1SELECT users.*,
2 addresses.street as address_street, addresses.city as address_city, addresses.country as address_country
3 FROM users
4 JOIN addresses ON users.address_id = addresses.id
5 WHERE email=$1When we use the JOIN keyword, we perform the inner join. The crucial thing is that it returns records with matching values in both tables. In our case, the address is optional. Running the above query for a user that does not have the address would return nothing.
To fix the issue, we need to perform the outer join. Outer joins preserve the rows that don’t have matching values. In our case, we want to use the LEFT JOIN that returns all records from the left table and the matched records from the right table. In our case, the left table is users, and the right table is the addresses.
1import { Injectable, NotFoundException } from '@nestjs/common';
2import DatabaseService from '../database/database.service';
3import UserModel from './user.model';
4
5@Injectable()
6class UsersRepository {
7 constructor(private readonly databaseService: DatabaseService) {}
8
9 async getByEmail(email: string) {
10 const databaseResponse = await this.databaseService.runQuery(
11 `
12 SELECT users.*,
13 addresses.street as address_street, addresses.city as address_city, addresses.country as address_country
14 FROM users
15 LEFT JOIN addresses ON users.address_id = addresses.id
16 WHERE email=$1
17 `,
18 [email],
19 );
20 const entity = databaseResponse.rows[0];
21 if (!entity) {
22 throw new NotFoundException();
23 }
24 return new UserModel(entity);
25 }
26}
27
28export default UsersRepository;Thanks to the above approach, our query works correctly for users that don’t have the address.
Returning the related entity when inserting
Before, we used the WITH statement to create the user and the address in a single query. We can use two WITH statements to return the data from both tables.
1import { Injectable } from '@nestjs/common';
2import DatabaseService from '../database/database.service';
3import UserModel from './user.model';
4import { CreateUserDto } from './dto/createUser.dto';
5import isRecord from '../utils/isRecord';
6import PostgresErrorCode from '../database/postgresErrorCode.enum';
7import UserAlreadyExistsException from './exceptions/userAlreadyExists.exception';
8
9@Injectable()
10class UsersRepository {
11 constructor(private readonly databaseService: DatabaseService) {}
12
13 private async createUserWithAddress(userData: CreateUserDto) {
14 try {
15 const databaseResponse = await this.databaseService.runQuery(
16 `
17 WITH created_address AS (
18 INSERT INTO addresses (
19 street,
20 city,
21 country
22 ) VALUES (
23 $1,
24 $2,
25 $3
26 ) RETURNING *
27 ),
28 created_user AS (
29 INSERT INTO users (
30 email,
31 name,
32 password,
33 address_id
34 ) VALUES (
35 $4,
36 $5,
37 $6,
38 (SELECT id FROM created_address)
39 ) RETURNING *
40 )
41 SELECT created_user.id AS id, created_user.email AS email, created_user.name AS name, created_user.password AS password,
42 created_address.id AS address_id, street AS address_street, city AS address_city, country AS address_country
43 FROM created_user, created_address
44 `,
45 [
46 userData.address.street,
47 userData.address.city,
48 userData.address.country,
49 userData.email,
50 userData.name,
51 userData.password,
52 ],
53 );
54 return new UserModel(databaseResponse.rows[0]);
55 } catch (error) {
56 if (isRecord(error) && error.code === PostgresErrorCode.UniqueViolation) {
57 throw new UserAlreadyExistsException(userData.email);
58 }
59 throw error;
60 }
61 }
62
63 // ...
64}
65
66export default UsersRepository;Thanks to the above, our API returns the user together with the address when signing up.
Summary
In this article, we’ve gone through the idea behind one-to-one relationships. We’ve also learned to work with them using PostgreSQL and raw SQL queries. When doing that, we had to write common table expressions to make sure we created two entities in a single query. We’ve also identified the difference between inner and outer joins. There is still much to learn regarding relationships in PostgreSQL, so stay tuned!