Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat: New schema for reviews backend. | NPG-000 #731

Merged
merged 7 commits into from
Jan 17, 2025
Merged
Show file tree
Hide file tree
Changes from 3 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
106 changes: 106 additions & 0 deletions src/event-db/migrations/V11__reviews.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,106 @@
-- 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.user_id IS 'The user ID this subscription belongs to.';
COMMENT ON COLUMN subscription.event_id IS 'The event ID this subscription belongs to.';

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],
reward_address: str
';


-- 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 ID the relationship belongs to.';
COMMENT ON COLUMN allocation.review_id IS 'The review ID the relationship belongs to.';
COMMENT ON COLUMN allocation.user_id IS 'The user ID the relationship belongs 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 ID the moderation belongs to.';
COMMENT ON COLUMN moderation.user_id IS 'The user ID the moderation belongs to.';
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.';
45 changes: 45 additions & 0 deletions src/event-db/migrations/V4__catalyst_id.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
-- 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,
username VARCHAR NOT NULL,
signed_email VARCHAR NOT NULL,
status INTEGER NOT NULL,
confirmation_token VARCHAR,
confirmation_requested_at TIMESTAMP,
confirmed_at TIMESTAMP,

UNIQUE(catalyst_id)
);

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

COMMENT ON TABLE catalyst_id_map IS '
The `catalyst_id_map` table is used to store the map between the CatalystID and email/username for each user.
Because the Catalyst RBAC registration are stored on-chain, and for this reason are publicly accessible,
sensitive information like email address will be stored in a centralized DB, keeping a reference to the CatalystID.
The email address is stored only when its signature corresponds to the CatalystID.
';
COMMENT ON COLUMN catalyst_id_map.catalyst_id IS '
It contains the unique part of the CatalystID.
Given a full CatalystID like `id.catalyst://[email protected]/FftxFnOrj2qmTuB2oZG2v0YEWJfKvQ9Gg8AgNAhDsKE`
The scheme and the username are omitted and only the unique part `preprod.cardano/FftxFnOrj2qmTuB2oZG2v0YEWJfKvQ9Gg8AgNAhDsKE`
is stored in this field.
';
COMMENT ON COLUMN catalyst_id_map.email IS 'The email address stored in plaintext.';
COMMENT ON COLUMN catalyst_id_map.username IS 'The username extracted from the CatalystID stored in plaintext.';
COMMENT ON COLUMN catalyst_id_map.signed_email IS 'The signed document that includes the email address.';
COMMENT ON COLUMN catalyst_id_map.status IS '
Describes the status of an account:
0: Inactive
1: Active
2: Banned.';
COMMENT ON COLUMN catalyst_id_map.confirmation_token IS 'The token that is generated for the email confirmation.';
COMMENT ON COLUMN catalyst_id_map.confirmation_requested_at IS 'The timestamp to validate confirmation token validity.';
COMMENT ON COLUMN catalyst_id_map.confirmed_at IS 'The timestamp of the email confirmation.';
53 changes: 53 additions & 0 deletions src/event-db/migrations/V5__user.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,53 @@
-- 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 TABLE catalyst_user IS '
This tables stores the user account for the Review Module.
It contains a reference to the catalyst_id that is used as public and unique identifier.
';

COMMENT ON COLUMN catalyst_user.catalyst_id IS 'The catalyst_id this account belongs to.';
COMMENT ON COLUMN catalyst_user.enc_password IS 'The encrypted password.';
COMMENT ON COLUMN catalyst_user.salt IS 'The salt for the password encryption.';
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,52 +99,47 @@ 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,

-- These fields are deprecated and WILL BE removed in a future migration.
-- They MUST only be used for Vit-SS compatibility.
impact_alignment_rating_given INTEGER,
impact_alignment_note VARCHAR,
feasibility_rating_given INTEGER,
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.';
COMMENT ON COLUMN proposal_review.row_id IS 'Synthetic Unique Key.';
COMMENT ON COLUMN proposal_review.proposal_id IS 'The Proposal this review is for.';
COMMENT ON COLUMN proposal_review.assessor IS 'Assessors Anonymized ID';
COMMENT ON COLUMN proposal_review.proposal_id IS 'The Proposal id this review belongs to.';
COMMENT ON COLUMN proposal_review.user_id IS 'The user id this review belongs to.';
COMMENT ON COLUMN proposal_review.assessor IS 'Assessors Anonymized ID.';
COMMENT ON COLUMN proposal_review.assessor_level IS 'Assessors level ID';
COMMENT ON COLUMN proposal_review.reward_address IS 'Assessors reward address';

COMMENT ON COLUMN proposal_review.impact_alignment_rating_given IS
'The numeric rating assigned to the proposal by the assessor.
DEPRECATED: Only used for Vit-SS compatibility.';
'The numeric rating assigned to the proposal by the assessor.';
COMMENT ON COLUMN proposal_review.impact_alignment_note IS
'A note about why the impact rating was given.
DEPRECATED: Only used for Vit-SS compatibility.';

'A note about why the impact rating was given.';
COMMENT ON COLUMN proposal_review.feasibility_rating_given IS
'The numeric feasibility rating given.
DEPRECATED: Only used for Vit-SS compatibility.';
'The numeric feasibility rating given.';
COMMENT ON COLUMN proposal_review.feasibility_note IS
'A note about why the feasibility rating was given.
DEPRECATED: Only used for Vit-SS compatibility.';

'A note about why the feasibility rating was given.';
COMMENT ON COLUMN proposal_review.auditability_rating_given IS
'The numeric auditability rating given.
DEPRECATED: Only used for Vit-SS compatibility.';
'The numeric auditability rating given.';
COMMENT ON COLUMN proposal_review.auditability_note IS
'A note about the auditability rating given.
DEPRECATED: Only used for Vit-SS compatibility.';
'A note about the auditability rating given.';

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.
Expand Down
42 changes: 0 additions & 42 deletions src/event-db/migrations/V9__moderation_stage.sql

This file was deleted.

1 change: 1 addition & 0 deletions utilities/ideascale-importer/Earthfile
Original file line number Diff line number Diff line change
Expand Up @@ -29,6 +29,7 @@ build:
RUN poetry env use python
RUN poetry config installer.max-workers 10
RUN poetry install --no-cache --no-root
RUN poetry self add poetry-plugin-export

# Build the distribution wheels and save them as artifacts
RUN poetry export --without-hashes -f requirements.txt --output requirements.txt
Expand Down
Loading