Skip to content

Commit

Permalink
feat: implement postgres optimization (#1305)
Browse files Browse the repository at this point in the history
* Refactor backups
* Add db migration scripts
* Update db configuration
  • Loading branch information
francois-potato authored May 27, 2022
1 parent 27ca9c2 commit 2cd6105
Show file tree
Hide file tree
Showing 12 changed files with 145 additions and 195 deletions.
9 changes: 2 additions & 7 deletions packages/db/db-client-types.ts
Original file line number Diff line number Diff line change
Expand Up @@ -119,12 +119,7 @@ export type PinSyncRequestOutput = {
}

// Backup
export type BackupOutput = {
_id: string
created: definitions['backup']['inserted_at']
url: definitions['backup']['url']
uploadId: definitions['backup']['upload_id']
}
export type BackupOutput = definitions['upload']['backup_urls']

// Deal
export type Deal = {
Expand Down Expand Up @@ -186,7 +181,7 @@ export interface CreateUploadInput {
status: definitions['pin']['status']
location: Location
}>,
backupUrls: Array<definitions['backup']['url']>
backupUrls: definitions['upload']['backup_urls']
}

export type CreateUploadOutput = {
Expand Down
21 changes: 10 additions & 11 deletions packages/db/index.js
Original file line number Diff line number Diff line change
Expand Up @@ -392,6 +392,7 @@ export class DBClient {
*/
async createUpload (data) {
const now = new Date().toISOString()

/** @type {{ data: string, error: PostgrestError }} */
const { data: uploadResponse, error } = await this._client.rpc('create_upload', {
data: {
Expand Down Expand Up @@ -603,22 +604,20 @@ export class DBClient {
* @return {Promise<Array<import('./db-client-types').BackupOutput>>}
*/
async getBackups (uploadId) {
/** @type {{ data: Array<definitions['backup']>, error: PostgrestError }} */
const { data: backups, error } = await this._client
.from('backup')
.select(`
_id:id::text,
created:inserted_at,
uploadId:upload_id::text,
url
`)
.match({ upload_id: uploadId })
/** @type {{ data: {backupUrls: definitions['upload']['backup_urls']}, error: PostgrestError }} */
const { data: { backupUrls }, error } = await this._client
.from('upload')
.select('backupUrls:backup_urls')
.eq('id', uploadId)
.single()

if (error) {
throw new DBError(error)
}

return backups
const uniqueUrls = new Set(backupUrls)

return Array.from(uniqueUrls)
}

/**
Expand Down
18 changes: 17 additions & 1 deletion packages/db/postgres/config.sql
Original file line number Diff line number Diff line change
@@ -1 +1,17 @@
SET max_parallel_workers_per_gather TO 4;
SET max_parallel_workers_per_gather TO 4;
-- PG doesn't support ALTER DATABASE CURRENT, and the db name is different between local/staging/production
-- So we have to execute using variable subsitution
DO $$
BEGIN
EXECUTE 'ALTER DATABASE ' || current_database() || ' SET default_statistics_target = 1000';
EXECUTE 'ALTER DATABASE ' || current_database() || ' SET enable_partitionwise_aggregate = on';
EXECUTE 'ALTER DATABASE ' || current_database() || ' SET enable_partitionwise_join = on';
EXECUTE 'ALTER DATABASE ' || current_database() || ' SET max_parallel_workers_per_gather = 8';
EXECUTE 'ALTER DATABASE ' || current_database() || ' SET max_parallel_workers = 16';
EXECUTE 'ALTER DATABASE ' || current_database() || ' SET max_parallel_maintenance_workers = 8';
EXECUTE 'ALTER DATABASE ' || current_database() || ' SET jit = on';
EXECUTE 'ALTER DATABASE ' || current_database() || ' SET idle_in_transaction_session_timeout = ''1min''';
EXECUTE 'ALTER DATABASE ' || current_database() || ' SET lock_timeout = ''1min''';
EXECUTE 'ALTER DATABASE ' || current_database() || ' SET statement_timeout = ''30s''';
END
$$;
12 changes: 8 additions & 4 deletions packages/db/postgres/docker/docker-compose.yml
Original file line number Diff line number Diff line change
Expand Up @@ -17,12 +17,16 @@ services:
db:
build:
context: ./postgres
deploy:
resources:
limits:
cpus: '2'
memory: 2G
reservations:
cpus: '1'
memory: 1G
ports:
- 5432:5432
command:
- postgres
- -c
- wal_level=logical
environment:
POSTGRES_DB: postgres
POSTGRES_USER: postgres
Expand Down
7 changes: 5 additions & 2 deletions packages/db/postgres/docker/postgres/Dockerfile
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
FROM supabase/postgres:0.13.0
FROM supabase/postgres:13.3.0

COPY 00-initial-schema.sql /docker-entrypoint-initdb.d/00-initial-schema.sql

Expand All @@ -8,4 +8,7 @@ ENV POSTGRES_USER=postgres
ENV POSTGRES_PASSWORD=postgres
ENV POSTGRES_PORT=5432

EXPOSE 5432
EXPOSE 5432

# Enables cat /var/lib/postgresql/data/pg_log/postgresql.log within the container to debug queries
CMD ["postgres", "-c", "wal_level=logical", "-c", "log_statement=all", "-c", "pg_stat_statements.track=all"]
25 changes: 8 additions & 17 deletions packages/db/postgres/functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -120,48 +120,39 @@ CREATE OR REPLACE FUNCTION create_upload(data json) RETURNS TEXT
AS
$$
DECLARE
backup_url TEXT;
inserted_upload_id BIGINT;

BEGIN
-- Set timeout as imposed by heroku
SET LOCAL statement_timeout = '30s';

PERFORM create_content(data);

insert into upload (user_id,
insert into upload as upld (user_id,
auth_key_id,
content_cid,
source_cid,
type,
name,
inserted_at,
updated_at)
updated_at,
backup_urls)
values ((data ->> 'user_id')::BIGINT,
(data ->> 'auth_key_id')::BIGINT,
data ->> 'content_cid',
data ->> 'source_cid',
(data ->> 'type')::upload_type,
data ->> 'name',
(data ->> 'inserted_at')::timestamptz,
(data ->> 'updated_at')::timestamptz)
(data ->> 'updated_at')::timestamptz,
json_arr_to_text_arr(data -> 'backup_urls'))
ON CONFLICT ( user_id, source_cid ) DO UPDATE
SET "updated_at" = (data ->> 'updated_at')::timestamptz,
"name" = data ->> 'name',
"deleted_at" = null
"deleted_at" = null,
"backup_urls" = upld.backup_urls || json_arr_to_text_arr(data -> 'backup_urls')
returning id into inserted_upload_id;

foreach backup_url in array json_arr_to_text_arr(data -> 'backup_urls')
loop
-- insert into backup with update
insert into backup (upload_id,
url,
inserted_at)
values (inserted_upload_id,
backup_url,
(data ->> 'inserted_at')::timestamptz)
ON CONFLICT ( upload_id, url ) DO NOTHING;
end loop;

return (inserted_upload_id)::TEXT;
END
$$;
Expand Down
1 change: 1 addition & 0 deletions packages/db/postgres/migrations/008-add-backup-urls.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
ALTER TABLE "upload" ADD COLUMN IF NOT EXISTS "backup_urls" TEXT[];
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
UPDATE "upload" SET "backup_urls" = (SELECT array_agg("url") FROM "backup" WHERE "upload_id" = "upload"."id");
131 changes: 4 additions & 127 deletions packages/db/postgres/pg-rest-api-types.d.ts
Original file line number Diff line number Diff line change
Expand Up @@ -259,102 +259,6 @@ export interface paths {
};
};
};
"/backup": {
get: {
parameters: {
query: {
id?: parameters["rowFilter.backup.id"];
upload_id?: parameters["rowFilter.backup.upload_id"];
url?: parameters["rowFilter.backup.url"];
inserted_at?: parameters["rowFilter.backup.inserted_at"];
/** Filtering Columns */
select?: parameters["select"];
/** Ordering */
order?: parameters["order"];
/** Limiting and Pagination */
offset?: parameters["offset"];
/** Limiting and Pagination */
limit?: parameters["limit"];
};
header: {
/** Limiting and Pagination */
Range?: parameters["range"];
/** Limiting and Pagination */
"Range-Unit"?: parameters["rangeUnit"];
/** Preference */
Prefer?: parameters["preferCount"];
};
};
responses: {
/** OK */
200: {
schema: definitions["backup"][];
};
/** Partial Content */
206: unknown;
};
};
post: {
parameters: {
body: {
/** backup */
backup?: definitions["backup"];
};
query: {
/** Filtering Columns */
select?: parameters["select"];
};
header: {
/** Preference */
Prefer?: parameters["preferReturn"];
};
};
responses: {
/** Created */
201: unknown;
};
};
delete: {
parameters: {
query: {
id?: parameters["rowFilter.backup.id"];
upload_id?: parameters["rowFilter.backup.upload_id"];
url?: parameters["rowFilter.backup.url"];
inserted_at?: parameters["rowFilter.backup.inserted_at"];
};
header: {
/** Preference */
Prefer?: parameters["preferReturn"];
};
};
responses: {
/** No Content */
204: never;
};
};
patch: {
parameters: {
query: {
id?: parameters["rowFilter.backup.id"];
upload_id?: parameters["rowFilter.backup.upload_id"];
url?: parameters["rowFilter.backup.url"];
inserted_at?: parameters["rowFilter.backup.inserted_at"];
};
body: {
/** backup */
backup?: definitions["backup"];
};
header: {
/** Preference */
Prefer?: parameters["preferReturn"];
};
};
responses: {
/** No Content */
204: never;
};
};
};
"/content": {
get: {
parameters: {
Expand Down Expand Up @@ -2123,27 +2027,6 @@ export interface definitions {
/** Format: timestamp with time zone */
deleted_at?: string;
};
backup: {
/**
* Format: bigint
* @description Note:
* This is a Primary Key.<pk/>
*/
id: number;
/**
* Format: bigint
* @description Note:
* This is a Foreign Key to `upload.id`.<fk table='upload' column='id'/>
*/
upload_id: number;
/** Format: text */
url: string;
/**
* Format: timestamp with time zone
* @default timezone('utc'::text, now())
*/
inserted_at: string;
};
content: {
/**
* Format: text
Expand Down Expand Up @@ -2429,6 +2312,10 @@ export interface definitions {
updated_at: string;
/** Format: timestamp with time zone */
deleted_at?: string;
/**
* Format: created is a timestamp with time zone
*/
backup_urls: string[];
};
user: {
/**
Expand Down Expand Up @@ -2561,16 +2448,6 @@ export interface parameters {
"rowFilter.auth_key_history.inserted_at": string;
/** Format: timestamp with time zone */
"rowFilter.auth_key_history.deleted_at": string;
/** @description backup */
"body.backup": definitions["backup"];
/** Format: bigint */
"rowFilter.backup.id": string;
/** Format: bigint */
"rowFilter.backup.upload_id": string;
/** Format: text */
"rowFilter.backup.url": string;
/** Format: timestamp with time zone */
"rowFilter.backup.inserted_at": string;
/** @description content */
"body.content": definitions["content"];
/** Format: text */
Expand Down
5 changes: 4 additions & 1 deletion packages/db/postgres/reset.sql
Original file line number Diff line number Diff line change
Expand Up @@ -18,4 +18,7 @@ DROP SCHEMA IF EXISTS cargo CASCADE;
DROP SERVER IF EXISTS dag_cargo_server CASCADE;
DROP MATERIALIZED VIEW IF EXISTS public.aggregate_entry CASCADE;
DROP MATERIALIZED VIEW IF EXISTS public.deal CASCADE;
DROP MATERIALIZED VIEW IF EXISTS public.aggregate CASCADE;
DROP MATERIALIZED VIEW IF EXISTS public.aggregate CASCADE;

-- Reset settings from config.sql
ALTER DATABASE postgres RESET ALL;
15 changes: 1 addition & 14 deletions packages/db/postgres/tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -223,6 +223,7 @@ CREATE TABLE IF NOT EXISTS upload
type upload_type NOT NULL,
-- User provided name for this upload.
name TEXT,
backup_urls TEXT[],
inserted_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL,
deleted_at TIMESTAMP WITH TIME ZONE,
Expand All @@ -233,20 +234,6 @@ CREATE INDEX IF NOT EXISTS upload_auth_key_id_idx ON upload (auth_key_id);
CREATE INDEX IF NOT EXISTS upload_content_cid_idx ON upload (content_cid);
CREATE INDEX IF NOT EXISTS upload_updated_at_idx ON upload (updated_at);

-- Details of the backups created for an upload.
CREATE TABLE IF NOT EXISTS backup
(
id BIGSERIAL PRIMARY KEY,
-- Upload that resulted in this backup.
upload_id BIGINT NOT NULL REFERENCES upload (id) ON DELETE CASCADE,
-- Backup url location.
url TEXT NOT NULL,
inserted_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL,
UNIQUE (upload_id, url)
);

CREATE INDEX IF NOT EXISTS backup_upload_id_idx ON backup (upload_id);

-- Tracks requests to replicate content to more nodes.
CREATE TABLE IF NOT EXISTS pin_request
(
Expand Down
Loading

0 comments on commit 2cd6105

Please sign in to comment.