134 lines
4.4 KiB
SQL
134 lines
4.4 KiB
SQL
-- 用户表
|
|
CREATE TABLE users (
|
|
id TEXT PRIMARY KEY,
|
|
name TEXT NOT NULL CHECK(length(name) >= 2 AND length(name) <= 20),
|
|
phone TEXT UNIQUE NOT NULL CHECK(length(phone) = 11 AND phone LIKE '1%' AND substr(phone, 2, 1) BETWEEN '3' AND '9'),
|
|
password TEXT NOT NULL DEFAULT '',
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- 创建用户表索引
|
|
CREATE INDEX idx_users_phone ON users(phone);
|
|
CREATE INDEX idx_users_created_at ON users(created_at);
|
|
|
|
-- 题目表
|
|
CREATE TABLE questions (
|
|
id TEXT PRIMARY KEY,
|
|
content TEXT NOT NULL,
|
|
type TEXT NOT NULL CHECK(type IN ('single', 'multiple', 'judgment', 'text')),
|
|
options TEXT, -- JSON格式存储选项
|
|
answer TEXT NOT NULL,
|
|
analysis TEXT NOT NULL DEFAULT '',
|
|
score INTEGER NOT NULL CHECK(score > 0),
|
|
category TEXT NOT NULL DEFAULT '通用',
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- 创建题目表索引
|
|
CREATE INDEX idx_questions_type ON questions(type);
|
|
CREATE INDEX idx_questions_score ON questions(score);
|
|
CREATE INDEX idx_questions_category ON questions(category);
|
|
|
|
-- 题目类别表
|
|
CREATE TABLE question_categories (
|
|
id TEXT PRIMARY KEY,
|
|
name TEXT UNIQUE NOT NULL,
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
INSERT OR IGNORE INTO question_categories (id, name) VALUES ('default', '通用');
|
|
|
|
-- 考试科目表
|
|
CREATE TABLE exam_subjects (
|
|
id TEXT PRIMARY KEY,
|
|
name TEXT UNIQUE NOT NULL,
|
|
type_ratios TEXT NOT NULL,
|
|
category_ratios TEXT NOT NULL,
|
|
total_score INTEGER NOT NULL,
|
|
duration_minutes INTEGER NOT NULL DEFAULT 60,
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at DATETIME DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- 考试任务表
|
|
CREATE TABLE exam_tasks (
|
|
id TEXT PRIMARY KEY,
|
|
name TEXT NOT NULL,
|
|
subject_id TEXT NOT NULL,
|
|
start_at DATETIME NOT NULL,
|
|
end_at DATETIME NOT NULL,
|
|
selection_config TEXT,
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
FOREIGN KEY (subject_id) REFERENCES exam_subjects(id)
|
|
);
|
|
|
|
CREATE INDEX idx_exam_tasks_subject_id ON exam_tasks(subject_id);
|
|
|
|
-- 考试任务参与用户表
|
|
CREATE TABLE exam_task_users (
|
|
id TEXT PRIMARY KEY,
|
|
task_id TEXT NOT NULL,
|
|
user_id TEXT NOT NULL,
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE(task_id, user_id),
|
|
FOREIGN KEY (task_id) REFERENCES exam_tasks(id) ON DELETE CASCADE,
|
|
FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
|
|
);
|
|
|
|
CREATE INDEX idx_exam_task_users_task_id ON exam_task_users(task_id);
|
|
CREATE INDEX idx_exam_task_users_user_id ON exam_task_users(user_id);
|
|
|
|
-- 答题记录表
|
|
CREATE TABLE quiz_records (
|
|
id TEXT PRIMARY KEY,
|
|
user_id TEXT NOT NULL,
|
|
subject_id TEXT,
|
|
task_id TEXT,
|
|
total_score INTEGER NOT NULL,
|
|
correct_count INTEGER NOT NULL,
|
|
total_count INTEGER NOT NULL,
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
FOREIGN KEY (user_id) REFERENCES users(id),
|
|
FOREIGN KEY (subject_id) REFERENCES exam_subjects(id),
|
|
FOREIGN KEY (task_id) REFERENCES exam_tasks(id)
|
|
);
|
|
|
|
-- 创建答题记录表索引
|
|
CREATE INDEX idx_quiz_records_user_id ON quiz_records(user_id);
|
|
CREATE INDEX idx_quiz_records_created_at ON quiz_records(created_at);
|
|
CREATE INDEX idx_quiz_records_subject_id ON quiz_records(subject_id);
|
|
CREATE INDEX idx_quiz_records_task_id ON quiz_records(task_id);
|
|
|
|
-- 答题答案表
|
|
CREATE TABLE quiz_answers (
|
|
id TEXT PRIMARY KEY,
|
|
record_id TEXT NOT NULL,
|
|
question_id TEXT NOT NULL,
|
|
user_answer TEXT NOT NULL,
|
|
score INTEGER NOT NULL,
|
|
is_correct BOOLEAN NOT NULL,
|
|
created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
|
|
FOREIGN KEY (record_id) REFERENCES quiz_records(id),
|
|
FOREIGN KEY (question_id) REFERENCES questions(id)
|
|
);
|
|
|
|
-- 创建答题答案表索引
|
|
CREATE INDEX idx_quiz_answers_record_id ON quiz_answers(record_id);
|
|
CREATE INDEX idx_quiz_answers_question_id ON quiz_answers(question_id);
|
|
|
|
-- 系统配置表
|
|
CREATE TABLE system_configs (
|
|
id TEXT PRIMARY KEY,
|
|
config_type TEXT UNIQUE NOT NULL,
|
|
config_value TEXT NOT NULL,
|
|
updated_at DATETIME DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- 初始化抽题配置
|
|
INSERT INTO system_configs (id, config_type, config_value) VALUES
|
|
('1', 'quiz_config', '{"singleRatio":40,"multipleRatio":30,"judgmentRatio":20,"textRatio":10,"totalScore":100}');
|
|
|
|
-- 初始化管理员账号
|
|
INSERT INTO system_configs (id, config_type, config_value) VALUES
|
|
('2', 'admin_user', '{"username":"admin","password":"admin123"}');
|