Skip to content

Commit

Permalink
feat: DB schema and API for user_tag_proposal. (#1006)
Browse files Browse the repository at this point in the history
* Users create records in this table and admins manage it.

Co-authored-by: trigramdev9 <jsdevel@trigram.co>
  • Loading branch information
jsdevel authored Jun 2, 2022
1 parent 915c997 commit effe575
Show file tree
Hide file tree
Showing 2 changed files with 61 additions and 0 deletions.
26 changes: 26 additions & 0 deletions packages/db/postgres/migrations/012-user_tag_proposal.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,26 @@
-- 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,
proposed_tag_value TEXT NOT NULL,
user_proposal_form jsonb 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;
35 changes: 35 additions & 0 deletions packages/db/postgres/tables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -25,6 +25,16 @@ BEGIN
);
END IF;

-- Proposal decision types are used by admins to denote approval/denial of a
-- request by the user to receive more permissions int he application.
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'user_tag_proposal_decision_type') THEN
CREATE TYPE user_tag_proposal_decision_type AS ENUM
(
'Approved',
'Declined'
);
END IF;

-- Types for notification emails
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'email_type') THEN
CREATE TYPE email_type AS ENUM
Expand Down Expand Up @@ -74,6 +84,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,
proposed_tag_value TEXT NOT NULL,
user_proposal_form jsonb 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;

-- User authentication keys.
CREATE TABLE IF NOT EXISTS auth_key
(
Expand Down

0 comments on commit effe575

Please sign in to comment.