Skip to content

Commit

Permalink
feat: New schema for reviews backend.
Browse files Browse the repository at this point in the history
  • Loading branch information
coire1 committed Jan 9, 2025
1 parent 5312962 commit 173da29
Show file tree
Hide file tree
Showing 9 changed files with 180 additions and 44 deletions.
102 changes: 102 additions & 0 deletions src/event-db/migrations/V11__reviews.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,102 @@
-- Catalyst Event Database

-- Subscription Table
-- This table stores the subscriptions for users in the reviews module

CREATE TABLE subscription
(
row_id SERIAL PRIMARY KEY,
user_id INTEGER NOT NULL,
event_id INTEGER NOT NULL,
role INTEGER NOT NULL,
status INTEGER NOT NULL,
extra JSONB NULL,

FOREIGN KEY (user_id) REFERENCES catalyst_user(row_id) ON DELETE CASCADE,
FOREIGN KEY (event_id) REFERENCES event(row_id) ON DELETE CASCADE
);

CREATE UNIQUE INDEX subscription_idx ON subscription(user_id,event_id,role);

COMMENT ON TABLE subscription IS '
A subscription describes the possible roles of a single user for an event.
A user can participate in multiple events active as multiple roles.
For this reason this dedicated table tracks all active roles for a user related
to a specific event and stores meta information about them.
Some of these subscriptions will be automatically created by the system.
The presence/status of subscriptions will determine user capabilities in the app.
';

COMMENT ON COLUMN subscription.role IS
'This field describes the role of the user for this subscription.
Possible values:
0: For LV0 Community Reviewers
1: For LV1 Community Reviewers
2: For LV2 Moderators';

COMMENT ON COLUMN subscription.extra IS
'This field is used to store all meta information about a subscription.
Specifically:
anonymous_id: str,
subscription_date: datetime,
preferred_categories: [int]
';


-- Allocation - Defines the relationship between users and proposals or proposals_reviews
-- to describe:
-- - the ownership of a proposal.
-- - the allocation of the reviews that needs to be done.
-- - the allocation of moderations that needs to be done.

CREATE TABLE allocation (
row_id SERIAL PRIMARY KEY,
proposal_id INTEGER NULL,
review_id INTEGER NULL,
user_id INTEGER NOT NULL,
type INTEGER NOT NULL,

FOREIGN KEY (proposal_id) REFERENCES proposal(row_id) ON DELETE CASCADE,
FOREIGN KEY (review_id) REFERENCES proposal_review(row_id) ON DELETE CASCADE,
FOREIGN KEY (user_id) REFERENCES catalyst_user(row_id) ON DELETE CASCADE
);


COMMENT ON TABLE allocation IS 'The relationship between users and proposals or proposals_reviews.';
COMMENT ON COLUMN allocation.row_id IS 'Synthetic ID of this relationship.';
COMMENT ON COLUMN allocation.proposal_id IS 'The proposal the relationship is related to.';
COMMENT ON COLUMN allocation.review_id IS 'The review the relationship is related to.';
COMMENT ON COLUMN allocation.user_id IS 'The user the relationship is related to.';
COMMENT ON COLUMN allocation.type IS 'The type of relationship stored.
Possible values:
0: proposal ownership relation. proposal_id and user_id are required
1: proposal allocated for review. proposal_id and user_id are required
2: review allocated for moderation. review_id and user_id are required';

CREATE INDEX idx_allocation_proposal_type ON allocation(proposal_id, type) WHERE proposal_id IS NOT NULL;
CREATE INDEX idx_allocation_review_type ON allocation(review_id, type) WHERE review_id IS NOT NULL;
CREATE INDEX idx_allocation_user_type ON allocation(user_id, type);


-- Moderation - Defines the moderation submitted by users for each proposal_review.

CREATE TABLE moderation (
row_id SERIAL PRIMARY KEY,
review_id INTEGER NOT NULL,
user_id INTEGER NOT NULL,
classification INTEGER NOT NULL,
rationale VARCHAR,
UNIQUE (review_id, user_id),

FOREIGN KEY (review_id) REFERENCES proposal_review(row_id) ON DELETE CASCADE,
FOREIGN KEY (user_id) REFERENCES catalyst_user(row_id) ON DELETE CASCADE
);


COMMENT ON TABLE moderation IS 'An individual moderation for a proposal review.';
COMMENT ON COLUMN moderation.row_id IS 'Synthetic ID of this moderation.';
COMMENT ON COLUMN moderation.review_id IS 'The review the moderation is related to.';
COMMENT ON COLUMN moderation.user_id IS 'The user the moderation is submitted from.';
COMMENT ON COLUMN moderation.classification IS 'The value used to describe the moderation (e.g. 0: excluded, 1: included).';
COMMENT ON COLUMN moderation.rationale IS 'The rationale for the given classification.';
25 changes: 25 additions & 0 deletions src/event-db/migrations/V4__catalyst_id.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
-- Catalyst Event Database

-- Catalyst ID map Table
-- This table stores the relationship between a catalyst ID and an email address.

CREATE TABLE catalyst_id_map
(
row_id SERIAL PRIMARY KEY,
catalyst_id VARCHAR NOT NULL,
email VARCHAR NOT NULL,
signed_email VARCHAR NOT NULL,
status INTEGER NOT NULL,
confirmation_token VARCHAR NOT NULL,

UNIQUE(catalyst_id)
);

CREATE UNIQUE INDEX catalyst_id_idx ON catalyst_id_map(catalyst_id, email);

COMMENT ON COLUMN catalyst_id_map.email IS 'The email is stored encrypted.';
COMMENT ON COLUMN catalyst_id_map.status IS '
Describes the status of an account:
0: Inactive
1: Active
2: Banned.';
45 changes: 45 additions & 0 deletions src/event-db/migrations/V5__user.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
-- Catalyst Event Database

-- User Table
-- This table stores the users for the reviews module

CREATE TABLE catalyst_user
(
row_id SERIAL PRIMARY KEY,
catalyst_id INTEGER NOT NULL,
enc_password VARCHAR NOT NULL,
salt VARCHAR NOT NULL,
extra JSONB NULL,

FOREIGN KEY(catalyst_id) REFERENCES catalyst_id_map(row_id) ON DELETE CASCADE
);

CREATE UNIQUE INDEX user_catalyst_id_idx ON catalyst_user(catalyst_id);


COMMENT ON COLUMN catalyst_user.extra IS
'This field is used to store all meta information about a user that
are required by the application. Specifically:
admin: bool,
username: str,
registration_date: datetime,
due_diligence: {
status: int,
due_diligence_id: str,
url: str
},
historic_stats: {
"reviews": {
"active_funds": int,
"submitted": int,
"blank": int,
"valid": int
},
"moderations": {
"active_funds": int,
"submitted": int,
"allocated": int,
}
}
';
Original file line number Diff line number Diff line change
Expand Up @@ -99,6 +99,7 @@ COMMENT ON COLUMN reviewer_level.event_id IS 'The specific Event ID this review
CREATE TABLE proposal_review (
row_id SERIAL PRIMARY KEY,
proposal_id INTEGER NOT NULL,
user_id INTEGER NOT NULL,
assessor VARCHAR NOT NULL,
assessor_level INTEGER,
reward_address TEXT,
Expand All @@ -111,11 +112,12 @@ CREATE TABLE proposal_review (
feasibility_note VARCHAR,
auditability_rating_given INTEGER,
auditability_note VARCHAR,
allocated INTEGER,
ranking INTEGER,
flags JSONB NULL,

FOREIGN KEY (proposal_id) REFERENCES proposal(row_id) ON DELETE CASCADE,
FOREIGN KEY (assessor_level) REFERENCES reviewer_level(row_id) ON DELETE CASCADE
FOREIGN KEY (user_id) REFERENCES catalyst_user(row_id) ON DELETE SET NULL,
FOREIGN KEY (proposal_id) REFERENCES proposal(row_id) ON DELETE CASCADE
);

COMMENT ON TABLE proposal_review IS 'All Reviews.';
Expand Down Expand Up @@ -146,6 +148,10 @@ COMMENT ON COLUMN proposal_review.auditability_note IS
'A note about the auditability rating given.
DEPRECATED: Only used for Vit-SS compatibility.';

COMMENT ON COLUMN proposal_review.allocated IS
'Describes if the review was part of the original reviewer allocation.
';

COMMENT ON COLUMN proposal_review.ranking IS
'Numeric Measure of quality of this review according to veteran community advisors.
DEPRECATED: Only used for Vit-SS compatibility.
Expand Down
File renamed without changes.
42 changes: 0 additions & 42 deletions src/event-db/migrations/V9__moderation_stage.sql

This file was deleted.

File renamed without changes.

0 comments on commit 173da29

Please sign in to comment.