// E-Learning Platform - Enhanced ERD v3.0 // Major improvements: // 1. Separated roles table with display values // 2. Separated user_profiles table // 3. Added created_by/updated_by audit trails // 4. Made updated_at/updated_by nullable // 5. Used ENUM for status fields // 6. Optimized audit trail placement // 7. Added announcement status and multi-instructor support // ============================================ // CORE TABLES // ============================================ Table roles { id int [pk, increment] code varchar [unique, not null, note: 'ADMIN | INSTRUCTOR | STUDENT'] name jsonb [not null, note: '{"th": "ผู้ดูแลระบบ", "en": "Administrator"}'] description jsonb [note: 'role description'] created_at datetime [not null, default: `now()`] indexes { code [unique] } } Table users { id int [pk, increment] username varchar [unique, not null] email varchar [unique, not null] password varchar [not null] role_id int [not null, ref: > roles.id] email_verified_at datetime created_at datetime [not null, default: `now()`] updated_at datetime indexes { username [unique] email [unique] role_id } } Table user_profiles { id int [pk, increment] user_id int [unique, not null, ref: > users.id] prefix varchar [note: 'Mr. | Mrs. | Ms. | Dr. etc.'] first_name varchar [not null] last_name varchar [not null] phone varchar avatar_url varchar birth_date datetime created_at datetime [not null, default: `now()`] updated_at datetime updated_by int [ref: > users.id] indexes { user_id [unique] } } Table categories { id int [pk, increment] name jsonb [not null, note: 'multi-language category name'] slug varchar [unique, not null] description jsonb icon varchar [note: 'icon identifier'] sort_order int [not null, default: 0] is_active boolean [not null, default: true] created_at datetime [not null, default: `now()`] created_by int [not null, ref: > users.id] updated_at datetime updated_by int [ref: > users.id] indexes { slug [unique] is_active sort_order } } // ============================================ // COURSE STRUCTURE // ============================================ Table courses { id int [pk, increment] category_id int [ref: > categories.id] title jsonb [not null, note: '{"th": "...", "en": "..."}'] slug varchar [unique, not null] description jsonb thumbnail_url varchar price decimal [not null, default: 0, note: 'must be >= 0'] is_free boolean [not null, default: false] have_certificate boolean [not null, default: false, note: 'issue certificate upon completion'] status varchar [not null, default: 'DRAFT', note: 'ENUM: DRAFT | PENDING | APPROVED | REJECTED | ARCHIVED'] approved_by int [ref: > users.id, note: 'admin user id'] approved_at datetime rejection_reason varchar created_at datetime [not null, default: `now()`] created_by int [not null, ref: > users.id, note: 'primary instructor'] updated_at datetime updated_by int [ref: > users.id] indexes { category_id slug [unique] status created_by (status, is_free) (category_id, status) } } Table course_instructors { id int [pk, increment] course_id int [not null, ref: > courses.id] user_id int [not null, ref: > users.id] is_primary boolean [not null, default: false, note: 'primary instructor'] joined_at datetime [not null, default: `now()`] indexes { (course_id, user_id) [unique] course_id user_id is_primary } } Table course_approvals { id int [pk, increment] course_id int [not null, ref: > courses.id] submitted_by int [not null, ref: > users.id, note: 'instructor who submitted'] reviewed_by int [ref: > users.id, note: 'admin who reviewed'] action varchar [not null, note: 'ENUM: SUBMITTED | APPROVED | REJECTED'] previous_status varchar [not null, note: 'status before this action'] new_status varchar [not null, note: 'status after this action'] comment text [note: 'admin comment or rejection reason'] created_at datetime [not null, default: `now()`] Note: 'Tracks complete approval workflow history' indexes { course_id submitted_by reviewed_by action created_at (course_id, created_at) } } Table chapters { id int [pk, increment] course_id int [not null, ref: > courses.id] title jsonb [not null, note: 'multi-language'] description jsonb sort_order int [not null, default: 0, note: 'must be >= 0'] is_published boolean [not null, default: false] created_at datetime [not null, default: `now()`] updated_at datetime Note: 'No created_by/updated_by - use course audit trail' indexes { course_id (course_id, sort_order) } } Table lessons { id int [pk, increment] chapter_id int [not null, ref: > chapters.id] title jsonb [not null, note: 'multi-language'] content jsonb [note: 'multi-language lesson content'] type varchar [not null, note: 'ENUM: VIDEO QUIZ'] duration_minutes int [note: 'estimated duration'] sort_order int [not null, default: 0, note: 'must be >= 0'] is_sequential boolean [not null, default: true] prerequisite_lesson_ids jsonb [note: 'array of lesson IDs [1, 2, 3]'] require_pass_quiz boolean [default: false] is_published boolean [not null, default: false] created_at datetime [not null, default: `now()`] updated_at datetime Note: 'No created_by/updated_by - use course audit trail' indexes { chapter_id (chapter_id, sort_order) type } } // ============================================ // QUIZ SYSTEM // ============================================ Table quizzes { id int [pk, increment] lesson_id int [not null, ref: > lessons.id] title jsonb [not null, note: 'multi-language'] description jsonb passing_score int [not null, default: 60, note: 'must be 0-100'] time_limit int [note: 'in minutes, must be > 0 if set'] shuffle_questions boolean [not null, default: false] shuffle_choices boolean [not null, default: false] show_answers_after_completion boolean [not null, default: true, note: 'show correct answers after quiz completion'] created_at datetime [not null, default: `now()`] created_by int [not null, ref: > users.id] updated_at datetime updated_by int [ref: > users.id] indexes { lesson_id } } Table questions { id int [pk, increment] quiz_id int [not null, ref: > quizzes.id] question jsonb [not null, note: 'multi-language'] explanation jsonb [note: 'answer explanation'] question_type varchar [not null, default: 'MULTIPLE_CHOICE', note: 'ENUM: MULTIPLE_CHOICE | TRUE_FALSE | SHORT_ANSWER'] score int [not null, default: 1, note: 'must be > 0'] sort_order int [not null, default: 0] created_at datetime [not null, default: `now()`] updated_at datetime Note: 'No created_by/updated_by - saved with quiz' indexes { quiz_id (quiz_id, sort_order) } } Table choices { id int [pk, increment] question_id int [not null, ref: > questions.id] text jsonb [not null, note: 'multi-language'] is_correct boolean [not null, default: false] sort_order int [not null, default: 0] indexes { question_id } } // ============================================ // STUDENT PROGRESS // ============================================ Table enrollments { id int [pk, increment] user_id int [not null, ref: > users.id] course_id int [not null, ref: > courses.id] status varchar [not null, default: 'ENROLLED', note: 'ENUM: ENROLLED | IN_PROGRESS | COMPLETED | DROPPED'] progress_percentage int [not null, default: 0, note: '0-100'] enrolled_at datetime [not null, default: `now()`] started_at datetime [note: 'first lesson access'] completed_at datetime last_accessed_at datetime Note: 'No created_by/updated_by - system managed' indexes { (user_id, course_id) [unique, name: 'unique_enrollment'] user_id course_id status last_accessed_at } } Table certificates { id int [pk, increment] user_id int [not null, ref: > users.id] course_id int [not null, ref: > courses.id] enrollment_id int [unique, not null, ref: > enrollments.id] file_path varchar [not null, note: 'S3 path to certificate PDF'] issued_at datetime [not null, default: `now()`] indexes { user_id course_id enrollment_id [unique] (user_id, course_id) } } Table lesson_progress { id int [pk, increment] user_id int [not null, ref: > users.id] lesson_id int [not null, ref: > lessons.id] is_completed boolean [not null, default: false] completed_at datetime video_progress_seconds int [default: 0] video_duration_seconds int video_progress_percentage decimal(5,2) last_watched_at datetime created_at datetime [not null, default: `now()`] updated_at datetime Note: 'No created_by/updated_by - student action only' indexes { (user_id, lesson_id) [unique] user_id lesson_id last_watched_at } } Table quiz_attempts { id int [pk, increment] user_id int [not null, ref: > users.id] quiz_id int [not null, ref: > quizzes.id] score int [not null, default: 0, note: '0-100'] total_questions int [not null] correct_answers int [not null, default: 0] is_passed boolean [not null, default: false] attempt_number int [not null, default: 1] answers jsonb [note: 'student answers for review'] started_at datetime [not null, default: `now()`] completed_at datetime Note: 'No updated_at - attempts are immutable after completion' indexes { user_id quiz_id (user_id, quiz_id) (user_id, quiz_id, attempt_number) } } // ============================================ // COMMUNICATION // ============================================ Table announcements { id int [pk, increment] course_id int [not null, ref: > courses.id] title jsonb [not null, note: 'multi-language'] content jsonb [not null, note: 'multi-language'] status varchar [not null, default: 'DRAFT', note: 'ENUM: DRAFT | PUBLISHED | ARCHIVED'] is_pinned boolean [not null, default: false] published_at datetime [note: 'scheduled publish date'] created_at datetime [not null, default: `now()`] created_by int [not null, ref: > users.id] updated_at datetime updated_by int [ref: > users.id] indexes { course_id created_by status (course_id, status, is_pinned, published_at) } } Table announcement_attachments { id int [pk, increment] announcement_id int [not null, ref: > announcements.id] file_name varchar [not null] file_path varchar [not null, note: 'S3 key'] file_size int [not null, note: 'bytes'] mime_type varchar [not null] created_at datetime [not null, default: `now()`] Note: 'No updated_at - attachments are immutable' indexes { announcement_id } } Table lesson_attachments { id int [pk, increment] lesson_id int [not null, ref: > lessons.id] file_name varchar [not null] file_path varchar [not null, note: 'S3 key'] file_size int [not null, note: 'bytes'] mime_type varchar [not null] description jsonb [note: 'multi-language'] sort_order int [not null, default: 0] created_at datetime [not null, default: `now()`] Note: 'No updated_at - use lesson audit trail' indexes { lesson_id (lesson_id, sort_order) } } // ============================================ // PAYMENT SYSTEM (Future) // ============================================ Table orders { id int [pk, increment] user_id int [not null, ref: > users.id] total_amount decimal [not null, default: 0] status varchar [not null, default: 'PENDING', note: 'ENUM: PENDING | PAID | CANCELLED | REFUNDED'] created_at datetime [not null, default: `now()`] updated_at datetime indexes { user_id status (user_id, status) } } Table order_items { id int [pk, increment] order_id int [not null, ref: > orders.id] course_id int [not null, ref: > courses.id] price decimal [not null] created_at datetime [not null, default: `now()`] indexes { order_id course_id } } Table payments { id int [pk, increment] order_id int [not null, ref: > orders.id] provider varchar [not null, note: 'stripe | paypal | promptpay'] transaction_id varchar [unique] amount decimal [not null] status varchar [not null, default: 'PENDING', note: 'ENUM: PENDING | SUCCESS | FAILED'] paid_at datetime created_at datetime [not null, default: `now()`] updated_at datetime indexes { order_id transaction_id [unique] status } } Table instructor_balances { id int [pk, increment] instructor_id int [not null, unique, ref: > users.id] available_amount decimal [not null, default: 0] withdrawn_amount decimal [not null, default: 0] created_at datetime [not null, default: `now()`] updated_at datetime indexes { instructor_id [unique] } } Table withdrawal_requests { id int [pk, increment] instructor_id int [not null, ref: > users.id] amount decimal [not null] status varchar [not null, default: 'PENDING', note: 'ENUM: PENDING | APPROVED | REJECTED | PAID'] approved_by int [ref: > users.id] approved_at datetime rejected_reason varchar created_at datetime [not null, default: `now()`] updated_at datetime updated_by int [ref: > users.id] indexes { instructor_id status (instructor_id, status) } } // ============================================ // NOTES & BEST PRACTICES // ============================================ // 1. ENUM Status Values: // - courses: DRAFT | PENDING | APPROVED | REJECTED | ARCHIVED // - enrollments: ENROLLED | IN_PROGRESS | COMPLETED | DROPPED // - announcements: DRAFT | PUBLISHED | ARCHIVED // - orders: PENDING | PAID | CANCELLED | REFUNDED // - payments: PENDING | SUCCESS | FAILED // - withdrawals: PENDING | APPROVED | REJECTED | PAID // - score_policy: HIGHEST | LATEST | FIRST | AVERAGE // - lesson_type: VIDEO | PDF | TEXT | QUIZ // - question_type: MULTIPLE_CHOICE | TRUE_FALSE | SHORT_ANSWER // 2. Audit Trail Strategy: // - Full audit (created_by, updated_by): courses, quizzes, categories, announcements // - Partial audit (created_by only): user_profiles // - No audit: student actions (enrollments, progress, attempts) // - No audit: child records saved with parent (questions, choices, chapters, lessons) // 3. Updated Fields: // - updated_at is NULL on creation, only set when actually updated // - updated_by is NULL on creation, only set when updated by someone // 4. Multi-Instructor Support: // - course_instructors table allows multiple instructors per course // - is_primary flag identifies main instructor // - created_by in courses table is the original creator // 5. Role System: // - roles table stores code (ADMIN) and display names ({"th": "ผู้ดูแลระบบ"}) // - Allows easy translation and role management // - users.role_id references roles.id // 6. User Profiles: // - Separated from users table for cleaner authentication // - Contains display information (name, bio, avatar) // - prefix field for Thai/international name prefixes // 7. Announcement Status: // - DRAFT: not visible to students // - PUBLISHED: visible to enrolled students // - ARCHIVED: hidden but kept for history // 8. Foreign Key Actions: // - users.role_id: RESTRICT (don't delete roles in use) // - courses.created_by: RESTRICT (don't delete instructors with courses) // - enrollments: CASCADE (delete with user/course) // - announcements: CASCADE (delete with course) // - quiz_attempts: CASCADE (delete with user) Ref: "certificates"."issued_at" < "certificates"."enrollment_id"