CREATE TABLE IF NOT EXISTS users ( id BIGSERIAL PRIMARY KEY, first_name VARCHAR(255) NOT NULL, last_name VARCHAR(255) NOT NULL, nick_name VARCHAR(100), email VARCHAR(255) UNIQUE, phone_number VARCHAR(20) UNIQUE, role VARCHAR(50) NOT NULL, -- SUPER_ADMIN, ORG_ADMIN, INSTRUCTOR, STUDENT, SUPPORT password BYTEA NOT NULL, age INT, education_level VARCHAR(100), country VARCHAR(100), region VARCHAR(100), email_verified BOOLEAN NOT NULL DEFAULT FALSE, phone_verified BOOLEAN NOT NULL DEFAULT FALSE, suspended BOOLEAN NOT NULL DEFAULT FALSE, suspended_at TIMESTAMPTZ, organization_id BIGINT, created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMPTZ, CHECK (email IS NOT NULL OR phone_number IS NOT NULL), UNIQUE (email, organization_id), UNIQUE (phone_number, organization_id) ); 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, sent_to VARCHAR(255) NOT NULL, medium VARCHAR(50) NOT NULL, -- email, sms otp_for VARCHAR(50) NOT NULL, -- login, reset_password, verify 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 organizations ( id BIGSERIAL PRIMARY KEY, name TEXT NOT NULL, slug TEXT UNIQUE NOT NULL, owner_id BIGINT NOT NULL REFERENCES users(id), is_active BOOLEAN NOT NULL DEFAULT TRUE, created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE courses ( id BIGSERIAL PRIMARY KEY, organization_id BIGINT NOT NULL REFERENCES organizations(id) ON DELETE CASCADE, instructor_id BIGINT NOT NULL REFERENCES users(id), title TEXT NOT NULL, description TEXT, level TEXT, language TEXT, is_published BOOLEAN NOT NULL DEFAULT FALSE, created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE course_modules ( id BIGSERIAL PRIMARY KEY, course_id BIGINT NOT NULL REFERENCES courses(id) ON DELETE CASCADE, title TEXT NOT NULL, position INT NOT NULL, created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE lessons ( id BIGSERIAL PRIMARY KEY, module_id BIGINT NOT NULL REFERENCES course_modules(id) ON DELETE CASCADE, title TEXT NOT NULL, content_type TEXT NOT NULL, -- video, article, quiz content_url TEXT, duration_minutes INT, position INT NOT NULL, created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE enrollments ( id BIGSERIAL PRIMARY KEY, course_id BIGINT NOT NULL REFERENCES courses(id) ON DELETE CASCADE, student_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, enrolled_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, completed_at TIMESTAMPTZ, UNIQUE (course_id, student_id) ); CREATE TABLE lesson_progress ( id BIGSERIAL PRIMARY KEY, lesson_id BIGINT NOT NULL REFERENCES lessons(id) ON DELETE CASCADE, student_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, completed BOOLEAN NOT NULL DEFAULT FALSE, completed_at TIMESTAMPTZ, UNIQUE (lesson_id, student_id) ); CREATE TABLE assessments ( id BIGSERIAL PRIMARY KEY, course_id BIGINT NOT NULL REFERENCES courses(id) ON DELETE CASCADE, title TEXT NOT NULL, type TEXT NOT NULL, -- quiz, assignment total_score INT NOT NULL, due_date TIMESTAMPTZ, created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP ); CREATE TABLE assessment_submissions ( id BIGSERIAL PRIMARY KEY, assessment_id BIGINT NOT NULL REFERENCES assessments(id) ON DELETE CASCADE, student_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, score INT, feedback TEXT, submitted_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, graded_at TIMESTAMPTZ, UNIQUE (assessment_id, student_id) ); 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 organization_settings ( organization_id BIGINT NOT NULL REFERENCES organizations(id) ON DELETE CASCADE, key TEXT NOT NULL, value TEXT NOT NULL, created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (organization_id, key) ); 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 );