Skip to content

Commit

Permalink
feat: DB schema and API for user_tag_proposal. (#1410)
Browse files Browse the repository at this point in the history
* Users create records in this table and admins manage it.
  • Loading branch information
jsdevel committed May 26, 2022
1 parent 318ad50 commit f0e4284
Show file tree
Hide file tree
Showing 2 changed files with 59 additions and 1 deletion.
27 changes: 27 additions & 0 deletions packages/api/db/migrations/003-user_tag_proposals.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
-- Migration to setup user_tag_proposal
CREATE TYPE user_tag_proposal_decision_type AS ENUM
(
'Approved',
'Declined'
);

CREATE TABLE IF NOT EXISTS public.user_tag_proposal
(
id BIGSERIAL PRIMARY KEY,
user_id BIGINT NOT NULL REFERENCES public.user (id),
tag user_tag_type NOT NULL,
user_proposed_value TEXT NOT NULL,
user_proposal_message TEXT NOT NULL,
admin_decision_message TEXT ,
admin_decision_type user_tag_proposal_decision_type,
inserted_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL,
deleted_at TIMESTAMP WITH TIME ZONE
);
-- Note: We index active user_tag_proposals with deleted_at IS NULL to enforce only 1 active
-- tag type proposal per user. We allow there to be multiple deleted user_tag_proposals of the same type per
-- user to handle the scenario where a user has been denied multiple times by admins.
-- If deleted_at is populated, it means the user_tag_proposal has been cancelled by
-- a user or a decision has been provided by an admin.
CREATE UNIQUE INDEX IF NOT EXISTS user_tag_proposal_is_not_deleted_idx ON user_tag_proposal (user_id, tag)
WHERE deleted_at IS NULL;

33 changes: 32 additions & 1 deletion packages/api/db/tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,12 @@ CREATE TYPE user_tag_type AS ENUM
'StorageLimitBytes'
);

CREATE TYPE user_tag_proposal_decision_type AS ENUM
(
'Approved',
'Declined'
);

-- Pin status type is a subset of IPFS Cluster "TrackerStatus".
-- https://github.com/ipfs/ipfs-cluster/blob/54c3608899754412861e69ee81ca8f676f7e294b/api/types.go#L52-L83
CREATE TYPE pin_status_type AS ENUM (
Expand Down Expand Up @@ -89,6 +95,31 @@ WHERE deleted_at IS NOT NULL;
CREATE UNIQUE INDEX IF NOT EXISTS user_tag_is_not_deleted_idx ON user_tag (user_id, tag)
WHERE deleted_at IS NULL;

-- These are user_tag(s) that a user has requested. It is assumed that a user can
-- only request one type of user_tag at any given time, hence the index associated
-- with this table. The admin app will have to create an entry in the user_tag
-- table once a proposal has been approved. These proposals are visible to both
-- users and admins.
CREATE TABLE IF NOT EXISTS public.user_tag_proposal
(
id BIGSERIAL PRIMARY KEY,
user_id BIGINT NOT NULL REFERENCES public.user (id),
tag user_tag_type NOT NULL,
user_proposed_value TEXT NOT NULL,
user_proposal_message TEXT NOT NULL,
admin_decision_message TEXT ,
admin_decision_type user_tag_proposal_decision_type,
inserted_at TIMESTAMP WITH TIME ZONE DEFAULT timezone('utc'::text, now()) NOT NULL,
deleted_at TIMESTAMP WITH TIME ZONE
);
-- Note: We index active user_tag_proposals with deleted_at IS NULL to enforce only 1 active
-- tag type proposal per user. We allow there to be multiple deleted user_tag_proposals of the same type per
-- user to handle the scenario where a user has been denied multiple times by admins.
-- If deleted_at is populated, it means the user_tag_proposal has been cancelled by
-- a user or a decision has been provided by an admin.
CREATE UNIQUE INDEX IF NOT EXISTS user_tag_proposal_is_not_deleted_idx ON user_tag_proposal (user_id, tag)
WHERE deleted_at IS NULL;

-- API authentication tokens.
CREATE TABLE IF NOT EXISTS auth_key
(
Expand Down Expand Up @@ -208,4 +239,4 @@ CREATE TABLE IF NOT EXISTS metric
value BIGINT 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
);
);

0 comments on commit f0e4284

Please sign in to comment.