From f1994a7cd49f05ea51858af5d2fd5a4d1ec52d3b Mon Sep 17 00:00:00 2001 From: Kavika Date: Tue, 5 Nov 2024 21:05:20 +1100 Subject: [PATCH] Question types framework + ShortAnswer & MultiChoice implementations (#483) * Move initial migration to one file * Update initial schema NOT NULL columns * Fix question_id ref column being int not bigint * Question framework and impl for MultiOption and ShortAnswer * answer framework for short answer and multichoice * update `Question` documentation to fit `serde` representation * fix duplicates in question framework * remove redundancy in answer framework * make question option id unique snowflake * re-separate schema migrations * set timestamps fields to `NOT NULL` * add answer to models module file * fix enum errors * fix always true/false case in answer length * add `Ranking` question type * rename multi option data "rank" to "order" * update question json example * fix use of postgres keyword `order` --------- Co-authored-by: skye_blair --- .../20240406023149_create_users.sql | 6 +- .../20240406024211_create_organisations.sql | 7 +- .../20240406025537_create_campaigns.sql | 18 +-- .../20240406031400_create_questions.sql | 22 +-- .../20240406031915_create_applications.sql | 57 +++++--- backend/server/src/models/answer.rs | 110 +++++++++++++++ backend/server/src/models/mod.rs | 3 + backend/server/src/models/question.rs | 128 ++++++++++++++++++ 8 files changed, 306 insertions(+), 45 deletions(-) create mode 100644 backend/server/src/models/answer.rs create mode 100644 backend/server/src/models/question.rs diff --git a/backend/migrations/20240406023149_create_users.sql b/backend/migrations/20240406023149_create_users.sql index 8dc86bf3..b820e2d2 100644 --- a/backend/migrations/20240406023149_create_users.sql +++ b/backend/migrations/20240406023149_create_users.sql @@ -10,8 +10,8 @@ CREATE TABLE users ( degree_name TEXT, degree_starting_year INTEGER, role user_role NOT NULL, - created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, - updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL + created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP ); -CREATE UNIQUE INDEX IDX_users_email_lower on users ((lower(email))); +CREATE UNIQUE INDEX IDX_users_email_lower on users ((lower(email))); \ No newline at end of file diff --git a/backend/migrations/20240406024211_create_organisations.sql b/backend/migrations/20240406024211_create_organisations.sql index 24f2c18d..008777c1 100644 --- a/backend/migrations/20240406024211_create_organisations.sql +++ b/backend/migrations/20240406024211_create_organisations.sql @@ -2,8 +2,8 @@ CREATE TABLE organisations ( id BIGINT PRIMARY KEY, name TEXT NOT NULL UNIQUE, logo UUID, - created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, - updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL + created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP ); CREATE TYPE organisation_role AS ENUM ('User', 'Admin'); @@ -12,7 +12,7 @@ CREATE TABLE organisation_members ( id BIGSERIAL PRIMARY KEY, organisation_id BIGINT NOT NULL, user_id BIGINT NOT NULL, - role organisation_role DEFAULT 'User' NOT NULL, + role organisation_role NOT NULL DEFAULT 'User', CONSTRAINT FK_organisation_members_organisation FOREIGN KEY(organisation_id) REFERENCES organisations(id) @@ -20,4 +20,5 @@ CREATE TABLE organisation_members ( ON UPDATE CASCADE ); + CREATE INDEX IDX_organisation_admins_organisation on organisation_members (organisation_id); diff --git a/backend/migrations/20240406025537_create_campaigns.sql b/backend/migrations/20240406025537_create_campaigns.sql index ebc1311c..757a3e63 100644 --- a/backend/migrations/20240406025537_create_campaigns.sql +++ b/backend/migrations/20240406025537_create_campaigns.sql @@ -6,13 +6,13 @@ CREATE TABLE campaigns ( description TEXT, starts_at TIMESTAMPTZ NOT NULL, ends_at TIMESTAMPTZ NOT NULL, - created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, - updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, + created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT FK_campaigns_organisations - FOREIGN KEY(organisation_id) - REFERENCES organisations(id) - ON DELETE CASCADE - ON UPDATE CASCADE + FOREIGN KEY(organisation_id) + REFERENCES organisations(id) + ON DELETE CASCADE + ON UPDATE CASCADE ); CREATE TABLE campaign_roles ( @@ -23,8 +23,8 @@ CREATE TABLE campaign_roles ( min_available INTEGER NOT NULL, max_available INTEGER NOT NULL, finalised BOOLEAN NOT NULL, - created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, - updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, + created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT FK_campaign_roles_campaign FOREIGN KEY(campaign_id) REFERENCES campaigns(id) @@ -32,4 +32,4 @@ CREATE TABLE campaign_roles ( ON UPDATE CASCADE ); -CREATE INDEX IDX_campaign_roles_campaign on campaign_roles (campaign_id); +CREATE INDEX IDX_campaign_roles_campaign on campaign_roles (campaign_id); \ No newline at end of file diff --git a/backend/migrations/20240406031400_create_questions.sql b/backend/migrations/20240406031400_create_questions.sql index 8e7136af..24f01d97 100644 --- a/backend/migrations/20240406031400_create_questions.sql +++ b/backend/migrations/20240406031400_create_questions.sql @@ -1,14 +1,15 @@ -CREATE TYPE question_type AS ENUM ('ShortAnswer', 'MultiChoice', 'MultiSelect', 'DropDown'); +CREATE TYPE question_type AS ENUM ('ShortAnswer', 'MultiChoice', 'MultiSelect', 'DropDown', 'Ranking'); CREATE TABLE questions ( id BIGINT PRIMARY KEY, title TEXT NOT NULL, description TEXT, + common BOOLEAN NOT NULL, required BOOLEAN, question_type question_type NOT NULL, campaign_id BIGINT NOT NULL, - created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, - updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, + created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT FK_questions_campaigns FOREIGN KEY(campaign_id) REFERENCES campaigns(id) @@ -17,14 +18,15 @@ CREATE TABLE questions ( ); CREATE TABLE multi_option_question_options ( - id BIGSERIAL PRIMARY KEY, + id BIGINT PRIMARY KEY, text TEXT NOT NULL, - question_id INTEGER NOT NULL, + question_id BIGINT NOT NULL, + display_order INTEGER NOT NULL, CONSTRAINT FK_multi_option_question_options_questions - FOREIGN KEY(question_id) - REFERENCES questions(id) - ON DELETE CASCADE - ON UPDATE CASCADE + FOREIGN KEY(question_id) + REFERENCES questions(id) + ON DELETE CASCADE + ON UPDATE CASCADE ); -CREATE INDEX IDX_multi_option_question_options_questions on multi_option_question_options (question_id); +CREATE INDEX IDX_multi_option_question_options_questions on multi_option_question_options (question_id); \ No newline at end of file diff --git a/backend/migrations/20240406031915_create_applications.sql b/backend/migrations/20240406031915_create_applications.sql index e2fcd057..7d1053b3 100644 --- a/backend/migrations/20240406031915_create_applications.sql +++ b/backend/migrations/20240406031915_create_applications.sql @@ -6,13 +6,13 @@ CREATE TABLE applications ( user_id BIGINT NOT NULL, status application_status NOT NULL DEFAULT 'Pending', private_status application_status NOT NULL DEFAULT 'Pending', - created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, - updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, + created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT FK_applications_campaigns - FOREIGN KEY(campaign_id) - REFERENCES campaigns(id) - ON DELETE CASCADE - ON UPDATE CASCADE, + FOREIGN KEY(campaign_id) + REFERENCES campaigns(id) + ON DELETE CASCADE + ON UPDATE CASCADE, CONSTRAINT FK_applications_users FOREIGN KEY(user_id) REFERENCES users(id) @@ -40,7 +40,7 @@ CREATE INDEX IDX_application_roles_applications on application_roles (applicatio CREATE INDEX IDX_application_roles_campaign_roles on application_roles (campaign_role_id); CREATE TABLE answers ( - id BIGSERIAL PRIMARY KEY, + id BIGINT PRIMARY KEY, application_id BIGINT NOT NULL, question_id BIGINT NOT NULL, CONSTRAINT FK_answers_applications @@ -61,7 +61,7 @@ CREATE INDEX IDX_answers_questions on answers (question_id); CREATE TABLE short_answer_answers ( id BIGSERIAL PRIMARY KEY, text TEXT NOT NULL, - answer_id INTEGER NOT NULL, + answer_id BIGINT NOT NULL, CONSTRAINT FK_short_answer_answers_answers FOREIGN KEY(answer_id) REFERENCES answers(id) @@ -74,17 +74,34 @@ CREATE INDEX IDX_short_answer_answers_answers on short_answer_answers (answer_id CREATE TABLE multi_option_answer_options ( id BIGSERIAL PRIMARY KEY, option_id BIGINT NOT NULL, - answer_id INTEGER NOT NULL, + answer_id BIGINT NOT NULL, CONSTRAINT FK_multi_option_answer_options_question_options FOREIGN KEY(option_id) REFERENCES multi_option_question_options(id) ON DELETE CASCADE ON UPDATE CASCADE, CONSTRAINT FK_multi_option_answer_options_answers - FOREIGN KEY(answer_id) - REFERENCES answers(id) - ON DELETE CASCADE - ON UPDATE CASCADE + FOREIGN KEY(answer_id) + REFERENCES answers(id) + ON DELETE CASCADE + ON UPDATE CASCADE +); + +CREATE TABLE ranking_answer_rankings ( + id BIGSERIAL PRIMARY KEY, + option_id BIGINT NOT NULL, + rank INTEGER NOT NULL, + answer_id BIGINT NOT NULL, + CONSTRAINT FK_ranking_answer_rankings_question_options + FOREIGN KEY(option_id) + REFERENCES multi_option_question_options(id) + ON DELETE CASCADE + ON UPDATE CASCADE, + CONSTRAINT FK_ranking_answer_rankings_answers + FOREIGN KEY(answer_id) + REFERENCES answers(id) + ON DELETE CASCADE + ON UPDATE CASCADE ); CREATE INDEX IDX_multi_option_answer_options_question_options on multi_option_answer_options (option_id); @@ -95,13 +112,13 @@ CREATE TABLE application_ratings ( application_id BIGINT NOT NULL, rater_id BIGINT NOT NULL, rating INTEGER NOT NULL, - created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, - updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP NOT NULL, + created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, CONSTRAINT FK_application_ratings_applications - FOREIGN KEY(application_id) - REFERENCES applications(id) - ON DELETE CASCADE - ON UPDATE CASCADE, + FOREIGN KEY(application_id) + REFERENCES applications(id) + ON DELETE CASCADE + ON UPDATE CASCADE, CONSTRAINT FK_application_ratings_users FOREIGN KEY(rater_id) REFERENCES users(id) @@ -110,4 +127,4 @@ CREATE TABLE application_ratings ( ); CREATE INDEX IDX_application_ratings_applications on application_ratings (application_id); -CREATE INDEX IDX_application_ratings_users on application_ratings (rater_id); +CREATE INDEX IDX_application_ratings_users on application_ratings (rater_id); \ No newline at end of file diff --git a/backend/server/src/models/answer.rs b/backend/server/src/models/answer.rs new file mode 100644 index 00000000..f79bf9d6 --- /dev/null +++ b/backend/server/src/models/answer.rs @@ -0,0 +1,110 @@ +use crate::models::error::ChaosError; +use anyhow::{bail, Result}; +use chrono::{DateTime, Utc}; +use serde::{Deserialize, Serialize}; +use sqlx::{Pool, Postgres, QueryBuilder, Row}; + +/// The `Answer` type that will be sent in API responses. +/// +/// +/// With the chosen `serde` representation and the use of `#[serde(flatten)]`, the JSON for a +/// `Answer` will look like this: +/// ```json +/// { +/// "id": 7233828375289773948, +/// "application_id": 7233828375289125398, +/// "question_id": 7233828375289139200, +/// "answer_type": "MultiChoice", +/// "data": 7233828393325384908, +/// "created_at": "2024-06-28T16:29:04.644008111Z", +/// "updated_at": "2024-06-30T12:14:12.458390190Z" +/// } +/// ``` +#[derive(Deserialize, Serialize)] +pub struct Answer { + id: i64, + application_id: i64, + question_id: i64, + + #[serde(flatten)] + answer_data: AnswerData, + + created_at: DateTime, + updated_at: DateTime, +} + +#[derive(Deserialize, Serialize)] +#[serde( tag = "answer_type", content = "data")] +pub enum AnswerData { + ShortAnswer(String), + MultiChoice(i64), + MultiSelect(Vec), + DropDown(i64), + Ranking(Vec) +} + +impl AnswerData { + pub async fn validate(self) -> Result<()> { + match self { + Self::ShortAnswer(text) => if text.len() == 0 { bail!("Empty answer") }, + Self::MultiSelect(data) => if data.len() == 0 { bail!("Empty answer") }, + _ => {}, + } + + Ok(()) + } + + pub async fn insert_into_db(self, answer_id: i64, pool: &Pool) -> Result<()> { + match self { + Self::ShortAnswer(text) => { + let result = sqlx::query!( + "INSERT INTO short_answer_answers (text, answer_id) VALUES ($1, $2)", + text, + answer_id + ) + .execute(pool) + .await?; + + Ok(()) + }, + Self::MultiChoice(option_id) + | Self::DropDown(option_id) => { + let result = sqlx::query!( + "INSERT INTO multi_option_answer_options (option_id, answer_id) VALUES ($1, $2)", + option_id, + answer_id + ) + .execute(pool) + .await?; + + Ok(()) + }, + Self::MultiSelect(option_ids) => { + let mut query_builder = sqlx::QueryBuilder::new("INSERT INTO multi_option_answer_options (option_id, answer_id)"); + + query_builder.push_values(option_ids, |mut b, option_id| { + b.push_bind(option_id).push_bind(answer_id); + }); + + let query = query_builder.build(); + let result = query.execute(pool).await?; + + Ok(()) + }, + Self::Ranking(option_ids) => { + let mut query_builder = sqlx::QueryBuilder::new("INSERT INTO ranking_answer_rankings (option_id, rank, answer_id)"); + + let mut rank = 1; + query_builder.push_values(option_ids, |mut b, option_id| { + b.push_bind(option_id).push_bind(rank).push_bind(answer_id); + rank += 1; + }); + + let query = query_builder.build(); + let result = query.execute(pool).await?; + + Ok(()) + } + } + } +} diff --git a/backend/server/src/models/mod.rs b/backend/server/src/models/mod.rs index 0af7da1a..bb79ea9d 100644 --- a/backend/server/src/models/mod.rs +++ b/backend/server/src/models/mod.rs @@ -1,10 +1,13 @@ +pub mod answer; pub mod app; pub mod auth; pub mod campaign; pub mod error; +pub mod question; pub mod organisation; pub mod role; pub mod storage; pub mod transaction; pub mod user; pub mod application; + diff --git a/backend/server/src/models/question.rs b/backend/server/src/models/question.rs new file mode 100644 index 00000000..307a7aae --- /dev/null +++ b/backend/server/src/models/question.rs @@ -0,0 +1,128 @@ +use crate::models::error::ChaosError; +use anyhow::{bail, Result}; +use chrono::{DateTime, Utc}; +use serde::{Deserialize, Serialize}; +use sqlx::{Pool, Postgres, QueryBuilder, Row}; +use snowflake::SnowflakeIdGenerator; + +/// The `Question` type that will be sent in API responses. +/// +/// +/// With the chosen `serde` representation and the use of `#[serde(flatten)]`, the JSON for a +/// `Question` will look like this: +/// ```json +/// { +/// "id": 7233828375289139200, +/// "title": "What is your favourite language?", +/// "required": true, +/// "question_type": "MultiChoice", +/// "data": { +/// "options": [ +/// { +/// "id": 7233828375387640938, +/// "display_order": 1, +/// "text": "Rust" +/// }, +/// { +/// "id": 7233828375387640954, +/// "display_order": 2, +/// "text": "Java" +/// }, +/// { +/// "id": 7233828375387640374, +/// "display_order": 3, +/// "text": "TypeScript" +/// } +/// ] +/// }, +/// "created_at": "2024-06-28T16:29:04.644008111Z", +/// "updated_at": "2024-06-30T12:14:12.458390190Z" +/// } +/// ``` +#[derive(Serialize)] +pub struct Question { + id: i64, + title: String, + description: Option, + common: bool, // Common question are shown at the start + required: bool, + + #[serde(flatten)] + question_data: QuestionData, + + created_at: DateTime, + updated_at: DateTime, +} + +/// An enum that represents all the data types of question data that CHAOS can handle. +/// This stores all the data for each question type. +/// +/// \ +/// Some question types are stored in memory and JSON using the same struct, and only differ +/// in their implementation when inserting to the database and in their restrictions +/// (e.g. max 1 answer allowed in multi-choice vs. many in multi-select) +#[derive(Deserialize, Serialize)] +#[serde(tag = "question_type", content = "data")] +pub enum QuestionData { + ShortAnswer, + MultiChoice(MultiOptionData), + MultiSelect(MultiOptionData), + DropDown(MultiOptionData), + Ranking(MultiOptionData), +} + +#[derive(Deserialize, Serialize)] +pub struct MultiOptionData { + options: Vec, +} + +/// Each of these structs represent a row in the `multi_option_question_options` +/// table. For a `MultiChoice` question like "What is your favourite programming +/// language?", there would be rows for "Rust", "Java" and "TypeScript". +#[derive(Deserialize, Serialize)] +pub struct MultiOptionQuestionOption { + id: i32, + display_order: i32, + text: String, +} + +impl QuestionData { + pub async fn validate(self) -> Result<()> { + match self { + Self::ShortAnswer => Ok(()), + Self::MultiChoice(data) + | Self::MultiSelect(data) + | Self::DropDown(data) + | Self::Ranking(data) => { + if data.options.len() > 0 { + return Ok(()); + }; + + bail!("Invalid number of options.") + } + } + } + + pub async fn insert_into_db(self, question_id: i64, pool: &Pool, mut snowflake_generator: SnowflakeIdGenerator) -> Result<()> { + match self { + Self::ShortAnswer => Ok(()), + Self::MultiChoice(data) + | Self::MultiSelect(data) + | Self::DropDown(data) + | Self::Ranking(data) => { + let mut query_builder = + QueryBuilder::new("INSERT INTO multi_option_question_options (id, text, question_id, display_order)"); + + query_builder.push_values(data.options, |mut b, option| { + let id = snowflake_generator.real_time_generate(); + b.push_bind(id).push_bind(option.text).push_bind(question_id).push_bind(option.display_order); + }); + + let query = query_builder.build(); + let result = query.execute(pool).await?; + + Ok(()) + } + } + } +}