From 703a6425fec981375f7fecdf5f086ccce1c686cb Mon Sep 17 00:00:00 2001 From: chamikaJ Date: Mon, 28 Jul 2025 15:17:21 +0530 Subject: [PATCH] feat(surveys): add survey tables and initial data for account setup questionnaire - Created tables for surveys, survey questions, survey responses, and survey answers to support the account setup process. - Added default account setup survey and corresponding questions to the database. - Implemented necessary indexes and constraints for data integrity and performance. --- worklenz-backend/database/sql/1_tables.sql | 57 ++++++++++++++++++++++ worklenz-backend/database/sql/2_dml.sql | 22 +++++++++ 2 files changed, 79 insertions(+) diff --git a/worklenz-backend/database/sql/1_tables.sql b/worklenz-backend/database/sql/1_tables.sql index 2ab00077..7b0e3f3c 100644 --- a/worklenz-backend/database/sql/1_tables.sql +++ b/worklenz-backend/database/sql/1_tables.sql @@ -2297,3 +2297,60 @@ ALTER TABLE organization_working_days ALTER TABLE organization_working_days ADD CONSTRAINT org_organization_id_fk FOREIGN KEY (organization_id) REFERENCES organizations; + +-- Survey tables for account setup questionnaire +CREATE TABLE IF NOT EXISTS surveys ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + name VARCHAR(255) NOT NULL, + description TEXT, + survey_type VARCHAR(50) DEFAULT 'account_setup' NOT NULL, + is_active BOOLEAN DEFAULT TRUE NOT NULL, + created_at TIMESTAMP DEFAULT now() NOT NULL, + updated_at TIMESTAMP DEFAULT now() NOT NULL +); + +CREATE TABLE IF NOT EXISTS survey_questions ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + survey_id UUID REFERENCES surveys(id) ON DELETE CASCADE NOT NULL, + question_key VARCHAR(100) NOT NULL, + question_type VARCHAR(50) NOT NULL, + is_required BOOLEAN DEFAULT FALSE NOT NULL, + sort_order INTEGER DEFAULT 0 NOT NULL, + options JSONB, + created_at TIMESTAMP DEFAULT now() NOT NULL, + updated_at TIMESTAMP DEFAULT now() NOT NULL +); + +CREATE TABLE IF NOT EXISTS survey_responses ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + survey_id UUID REFERENCES surveys(id) ON DELETE CASCADE NOT NULL, + user_id UUID REFERENCES users(id) ON DELETE CASCADE NOT NULL, + is_completed BOOLEAN DEFAULT FALSE NOT NULL, + started_at TIMESTAMP DEFAULT now() NOT NULL, + completed_at TIMESTAMP, + created_at TIMESTAMP DEFAULT now() NOT NULL, + updated_at TIMESTAMP DEFAULT now() NOT NULL +); + +CREATE TABLE IF NOT EXISTS survey_answers ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + response_id UUID REFERENCES survey_responses(id) ON DELETE CASCADE NOT NULL, + question_id UUID REFERENCES survey_questions(id) ON DELETE CASCADE NOT NULL, + answer_text TEXT, + answer_json JSONB, + created_at TIMESTAMP DEFAULT now() NOT NULL, + updated_at TIMESTAMP DEFAULT now() NOT NULL +); + +-- Survey table indexes +CREATE INDEX IF NOT EXISTS idx_surveys_type_active ON surveys(survey_type, is_active); +CREATE INDEX IF NOT EXISTS idx_survey_questions_survey_order ON survey_questions(survey_id, sort_order); +CREATE INDEX IF NOT EXISTS idx_survey_responses_user_survey ON survey_responses(user_id, survey_id); +CREATE INDEX IF NOT EXISTS idx_survey_responses_completed ON survey_responses(survey_id, is_completed); +CREATE INDEX IF NOT EXISTS idx_survey_answers_response ON survey_answers(response_id); + +-- Survey table constraints +ALTER TABLE survey_questions ADD CONSTRAINT survey_questions_sort_order_check CHECK (sort_order >= 0); +ALTER TABLE survey_questions ADD CONSTRAINT survey_questions_type_check CHECK (question_type IN ('single_choice', 'multiple_choice', 'text')); +ALTER TABLE survey_responses ADD CONSTRAINT unique_user_survey_response UNIQUE (user_id, survey_id); +ALTER TABLE survey_answers ADD CONSTRAINT unique_response_question_answer UNIQUE (response_id, question_id); diff --git a/worklenz-backend/database/sql/2_dml.sql b/worklenz-backend/database/sql/2_dml.sql index 1fd8074f..5902b495 100644 --- a/worklenz-backend/database/sql/2_dml.sql +++ b/worklenz-backend/database/sql/2_dml.sql @@ -142,3 +142,25 @@ DROP FUNCTION sys_insert_license_types(); INSERT INTO timezones (name, abbrev, utc_offset) SELECT name, abbrev, utc_offset FROM pg_timezone_names; + +-- Insert default account setup survey +INSERT INTO surveys (name, description, survey_type, is_active) VALUES +('Account Setup Survey', 'Initial questionnaire during account setup to understand user needs', 'account_setup', true) +ON CONFLICT DO NOTHING; + +-- Insert survey questions for account setup survey +DO $$ +DECLARE + survey_uuid UUID; +BEGIN + SELECT id INTO survey_uuid FROM surveys WHERE survey_type = 'account_setup' AND name = 'Account Setup Survey' LIMIT 1; + + -- Insert survey questions + INSERT INTO survey_questions (survey_id, question_key, question_type, is_required, sort_order, options) VALUES + (survey_uuid, 'organization_type', 'single_choice', true, 1, '["freelancer", "startup", "small_medium_business", "agency", "enterprise", "other"]'), + (survey_uuid, 'user_role', 'single_choice', true, 2, '["founder_ceo", "project_manager", "software_developer", "designer", "operations", "other"]'), + (survey_uuid, 'main_use_cases', 'multiple_choice', true, 3, '["task_management", "team_collaboration", "resource_planning", "client_communication", "time_tracking", "other"]'), + (survey_uuid, 'previous_tools', 'text', false, 4, null), + (survey_uuid, 'how_heard_about', 'single_choice', false, 5, '["google_search", "twitter", "linkedin", "friend_colleague", "blog_article", "other"]') + ON CONFLICT DO NOTHING; +END $$;