303 lines
9.2 KiB
Text
303 lines
9.2 KiB
Text
// E-Learning Platform - Enhanced ERD with Constraints
|
|
// Version 2.0 - Improved with NOT NULL, CHECK, DEFAULT, and UNIQUE constraints
|
|
|
|
Table users {
|
|
id int [pk, increment]
|
|
name varchar [not null]
|
|
email varchar [unique, not null]
|
|
password varchar [not null]
|
|
role varchar [not null, default: 'student', note: 'admin | instructor | student']
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
email [unique]
|
|
role
|
|
}
|
|
}
|
|
|
|
Table courses {
|
|
id int [pk, increment]
|
|
categories_id int [ref: > categories.id]
|
|
title jsonb [not null, note: '{ "th": "...", "en": "..." }']
|
|
description jsonb [note: '{ "th": "...", "en": "..." }']
|
|
price decimal [not null, default: 0, note: 'must be >= 0']
|
|
is_free boolean [not null, default: false]
|
|
status varchar [not null, default: 'draft', note: 'draft | pending | approved | rejected']
|
|
instructor_id int [not null, ref: > users.id]
|
|
approved_by int [ref: > users.id, note: 'admin user id']
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
instructor_id
|
|
categories_id
|
|
status
|
|
(instructor_id, status)
|
|
}
|
|
}
|
|
|
|
Table categories {
|
|
id int [pk, increment]
|
|
name jsonb [not null, note: 'multi-language category name']
|
|
description jsonb [note: 'optional']
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
}
|
|
|
|
Table chapters {
|
|
id int [pk, increment]
|
|
course_id int [not null, ref: > courses.id]
|
|
title jsonb [not null, note: 'multi-language']
|
|
sort_order int [not null, default: 0, note: 'must be >= 0']
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
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: 'video | pdf | text | quiz']
|
|
sort_order int [not null, default: 0, note: 'must be >= 0']
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
chapter_id
|
|
(chapter_id, sort_order)
|
|
type
|
|
}
|
|
}
|
|
|
|
Table quizzes {
|
|
id int [pk, increment]
|
|
lesson_id int [not null, ref: > lessons.id]
|
|
title jsonb [not null, note: 'multi-language']
|
|
passing_score int [not null, default: 60, note: 'must be 0-100']
|
|
time_limit int [note: 'in minutes, must be > 0 if set']
|
|
max_attempts int [note: 'null = unlimited']
|
|
cooldown_minutes int [note: 'waiting time between attempts']
|
|
score_policy varchar [default: 'highest', note: 'highest | latest | first | average']
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
lesson_id
|
|
}
|
|
}
|
|
|
|
Table questions {
|
|
id int [pk, increment]
|
|
quiz_id int [not null, ref: > quizzes.id]
|
|
question jsonb [not null, note: 'multi-language']
|
|
question_type varchar [not null, default: 'multiple_choice', note: 'multiple_choice | true_false']
|
|
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 [not null, default: `now()`]
|
|
|
|
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]
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
question_id
|
|
}
|
|
}
|
|
|
|
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: 'enrolled | completed']
|
|
progress_percentage int [not null, default: 0, note: '0-100']
|
|
certificate_issued boolean [not null, default: false]
|
|
certificate_id varchar [unique, note: 'unique certificate identifier']
|
|
enrolled_at datetime [not null, default: `now()`]
|
|
completed_at datetime [note: 'when status changed to completed']
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
(user_id, course_id) [unique, name: 'unique_enrollment']
|
|
user_id
|
|
course_id
|
|
status
|
|
}
|
|
}
|
|
|
|
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
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
(user_id, lesson_id) [unique]
|
|
user_id
|
|
lesson_id
|
|
}
|
|
}
|
|
|
|
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]
|
|
started_at datetime [not null, default: `now()`]
|
|
completed_at datetime
|
|
created_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
user_id
|
|
quiz_id
|
|
(user_id, quiz_id)
|
|
(user_id, quiz_id, attempt_number)
|
|
}
|
|
}
|
|
|
|
Table announcements {
|
|
id int [pk, increment]
|
|
course_id int [not null, ref: > courses.id]
|
|
instructor_id int [not null, ref: > users.id]
|
|
title jsonb [not null, note: 'multi-language']
|
|
content jsonb [not null, note: 'multi-language']
|
|
is_pinned boolean [not null, default: false, note: 'pin important announcements to top']
|
|
published_at datetime [note: 'scheduled publish date, null = publish immediately']
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
course_id
|
|
instructor_id
|
|
(course_id, is_pinned, published_at)
|
|
(course_id, 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 or file path']
|
|
file_size int [not null, note: 'in bytes']
|
|
mime_type varchar [not null]
|
|
created_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
announcement_id
|
|
}
|
|
}
|
|
|
|
Table orders {
|
|
id int [pk, increment]
|
|
user_id int [not null, ref: > users.id]
|
|
total_amount decimal [not null, default: 0, note: 'must be >= 0']
|
|
status varchar [not null, default: 'pending', note: 'pending | paid | cancelled']
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
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, note: 'must be >= 0']
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_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 etc.']
|
|
transaction_id varchar [unique, note: 'unique transaction ID from payment provider']
|
|
amount decimal [not null, note: 'must be > 0']
|
|
status varchar [not null, default: 'pending', note: 'pending | success | failed']
|
|
paid_at datetime
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
order_id
|
|
transaction_id [unique]
|
|
status
|
|
}
|
|
}
|
|
|
|
Table instructor_balances {
|
|
id int [pk, increment]
|
|
instructor_id int [not null, unique, ref: > users.id, note: 'one balance record per instructor']
|
|
available_amount decimal [not null, default: 0, note: 'must be >= 0']
|
|
withdrawn_amount decimal [not null, default: 0, note: 'must be >= 0']
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
instructor_id [unique]
|
|
}
|
|
}
|
|
|
|
Table withdrawal_requests {
|
|
id int [pk, increment]
|
|
instructor_id int [not null, ref: > users.id]
|
|
amount decimal [not null, note: 'must be > 0']
|
|
status varchar [not null, default: 'pending', note: 'pending | approved | rejected | paid']
|
|
approved_by int [ref: > users.id, note: 'admin user id']
|
|
rejected_reason varchar [note: 'reason if rejected']
|
|
created_at datetime [not null, default: `now()`]
|
|
updated_at datetime [not null, default: `now()`]
|
|
|
|
indexes {
|
|
instructor_id
|
|
status
|
|
(instructor_id, status)
|
|
}
|
|
}
|
|
|
|
// Additional helpful notes:
|
|
// 1. All foreign keys should have ON DELETE actions defined during implementation
|
|
// 2. Suggested ON DELETE actions:
|
|
// - courses.instructor_id: RESTRICT (prevent deleting instructor with courses)
|
|
// - enrollments: CASCADE (delete enrollments when user/course deleted)
|
|
// - announcements: CASCADE (delete announcements when course deleted)
|
|
// - quiz_attempts: CASCADE (delete attempts when user deleted)
|
|
// 3. All jsonb fields support multi-language: { "th": "...", "en": "..." }
|
|
// 4. Indexes are suggested for common query patterns
|
|
// 5. Consider adding soft delete (deleted_at) for important tables
|