Yimaru-BackEnd/db/migrations/000001_yimaru.up.sql

245 lines
6.8 KiB
SQL

CREATE TABLE IF NOT EXISTS users (
id BIGSERIAL PRIMARY KEY,
first_name VARCHAR(255),
last_name VARCHAR(255),
gender VARCHAR(255),
birth_day DATE,
email VARCHAR(255),
phone_number VARCHAR(20),
role VARCHAR(50) NOT NULL, -- SUPER_ADMIN, INSTRUCTOR, STUDENT, SUPPORT
password BYTEA NOT NULL,
age INT,
education_level VARCHAR(100),
country VARCHAR(100),
region VARCHAR(100),
knowledge_level VARCHAR(50), -- BEGINNER, INTERMEDIATE, ADVANCED
nick_name VARCHAR(100),
occupation VARCHAR(150),
learning_goal TEXT,
language_goal TEXT,
language_challange TEXT,
favourite_topic TEXT,
initial_assessment_completed BOOLEAN NOT NULL DEFAULT FALSE,
email_verified BOOLEAN NOT NULL DEFAULT FALSE,
phone_verified BOOLEAN NOT NULL DEFAULT FALSE,
status VARCHAR(50) NOT NULL, -- PENDING, ACTIVE, SUSPENDED, DEACTIVATED
last_login TIMESTAMPTZ,
profile_completed BOOLEAN,
profile_picture_url TEXT,
preferred_language VARCHAR(50),
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ,
-- Enforce: at least one contact method must be provided
CONSTRAINT users_email_or_phone_required
CHECK (email IS NOT NULL OR phone_number IS NOT NULL)
);
CREATE TABLE IF NOT EXISTS assessment_questions (
id BIGSERIAL PRIMARY KEY,
title TEXT NOT NULL,
description TEXT,
question_type VARCHAR(50) NOT NULL,
-- MULTIPLE_CHOICE, TRUE_FALSE, SHORT_ANSWER
difficulty_level VARCHAR(50),
-- EASY, MEDIUM, HARD
points INT NOT NULL DEFAULT 1,
is_active BOOLEAN NOT NULL DEFAULT TRUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ
);
CREATE TABLE IF NOT EXISTS assessment_question_options (
id BIGSERIAL PRIMARY KEY,
question_id BIGINT NOT NULL REFERENCES assessment_questions(id) ON DELETE CASCADE,
option_text TEXT NOT NULL,
option_order INT NOT NULL,
is_correct BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
UNIQUE (question_id, option_order)
);
CREATE TABLE IF NOT EXISTS assessment_short_answers (
id BIGSERIAL PRIMARY KEY,
question_id BIGINT NOT NULL REFERENCES assessment_questions(id) ON DELETE CASCADE,
correct_answer TEXT NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
);
ALTER TABLE assessment_questions
ADD CONSTRAINT chk_question_type
CHECK (question_type IN ('MULTIPLE_CHOICE', 'TRUE_FALSE', 'SHORT_ANSWER'));
CREATE TABLE IF NOT EXISTS assessment_attempts (
id BIGSERIAL PRIMARY KEY,
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
total_questions INT NOT NULL,
total_points INT NOT NULL,
score INT,
percentage NUMERIC(5,2),
status VARCHAR(50) NOT NULL,
-- IN_PROGRESS, SUBMITTED, EVALUATED
started_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
submitted_at TIMESTAMPTZ,
evaluated_at TIMESTAMPTZ,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ
);
CREATE TABLE IF NOT EXISTS assessment_attempt_questions (
id BIGSERIAL PRIMARY KEY,
attempt_id BIGINT NOT NULL REFERENCES assessment_attempts(id) ON DELETE CASCADE,
question_id BIGINT NOT NULL REFERENCES assessment_questions(id),
question_type VARCHAR(50) NOT NULL,
points INT NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
UNIQUE (attempt_id, question_id)
);
CREATE TABLE IF NOT EXISTS assessment_attempt_answers (
id BIGSERIAL PRIMARY KEY,
attempt_id BIGINT NOT NULL REFERENCES assessment_attempts(id) ON DELETE CASCADE,
question_id BIGINT NOT NULL REFERENCES assessment_questions(id) ON DELETE CASCADE,
-- For MCQ / TRUE_FALSE
selected_option_id BIGINT
REFERENCES assessment_question_options(id),
-- For SHORT_ANSWER
submitted_text TEXT,
is_correct BOOLEAN,
awarded_points INT NOT NULL DEFAULT 0,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
UNIQUE (attempt_id, question_id),
CHECK (
(selected_option_id IS NOT NULL AND submitted_text IS NULL)
OR
(selected_option_id IS NULL AND submitted_text IS NOT NULL)
)
);
ALTER TABLE assessment_attempts
ADD CONSTRAINT chk_attempt_status
CHECK (status IN ('IN_PROGRESS', 'SUBMITTED', 'EVALUATED'));
ALTER TABLE assessment_attempt_questions
ADD CONSTRAINT chk_attempt_question_type
CHECK (question_type IN ('MULTIPLE_CHOICE', 'TRUE_FALSE', 'SHORT_ANSWER'));
CREATE TABLE refresh_tokens (
id BIGSERIAL PRIMARY KEY,
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
token TEXT NOT NULL UNIQUE,
expires_at TIMESTAMPTZ NOT NULL,
revoked BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE otps (
id BIGSERIAL PRIMARY KEY,
user_id BIGSERIAL NOT NULL,
sent_to VARCHAR(255) NOT NULL,
medium VARCHAR(50) NOT NULL, -- email, sms
otp_for VARCHAR(50) NOT NULL, -- register, reset
otp VARCHAR(10) NOT NULL,
used BOOLEAN NOT NULL DEFAULT FALSE,
used_at TIMESTAMPTZ,
expires_at TIMESTAMPTZ NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE IF NOT EXISTS notifications (
id BIGSERIAL PRIMARY KEY,
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
type TEXT NOT NULL CHECK (
type IN (
'course_enrolled',
'lesson_completed',
'assessment_assigned',
'assessment_submitted',
'assessment_graded',
'course_completed',
'certificate_issued',
'announcement',
'otp_sent',
'signup_welcome',
'system_alert'
)
),
level TEXT NOT NULL CHECK (
level IN ('info', 'warning', 'success', 'error')
),
channel TEXT CHECK (
channel IN ('email', 'sms', 'push', 'in_app')
),
title TEXT NOT NULL,
message TEXT NOT NULL,
payload JSONB,
is_read BOOLEAN NOT NULL DEFAULT FALSE,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
read_at TIMESTAMPTZ
);
CREATE TABLE global_settings (
key TEXT PRIMARY KEY,
value TEXT NOT NULL,
created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE IF NOT EXISTS reported_issues (
id BIGSERIAL PRIMARY KEY,
user_id BIGINT NOT NULL REFERENCES users(id),
user_role VARCHAR(255) NOT NULL,
subject TEXT NOT NULL,
description TEXT NOT NULL,
issue_type TEXT NOT NULL,
-- e.g., "deposit", "withdrawal", "bet", "technical"
status TEXT NOT NULL DEFAULT 'pending',
-- pending, in_progress, resolved, rejected
metadata JSONB,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);