You cannot select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

120 lines
9.0 KiB
SQL

This file contains ambiguous Unicode characters!

This file contains ambiguous Unicode characters that may be confused with others in your current locale. If your use case is intentional and legitimate, you can safely ignore this warning. Use the Escape button to highlight these characters.

CREATE DATABASE if not exists yxs_sms;
USE yxs_sms;
-- 用户表
CREATE TABLE IF NOT EXISTS users (
id varchar(64) NOT NULL COMMENT '用户ID雪花算法生成',
username varchar(50) NOT NULL UNIQUE COMMENT '用户名',
password varchar(255) NOT NULL COMMENT '密码(加密存储)',
email varchar(100) COMMENT '邮箱',
role int NOT NULL COMMENT '用户角色1=超级管理员2=普通管理员3=教师4=学生',
status int NOT NULL DEFAULT 1 COMMENT '用户状态0=禁用1=正常2=已删除',
created_time datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_time datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (id),
UNIQUE KEY uk_username (username),
INDEX idx_role (role),
INDEX idx_status (status)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户表';
-- 初始化超级管理员账号密码admin123
INSERT INTO users (id, username, password, email, role, status)
VALUES ('1', 'admin', '$2a$10$hD.BTeMvHjwopHom7wyNsOD4zgFbQuF5ZYRflikt9ee.UrlzrqToi', 'admin@yuxingshi.com', 1, 1)
ON DUPLICATE KEY UPDATE id = id;
-- 班级表
CREATE TABLE IF NOT EXISTS classes (
id varchar(64) NOT NULL COMMENT '班级ID雪花算法生成',
class_name varchar(50) NOT NULL UNIQUE COMMENT '班级名称',
class_code varchar(30) NOT NULL UNIQUE COMMENT '班级代码',
description varchar(255) COMMENT '班级描述',
status int NOT NULL DEFAULT 1 COMMENT '班级状态0=禁用1=正常',
created_time datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_time datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (id),
UNIQUE KEY uk_class_name (class_name),
UNIQUE KEY uk_class_code (class_code),
INDEX idx_status (status)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='班级表';
-- 学生表
CREATE TABLE IF NOT EXISTS students (
id varchar(64) NOT NULL COMMENT '学生ID雪花算法生成',
user_id varchar(64) NOT NULL COMMENT '用户ID关联users表',
class_id varchar(64) NOT NULL COMMENT '班级ID关联classes表',
student_no varchar(30) NOT NULL UNIQUE COMMENT '学号',
real_name varchar(50) NOT NULL COMMENT '真实姓名',
gender int COMMENT '性别0=女1=男',
phone varchar(20) COMMENT '电话号码',
status int NOT NULL DEFAULT 1 COMMENT '学生状态0=禁用1=正常2=已毕业',
created_time datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_time datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (id),
UNIQUE KEY uk_user_id (user_id),
UNIQUE KEY uk_student_no (student_no),
KEY fk_class_id (class_id),
CONSTRAINT fk_classes FOREIGN KEY (class_id) REFERENCES classes(id),
CONSTRAINT fk_users FOREIGN KEY (user_id) REFERENCES users(id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='学生表';
-- 教师表
CREATE TABLE IF NOT EXISTS teachers (
id varchar(64) NOT NULL COMMENT '教师ID雪花算法生成',
user_id varchar(64) UNIQUE COMMENT '关联的用户ID',
teacher_no VARCHAR(50) UNIQUE NOT NULL COMMENT '教师工号',
real_name VARCHAR(100) NOT NULL COMMENT '教师真实姓名',
department VARCHAR(100) COMMENT '所属部门',
phone VARCHAR(20) COMMENT '电话号码',
status INT DEFAULT 1 COMMENT '状态1=启用0=禁用',
created_time DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_time DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='教师表';
-- 课程表
CREATE TABLE IF NOT EXISTS courses (
id varchar(64) NOT NULL COMMENT '课程ID雪花算法生成',
teacher_id varchar(64) NOT NULL COMMENT '教师ID外键',
course_name VARCHAR(200) NOT NULL COMMENT '课程名称',
course_code VARCHAR(100) UNIQUE NOT NULL COMMENT '课程代码',
credit DECIMAL(3,1) COMMENT '学分',
total_hours INT COMMENT '总课时',
description TEXT COMMENT '课程描述',
status INT DEFAULT 1 COMMENT '状态1=启用0=禁用',
created_time DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_time DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (id),
FOREIGN KEY (teacher_id) REFERENCES teachers(id) ON DELETE RESTRICT COMMENT '教师外键约束'
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='课程表';
-- 创建索引
CREATE INDEX idx_teacher_id ON courses(teacher_id);
CREATE INDEX idx_course_code ON courses(course_code);
CREATE INDEX idx_teacher_no ON teachers(teacher_no);
-- 课程成绩表
CREATE TABLE IF NOT EXISTS course_scores (
id varchar(64) NOT NULL COMMENT '成绩ID雪花算法生成',
course_id varchar(64) NOT NULL COMMENT '课程ID外键',
student_id varchar(64) NOT NULL COMMENT '学生ID外键',
usual_score DECIMAL(5,2) COMMENT '平时成绩(0-100)',
midterm_score DECIMAL(5,2) COMMENT '期中成绩(0-100)',
final_score DECIMAL(5,2) COMMENT '期末成绩(0-100)',
total_score DECIMAL(5,2) COMMENT '总成绩(0-100)',
grade VARCHAR(10) COMMENT '等级(A/B/C/D/F)',
status INT DEFAULT 1 COMMENT '状态1=正常0=删除',
remark VARCHAR(500) COMMENT '备注',
created_time DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_time DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (id),
FOREIGN KEY (course_id) REFERENCES courses(id) ON DELETE RESTRICT COMMENT '课程外键',
FOREIGN KEY (student_id) REFERENCES students(id) ON DELETE RESTRICT COMMENT '学生外键',
UNIQUE KEY uk_course_student (course_id, student_id) COMMENT '同一学生同一课程唯一'
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='课程成绩表';
-- 创建索引
CREATE INDEX idx_course_id ON course_scores(course_id);
CREATE INDEX idx_student_id ON course_scores(student_id);
CREATE INDEX idx_grade ON course_scores(grade);