-
Notifications
You must be signed in to change notification settings - Fork 167
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
1 parent
02975bf
commit 922b881
Showing
29 changed files
with
1,173 additions
and
199 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,42 @@ | ||
CREATE SCHEMA IF NOT EXISTS cargo; | ||
|
||
-- Import dag cargo schema | ||
IMPORT FOREIGN SCHEMA cargo | ||
LIMIT TO (aggregate_entries, aggregates, deals) | ||
FROM SERVER dag_cargo_server | ||
INTO cargo; | ||
|
||
-- Create materialized view from cargo "aggregate_entries" table | ||
CREATE MATERIALIZED VIEW public.aggregate_entry | ||
AS | ||
SELECT * | ||
FROM cargo.aggregate_entries; | ||
|
||
-- Indexes for "aggregate_entries" mat view | ||
CREATE UNIQUE INDEX aggregate_entry_unique_cidv1_aggregate_cid | ||
ON public.aggregate_entry (aggregate_cid, cid_v1); | ||
CREATE INDEX aggregate_entry_cid_v1 | ||
ON public.aggregate_entry (cid_v1); | ||
|
||
-- Create materialized view from cargo "deals" table | ||
CREATE MATERIALIZED VIEW public.deal | ||
AS | ||
SELECT * | ||
FROM cargo.deals; | ||
|
||
-- Indexes for "deals" mat view | ||
CREATE UNIQUE INDEX deal_unique_deal_id | ||
ON public.deal (deal_id); | ||
CREATE INDEX deal_aggregate_cid | ||
ON public.deal (aggregate_cid); | ||
|
||
-- Create materialized view from cargo "aggregates" table | ||
CREATE MATERIALIZED VIEW public.aggregate | ||
AS | ||
SELECT * | ||
FROM cargo.aggregates; | ||
|
||
-- Indexes for "aggregate" mat view | ||
CREATE UNIQUE INDEX aggregate_unique_aggregate_cid | ||
ON public.aggregate (aggregate_cid); | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,28 @@ | ||
version: '3.6' | ||
services: | ||
rest: | ||
image: postgrest/postgrest:v8.0.0 | ||
depends_on: | ||
- db | ||
restart: always | ||
ports: | ||
- 3000:3000/tcp | ||
environment: | ||
PGRST_DB_URI: postgres://postgres:postgres@db:5432/postgres | ||
PGRST_DB_SCHEMA: public | ||
PGRST_DB_ANON_ROLE: postgres | ||
PGRST_JWT_SECRET: super-secret-jwt-token-with-at-least-32-characters-long | ||
db: | ||
build: | ||
context: ./postgres | ||
ports: | ||
- 5432:5432 | ||
command: | ||
- postgres | ||
- -c | ||
- wal_level=logical | ||
environment: | ||
POSTGRES_DB: postgres | ||
POSTGRES_USER: postgres | ||
POSTGRES_PASSWORD: postgres | ||
POSTGRES_PORT: 5432 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,40 @@ | ||
|
||
|
||
-- Set up reatime | ||
create publication supabase_realtime for all tables; | ||
|
||
-- Extension namespacing | ||
create schema extensions; | ||
create extension if not exists "uuid-ossp" with schema extensions; | ||
create extension if not exists pgcrypto with schema extensions; | ||
create extension if not exists pgjwt with schema extensions; | ||
|
||
-- Developer roles | ||
create role anon nologin noinherit; | ||
create role authenticated nologin noinherit; -- "logged in" user: web_user, app_user, etc | ||
create role service_role nologin noinherit bypassrls; -- allow developers to create JWT's that bypass their policies | ||
|
||
create user authenticator noinherit; | ||
grant anon to authenticator; | ||
grant authenticated to authenticator; | ||
grant service_role to authenticator; | ||
|
||
grant usage on schema public to postgres, anon, authenticated, service_role; | ||
alter default privileges in schema public grant all on tables to postgres, anon, authenticated, service_role; | ||
alter default privileges in schema public grant all on functions to postgres, anon, authenticated, service_role; | ||
alter default privileges in schema public grant all on sequences to postgres, anon, authenticated, service_role; | ||
|
||
-- Create an event trigger function | ||
CREATE OR REPLACE FUNCTION public.pgrst_watch() RETURNS event_trigger | ||
LANGUAGE plpgsql | ||
AS $$ | ||
BEGIN | ||
NOTIFY pgrst, 'reload schema'; | ||
END; | ||
$$; | ||
|
||
-- This event trigger will fire after every ddl_command_end event | ||
CREATE EVENT TRIGGER pgrst_watch | ||
ON ddl_command_end | ||
EXECUTE PROCEDURE public.pgrst_watch(); | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,11 @@ | ||
FROM supabase/postgres:0.13.0 | ||
|
||
COPY 00-initial-schema.sql /docker-entrypoint-initdb.d/00-initial-schema.sql | ||
|
||
# Run time values | ||
ENV POSTGRES_DB=postgres | ||
ENV POSTGRES_USER=postgres | ||
ENV POSTGRES_PASSWORD=postgres | ||
ENV POSTGRES_PORT=5432 | ||
|
||
EXPOSE 5432 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,22 @@ | ||
CREATE | ||
EXTENSION IF NOT EXISTS postgres_fdw; | ||
|
||
DROP | ||
SERVER IF EXISTS dag_cargo_server CASCADE; | ||
|
||
CREATE | ||
SERVER dag_cargo_server | ||
FOREIGN DATA WRAPPER postgres_fdw | ||
OPTIONS ( | ||
host :'DAG_CARGO_HOST', | ||
dbname :'DAG_CARGO_DATABASE', | ||
fetch_size '200000' | ||
); | ||
|
||
CREATE | ||
USER MAPPING FOR current_user | ||
SERVER dag_cargo_server | ||
OPTIONS ( | ||
user :'DAG_CARGO_USER', | ||
password :'DAG_CARGO_PASSWORD' | ||
); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,70 +1,102 @@ | ||
DROP FUNCTION IF EXISTS upload_fn; | ||
DROP FUNCTION IF EXISTS deals_fn; | ||
|
||
DROP TYPE IF EXISTS upload_pin_type; | ||
|
||
CREATE TYPE upload_pin_type AS ( | ||
status pin_status_type, | ||
service service_type | ||
CREATE TYPE upload_pin_type AS | ||
( | ||
status pin_status_type, | ||
service service_type | ||
); | ||
|
||
CREATE OR REPLACE FUNCTION upload_fn(data json) RETURNS setof upload | ||
LANGUAGE plpgsql | ||
volatile | ||
PARALLEL UNSAFE | ||
AS | ||
LANGUAGE plpgsql | ||
volatile | ||
PARALLEL UNSAFE | ||
AS | ||
$$ | ||
BEGIN | ||
|
||
insert into content (cid, dag_size) | ||
values ( | ||
data->>'content_cid', | ||
(data->>'dag_size')::BIGINT | ||
) | ||
insert into content (cid, dag_size) | ||
values (data ->> 'content_cid', | ||
(data ->> 'dag_size')::BIGINT) | ||
ON CONFLICT ( cid ) DO NOTHING; | ||
|
||
insert into pin (content_cid, status, service) | ||
select data->>'content_cid', status, service | ||
from json_populate_recordset(null::upload_pin_type, (data->>'pins')::json) | ||
insert into pin (content_cid, status, service) | ||
select data ->> 'content_cid', status, service | ||
from json_populate_recordset(null::upload_pin_type, (data ->> 'pins')::json) | ||
on conflict (content_cid, service) do nothing; | ||
|
||
insert into upload ( | ||
account_id, | ||
key_id, | ||
content_cid, | ||
source_cid, | ||
mime_type, | ||
type, | ||
name, | ||
files, | ||
origins, | ||
meta | ||
) values ( | ||
(data->>'account_id')::BIGINT, | ||
(data->>'key_id')::BIGINT, | ||
data->>'content_cid', | ||
data->>'source_cid', | ||
data->>'mime_type', | ||
(data->>'type')::upload_type, | ||
data->>'name', | ||
(data->>'files')::jsonb, | ||
(data->>'origins')::jsonb, | ||
(data->>'meta')::jsonb | ||
) | ||
insert into upload (account_id, | ||
key_id, | ||
content_cid, | ||
source_cid, | ||
mime_type, | ||
type, | ||
name, | ||
files, | ||
origins, | ||
meta) | ||
values ((data ->> 'account_id')::BIGINT, | ||
(data ->> 'key_id')::BIGINT, | ||
data ->> 'content_cid', | ||
data ->> 'source_cid', | ||
data ->> 'mime_type', | ||
(data ->> 'type')::upload_type, | ||
data ->> 'name', | ||
(data ->> 'files')::jsonb, | ||
(data ->> 'origins')::jsonb, | ||
(data ->> 'meta')::jsonb) | ||
ON CONFLICT ( account_id, content_cid ) DO NOTHING; | ||
|
||
|
||
return query select * | ||
from upload u | ||
where u.account_id = (data ->> 'account_id')::BIGINT | ||
AND u.content_cid = data ->> 'content_cid'; | ||
|
||
--raise exception 'upload % content % ', inserted_upload.id, inserted_content.cid; | ||
|
||
return query select * | ||
from upload u | ||
where u.account_id = (data->>'account_id')::BIGINT AND u.content_cid = data->>'content_cid'; | ||
|
||
IF NOT FOUND THEN | ||
RAISE EXCEPTION 'No upload found %', data->>'content_cid'; | ||
END IF; | ||
IF NOT FOUND THEN | ||
RAISE EXCEPTION 'No upload found %', data ->> 'content_cid'; | ||
END IF; | ||
|
||
RETURN; | ||
RETURN; | ||
|
||
END | ||
$$; | ||
|
||
|
||
CREATE OR REPLACE FUNCTION deals_fn(cid text) | ||
RETURNS TABLE | ||
( | ||
status text, | ||
"lastChanged" timestamptz, | ||
"chainDealID" bigint, | ||
"datamodelSelector" text, | ||
"statusText" text, | ||
"dealActivation" timestamptz, | ||
"dealExpiration" timestamptz, | ||
miner text, | ||
"pieceCid" text, | ||
"batchRootCid" text | ||
) | ||
LANGUAGE sql | ||
STABLE | ||
PARALLEL SAFE | ||
AS | ||
$$ | ||
SELECT COALESCE(de.status, 'queued') as status, | ||
de.entry_last_updated as lastChanged, | ||
de.deal_id as chainDealID, | ||
ae.datamodel_selector as datamodelSelector, | ||
de.status_meta as statusText, | ||
de.start_time as dealActivation, | ||
de.end_time as dealExpiration, | ||
de.provider as miner, | ||
a.piece_cid as pieceCid, | ||
ae.aggregate_cid as batchRootCid | ||
FROM public.aggregate_entry ae | ||
join public.aggregate a using (aggregate_cid) | ||
LEFT JOIN public.deal de USING (aggregate_cid) | ||
WHERE ae.cid_v1 = cid | ||
ORDER BY de.entry_last_updated | ||
$$; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.