Skip to content

Commit

Permalink
feat: schema updates for admin site (#947)
Browse files Browse the repository at this point in the history
Co-authored-by: Joe Spencer <joe.spencer@discounttire.com>
  • Loading branch information
trigramdev9 and Joe Spencer authored Feb 8, 2022
1 parent 1373dbb commit 731b6e1
Showing 1 changed file with 37 additions and 2 deletions.
39 changes: 37 additions & 2 deletions packages/db/postgres/tables.sql
Original file line number Diff line number Diff line change
@@ -1,3 +1,13 @@
-- Auth key blocked status type is the type of blocking that has occurred on the api
-- key. These are primarily used by the admin app.
CREATE TYPE auth_key_blocked_status_type AS ENUM
(
-- The api key is blocked.
'Blocked',
-- The api key is unblocked.
'Unblocked'
);

-- A user of web3.storage.
CREATE TABLE IF NOT EXISTS public.user
(
Expand Down Expand Up @@ -34,6 +44,16 @@ CREATE TABLE IF NOT EXISTS auth_key

CREATE INDEX IF NOT EXISTS auth_key_user_id_idx ON auth_key (user_id);

CREATE TABLE IF NOT EXISTS auth_key_history
(
id BIGSERIAL PRIMARY KEY,
status auth_key_blocked_status_type NOT NULL,
reason TEXT NOT NULL,
auth_key_id BIGSERIAL NOT NULL REFERENCES auth_key (id),
inserted_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL,
deleted_at TIMESTAMP WITH TIME ZONE
);

-- Details of the root of a file/directory stored on web3.storage.
CREATE TABLE IF NOT EXISTS content
(
Expand All @@ -53,7 +73,7 @@ CREATE UNIQUE INDEX content_cid_with_size_idx ON content (cid) INCLUDE (dag_size
DO $$
BEGIN
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'pin_status_type') THEN

-- IPFS Cluster tracker status values.
-- https://github.com/ipfs/ipfs-cluster/blob/54c3608899754412861e69ee81ca8f676f7e294b/api/types.go#L52-L83
-- TODO: nft.storage only using a subset of these: https://github.com/ipfs-shipyard/nft.storage/blob/main/packages/api/db/tables.sql#L2-L7
Expand Down Expand Up @@ -248,4 +268,19 @@ CREATE TABLE IF NOT EXISTS pinning_authorization
user_id BIGINT NOT NULL REFERENCES public.user (id),
inserted_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL,
deleted_at TIMESTAMP WITH TIME ZONE
)
);

CREATE VIEW admin_search as
select
u.id::text as user_id,
u.email as email,
ak.secret as token,
ak.id::text as token_id,
ak.deleted_at as deleted_at,
akh.inserted_at as reason_inserted_at,
akh.reason as reason,
akh.status as status
from public.user u
right join auth_key ak on ak.user_id = u.id
full outer join (select * from auth_key_history where deleted_at is null) as akh on akh.auth_key_id = ak.id
where ak.deleted_at is NULL or ak.deleted_at is not NULL and akh.status is not NULL;

0 comments on commit 731b6e1

Please sign in to comment.