Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat: postgres schema #395

Closed
wants to merge 7 commits into from
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
33 changes: 33 additions & 0 deletions packages/db/cargo-fdw.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,33 @@
CREATE EXTENSION IF NOT EXISTS postgres_fdw;

CREATE SERVER dagcargo
FOREIGN DATA WRAPPER postgres_fdw
OPTIONS (host '{CARGO_HOST}', port '5432', dbname '{CARGO_DB_NAME}', fetch_size '50000');

CREATE USER MAPPING FOR {DB_USER}
SERVER dagcargo
OPTIONS (user '{CARGO_USER}', password '{CARGO_PASSWORD}');

-- Import foreign data into the cargo schema, create materialized views in
-- public schema.
CREATE SCHEMA cargo;

IMPORT FOREIGN SCHEMA cargo
LIMIT TO (deals, aggregates, aggregate_entries)
FROM SERVER dagcargo
INTO cargo;

-- Singular table names to retain consistency with our schema.
CREATE MATERIALIZED VIEW public.deal
AS SELECT * FROM cargo.deals

CREATE MATERIALIZED VIEW public.aggregate
AS SELECT * FROM cargo.aggregates

CREATE MATERIALIZED VIEW public.aggregate_entry
AS SELECT * FROM cargo.aggregate_entries

-- -- Later:
-- REFRESH MATERIALIZED VIEW public.deal
-- REFRESH MATERIALIZED VIEW public.aggregate
-- REFRESH MATERIALIZED VIEW public.aggregate_entry
77 changes: 77 additions & 0 deletions packages/db/tables.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,77 @@
CREATE TYPE public.pin_status AS ENUM (
'Queued',
'Pinning',
'Pinned',
'Failed'
);

CREATE TYPE public.service AS ENUM (
'Pinata',
'IpfsCluster'
);

CREATE TYPE public.upload_type AS ENUM (
'Car',
'Blob',
'Multipart',
'Remote',
'NFT'
);

CREATE TABLE IF NOT EXISTS public.user (
id BIGSERIAL PRIMARY KEY,
magic_link_id TEXT,
github_id TEXT,
name TEXT NOT NULL,
picture TEXT,
github TEXT,
email TEXT NOT NULL,
public_address TEXT NOT NULL UNIQUE,
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
);

CREATE TABLE IF NOT EXISTS public.auth_key (
id BIGSERIAL PRIMARY KEY,
name TEXT NOT NULL,
secret TEXT NOT NULL,
user_id BIGINT NOT NULL REFERENCES public.user ( id ),
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
);

CREATE TABLE IF NOT EXISTS public.content (
-- normalized base32 v1
cid TEXT PRIMARY KEY,
dag_size BIGINT,
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
);

CREATE TABLE IF NOT EXISTS public.pin (
id BIGSERIAL PRIMARY KEY,
status pin_status NOT NULL,
content_cid TEXT NOT NULL REFERENCES public.content ( cid ),
service public.service NOT NULL,
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,
UNIQUE (content_cid, service)
);

CREATE TABLE IF NOT EXISTS public.upload (
id BIGSERIAL PRIMARY KEY,
user_id BIGINT NOT NULL REFERENCES public.user ( id ),
auth_key_id BIGINT REFERENCES public.auth_key ( id ),
source_cid TEXT NOT NULL,
content_cid TEXT NOT NULL REFERENCES public.content ( cid ),
name TEXT,
type public.upload_type NOT NULL,
-- MIME type of the upload data as sent in the request.
mime_type TEXT,
files jsonb,
origins jsonb,
meta jsonb,
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 DEFAULT timezone('utc'::text, now())
);