workflow/src/main/resources/db/schema.sql
2025-07-31 21:24:31 +08:00

180 lines
9.4 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

DROP TABLE IF EXISTS `wk_user`;
CREATE TABLE `wk_user`
(
`id` bigint(64) NOT NULL AUTO_INCREMENT PRIMARY KEY COMMENT '主键',
`username` VARCHAR(32) NOT NULL UNIQUE COMMENT '用户名',
`nickname` VARCHAR(32) DEFAULT '默认用户' COMMENT '昵称',
`password` VARCHAR(256) NOT NULL COMMENT '加密后的密码',
`email` VARCHAR(32) UNIQUE COMMENT '邮箱',
`birthday` DATETIME DEFAULT NULL COMMENT '生日',
`sex` INT(2) DEFAULT NULL COMMENT '性别,男-1,女-2',
`phone` VARCHAR(15) DEFAULT NULL UNIQUE COMMENT '手机号',
`status` INT(2) NOT NULL DEFAULT 1 COMMENT '状态 -1删除 0警用 1启用',
`create_time` DATETIME NOT NULL DEFAULT NOW() COMMENT '创建时间',
`update_time` DATETIME NOT NULL DEFAULT NOW() ON UPDATE NOW() COMMENT '上次更新时间',
`last_login_time` DATETIME DEFAULT NULL COMMENT '上次登录时间'
) ENGINE = INNODB
DEFAULT CHARSET = UTF8 COMMENT '用户表';
DROP TABLE IF EXISTS `wk_role`;
CREATE TABLE `wk_role`
(
`id` BIGINT(64) NOT NULL AUTO_INCREMENT PRIMARY KEY COMMENT '主键',
`name` VARCHAR(32) NOT NULL UNIQUE COMMENT '角色名',
`description` VARCHAR(100) DEFAULT NULL COMMENT '描述',
`create_time` DATETIME NOT NULL DEFAULT NOW() COMMENT '创建时间',
`update_time` DATETIME NOT NULL DEFAULT NOW() ON UPDATE NOW() COMMENT '更新时间'
) ENGINE = INNODB
DEFAULT CHARSET = UTF8 COMMENT '角色表';
DROP TABLE IF EXISTS `wk_permission`;
CREATE TABLE `wk_permission`
(
`id` BIGINT AUTO_INCREMENT COMMENT '主键',
`name` VARCHAR(32) NOT NULL COMMENT '权限名',
`url` VARCHAR(1000) NULL COMMENT '类型为页面时,代表前端路由地址,类型为按钮时,代表后端接口地址',
`type` INT NOT NULL COMMENT '权限类型,页面-1,按钮-2',
`permission` VARCHAR(50) NULL COMMENT '权限表达式',
`method` VARCHAR(50) NULL COMMENT '后端接口访问方式',
`sort` INT NOT NULL COMMENT '排序',
`parent_id` BIGINT NOT NULL COMMENT '父级ID',
`create_time` DATETIME DEFAULT NOW() COMMENT '创建时间',
`update_time` DATETIME DEFAULT NOW() ON UPDATE NOW() COMMENT '更新时间',
PRIMARY KEY (`id`),
UNIQUE INDEX `name` (`name`)
) ENGINE = InnoDB
AUTO_INCREMENT = 1072806379384868866
DEFAULT CHARSET = utf8mb4
COLLATE = utf8mb4_unicode_ci
COMMENT = '权限表';
DROP TABLE IF EXISTS `wk_role_permission`;
CREATE TABLE `wk_role_permission`
(
`role_id` BIGINT NOT NULL COMMENT '角色ID',
`permission_id` BIGINT NOT NULL COMMENT '权限ID',
PRIMARY KEY (`role_id`, `permission_id`),
CONSTRAINT `fk_role_permission_permission`
FOREIGN KEY (`permission_id`)
REFERENCES `wk_permission` (`id`),
CONSTRAINT `fk_role_permission_role`
FOREIGN KEY (`role_id`)
REFERENCES `wk_role` (`id`)
) ENGINE = InnoDB
DEFAULT CHARSET = utf8mb4
COLLATE = utf8mb4_unicode_ci
COMMENT = '角色权限表';
DROP TABLE IF EXISTS `wk_role_user`;
CREATE TABLE `wk_role_user`
(
`role_id` BIGINT NOT NULL COMMENT '角色ID',
`user_id` BIGINT NOT NULL COMMENT '用户ID',
PRIMARY KEY (`role_id`, `user_id`),
CONSTRAINT `fk_role_user_role`
FOREIGN KEY (`role_id`)
REFERENCES `wk_role` (`id`),
CONSTRAINT `fk_role_user_user`
FOREIGN KEY (`user_id`)
REFERENCES `wk_user` (`id`)
) ENGINE = InnoDB
DEFAULT CHARSET = utf8mb4
COLLATE = utf8mb4_unicode_ci
COMMENT = '角色用户表';
DROP TABLE IF EXISTS `wk_notebooks`;
CREATE TABLE `wk_notebooks`
(
id BIGINT AUTO_INCREMENT PRIMARY KEY COMMENT '笔记本主键', -- 笔记本唯一标识
user_id bigint(64) NOT NULL COMMENT '所属用户ID', -- 笔记本所有者
name VARCHAR(100) NOT NULL COMMENT '笔记本名称', -- 显示名称
color VARCHAR(20) COMMENT '笔记本颜色标记用于UI显示', -- 如#FF0000
icon VARCHAR(50) COMMENT '笔记本图标标识', -- 如media-book
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '最后更新时间',
notes_count INT DEFAULT 0 COMMENT '包含的笔记数量', -- 用于快速统计
FOREIGN KEY (user_id) REFERENCES wk_user (id) ON DELETE CASCADE,
CONSTRAINT chk_notebook_name CHECK (name <> '') -- 名称不能为空
) COMMENT '用户笔记本';
DROP TABLE IF EXISTS `wk_notes`;
CREATE TABLE `wk_notes`
(
id BIGINT AUTO_INCREMENT PRIMARY KEY COMMENT '笔记唯一标识',
user_id bigint(64) NOT NULL COMMENT '作者用户ID',
notebook_id BIGINT COMMENT '所属笔记本ID可为空',
title VARCHAR(255) COMMENT '笔记标题,可为空(自动提取内容首行)',
content TEXT NOT NULL COMMENT '笔记正文内容支持Markdown格式',
preview_text VARCHAR(200) COMMENT '内容预览自动提取前200字符',
word_count INTEGER DEFAULT 0 COMMENT '自动计算的字数统计',
is_pinned BOOLEAN DEFAULT FALSE COMMENT '是否置顶显示',
is_archived BOOLEAN DEFAULT FALSE COMMENT '是否归档(不显示在默认列表中)',
is_favorite BOOLEAN DEFAULT FALSE COMMENT '是否标记为收藏',
password_protected BOOLEAN DEFAULT FALSE COMMENT '是否需要密码查看',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '最后编辑时间',
reminder TIMESTAMP COMMENT '提醒时间,为空表示无提醒',
cover_image VARCHAR(255) COMMENT '封面图片URL',
FOREIGN KEY (user_id) REFERENCES wk_user (id) ON DELETE CASCADE,
FOREIGN KEY (notebook_id) REFERENCES wk_notebooks (id) ON DELETE SET NULL,
CONSTRAINT chk_content_length CHECK (LENGTH(content) > 0) -- 内容不能为空
) COMMENT '核心笔记内容表,存储用户的所有笔记数据';
DROP TABLE IF EXISTS `wk_tags`;
CREATE TABLE `wk_tags`
(
id BIGINT AUTO_INCREMENT PRIMARY KEY COMMENT '标签唯一标识',
user_id bigint(64) NOT NULL COMMENT '所属用户ID',
name VARCHAR(50) NOT NULL COMMENT '标签名称',
color VARCHAR(20) COMMENT '标签颜色用于UI显示',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
usage_count INT DEFAULT 1 COMMENT '标签使用次数,用于排序',
UNIQUE (user_id, name) COMMENT '同一用户的标签名必须唯一',
FOREIGN KEY (user_id) REFERENCES wk_user (id) ON DELETE CASCADE,
CONSTRAINT chk_tag_name CHECK (name <> '') -- 标签名不能为空
) COMMENT '用户自定义标签表,用于多维度分类笔记';
DROP TABLE IF EXISTS `wk_note_tags`;
CREATE TABLE `wk_note_tags`
(
note_id BIGINT NOT NULL COMMENT '关联的笔记ID',
tag_id BIGINT NOT NULL COMMENT '关联的标签ID',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '关联创建时间',
PRIMARY KEY (note_id, tag_id) COMMENT '联合主键,防止重复关联',
FOREIGN KEY (note_id) REFERENCES wk_notes (id) ON DELETE CASCADE,
FOREIGN KEY (tag_id) REFERENCES wk_tags (id) ON DELETE CASCADE
) COMMENT '笔记和标签的多对多关联表';
DROP TABLE IF EXISTS `wk_attachments`;
CREATE TABLE wk_attachments
(
id BIGINT AUTO_INCREMENT PRIMARY KEY COMMENT '附件唯一标识',
note_id BIGINT NOT NULL COMMENT '所属笔记ID',
file_path VARCHAR(255) NOT NULL COMMENT '文件存储路径',
file_type VARCHAR(50) NOT NULL COMMENT '文件MIME类型如image/png',
file_name VARCHAR(255) NOT NULL COMMENT '原始文件名',
file_size INTEGER NOT NULL COMMENT '文件大小(字节)',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '上传时间',
thumbnail_path VARCHAR(255) COMMENT '缩略图路径(针对图片)',
FOREIGN KEY (note_id) REFERENCES wk_notes (id) ON DELETE CASCADE,
CONSTRAINT chk_file_size CHECK (file_size > 0) -- 文件大小必须为正
) COMMENT '笔记附件表,存储用户上传的各类文件';
# -- 用户相关索引
# CREATE INDEX idx_notes_user ON wk_notes (user_id) COMMENT '加速按用户查询笔记';
# CREATE INDEX idx_tags_user ON wk_tags (user_id) COMMENT '加速按用户查询标签';
# CREATE INDEX idx_notebooks_user ON wk_notebooks (user_id) COMMENT '加速按用户查询笔记本';
#
# -- 笔记内容检索索引
# CREATE INDEX idx_notes_notebook ON wk_notes (notebook_id) COMMENT '加速按笔记本查询笔记';
# CREATE INDEX idx_notes_title ON wk_notes (title) COMMENT '加速按标题搜索笔记';
# CREATE INDEX idx_notes_created ON wk_notes (created_at) COMMENT '加速按创建时间排序';
# CREATE INDEX idx_notes_updated ON wk_notes (updated_at) COMMENT '加速按更新时间排序';
#
# -- 全文检索索引(MySQL示例)
# CREATE FULLTEXT INDEX ft_note_content ON wk_notes (title, content)
# COMMENT '支持对标题和内容的全文检索';
#
# -- 标签查询优化
# CREATE INDEX idx_tags_name ON wk_tags (name) COMMENT '加速标签名称搜索';