-- ============================================ -- AIOJ 博客服务数据库表结构 -- 数据库: aioj_blog -- 描述: 用于用户发帖、分享技术经验、写文章 -- ============================================ -- 创建数据库 CREATE DATABASE IF NOT EXISTS `aioj_blog` DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci; USE `aioj_blog`; -- ============================================ -- 1. 文章分类表 -- ============================================ DROP TABLE IF EXISTS `blog_category`; CREATE TABLE `blog_category` ( `id` BIGINT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '分类ID', `name` VARCHAR(50) NOT NULL COMMENT '分类名称', `slug` VARCHAR(50) NOT NULL COMMENT '分类别名(用于URL)', `description` VARCHAR(200) DEFAULT NULL COMMENT '分类描述', `icon` VARCHAR(100) DEFAULT NULL COMMENT '分类图标', `parent_id` BIGINT UNSIGNED DEFAULT 0 COMMENT '父分类ID,0表示顶级分类', `sort_order` INT DEFAULT 0 COMMENT '排序权重,数值越大越靠前', `article_count` INT UNSIGNED DEFAULT 0 COMMENT '该分类下的文章数量', `is_deleted` TINYINT(1) DEFAULT 0 COMMENT '是否删除:0-否,1-是', `create_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `update_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), UNIQUE KEY `uk_slug` (`slug`), KEY `idx_parent_id` (`parent_id`), KEY `idx_sort_order` (`sort_order`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='文章分类表'; -- ============================================ -- 2. 文章标签表 -- ============================================ DROP TABLE IF EXISTS `blog_tag`; CREATE TABLE `blog_tag` ( `id` BIGINT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '标签ID', `name` VARCHAR(30) NOT NULL COMMENT '标签名称', `slug` VARCHAR(30) NOT NULL COMMENT '标签别名(用于URL)', `description` VARCHAR(200) DEFAULT NULL COMMENT '标签描述', `color` VARCHAR(7) DEFAULT NULL COMMENT '标签颜色(十六进制)', `article_count` INT UNSIGNED DEFAULT 0 COMMENT '该标签下的文章数量', `is_deleted` TINYINT(1) DEFAULT 0 COMMENT '是否删除:0-否,1-是', `create_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `update_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), UNIQUE KEY `uk_slug` (`slug`), KEY `idx_name` (`name`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='文章标签表'; -- ============================================ -- 3. 文章表 -- ============================================ DROP TABLE IF EXISTS `blog_article`; CREATE TABLE `blog_article` ( `id` BIGINT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '文章ID', `user_id` BIGINT UNSIGNED NOT NULL COMMENT '作者用户ID', `category_id` BIGINT UNSIGNED NOT NULL COMMENT '分类ID', `title` VARCHAR(200) NOT NULL COMMENT '文章标题', `slug` VARCHAR(200) DEFAULT NULL COMMENT '文章别名(用于URL,唯一)', `summary` VARCHAR(500) DEFAULT NULL COMMENT '文章摘要', `cover_image` VARCHAR(500) DEFAULT NULL COMMENT '封面图片URL', `content` MEDIUMTEXT NOT NULL COMMENT '文章内容(Markdown格式)', `content_html` MEDIUMTEXT DEFAULT NULL COMMENT '文章内容(HTML格式,缓存用)', `view_count` BIGINT UNSIGNED DEFAULT 0 COMMENT '浏览次数', `like_count` INT UNSIGNED DEFAULT 0 COMMENT '点赞数', `comment_count` INT UNSIGNED DEFAULT 0 COMMENT '评论数', `favorite_count` INT UNSIGNED DEFAULT 0 COMMENT '收藏数', `is_top` TINYINT(1) DEFAULT 0 COMMENT '是否置顶:0-否,1-是', `is_featured` TINYINT(1) DEFAULT 0 COMMENT '是否精选:0-否,1-是', `is_original` TINYINT(1) DEFAULT 1 COMMENT '是否原创:0-转载,1-原创', `source_url` VARCHAR(500) DEFAULT NULL COMMENT '转载来源URL', `status` TINYINT NOT NULL DEFAULT 0 COMMENT '文章状态:0-草稿,1-已发布,2-审核中,3-已下架', `publish_time` DATETIME DEFAULT NULL COMMENT '发布时间', `is_deleted` TINYINT(1) DEFAULT 0 COMMENT '是否删除:0-否,1-是', `create_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `update_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), UNIQUE KEY `uk_slug` (`slug`), KEY `idx_user_id` (`user_id`), KEY `idx_category_id` (`category_id`), KEY `idx_status` (`status`), KEY `idx_is_top` (`is_top`), KEY `idx_publish_time` (`publish_time`), KEY `idx_view_count` (`view_count`), FULLTEXT KEY `ft_title_content` (`title`, `content`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='文章表'; -- ============================================ -- 4. 文章标签关联表(多对多) -- ============================================ DROP TABLE IF EXISTS `blog_article_tag`; CREATE TABLE `blog_article_tag` ( `id` BIGINT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '关联ID', `article_id` BIGINT UNSIGNED NOT NULL COMMENT '文章ID', `tag_id` BIGINT UNSIGNED NOT NULL COMMENT '标签ID', `create_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', PRIMARY KEY (`id`), UNIQUE KEY `uk_article_tag` (`article_id`, `tag_id`), KEY `idx_article_id` (`article_id`), KEY `idx_tag_id` (`tag_id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='文章标签关联表'; -- ============================================ -- 5. 评论表 -- ============================================ DROP TABLE IF EXISTS `blog_comment`; CREATE TABLE `blog_comment` ( `id` BIGINT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '评论ID', `article_id` BIGINT UNSIGNED NOT NULL COMMENT '文章ID', `user_id` BIGINT UNSIGNED NOT NULL COMMENT '评论用户ID', `parent_id` BIGINT UNSIGNED DEFAULT 0 COMMENT '父评论ID,0表示一级评论', `reply_user_id` BIGINT UNSIGNED DEFAULT NULL COMMENT '被回复的用户ID', `content` TEXT NOT NULL COMMENT '评论内容', `like_count` INT UNSIGNED DEFAULT 0 COMMENT '点赞数', `reply_count` INT UNSIGNED DEFAULT 0 COMMENT '回复数', `status` TINYINT NOT NULL DEFAULT 0 COMMENT '评论状态:0-待审核,1-已通过,2-已拒绝', `is_deleted` TINYINT(1) DEFAULT 0 COMMENT '是否删除:0-否,1-是', `create_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `update_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), KEY `idx_article_id` (`article_id`), KEY `idx_user_id` (`user_id`), KEY `idx_parent_id` (`parent_id`), KEY `idx_status` (`status`), KEY `idx_create_time` (`create_time`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='评论表'; -- ============================================ -- 6. 点赞表 -- ============================================ DROP TABLE IF EXISTS `blog_like`; CREATE TABLE `blog_like` ( `id` BIGINT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '点赞ID', `user_id` BIGINT UNSIGNED NOT NULL COMMENT '用户ID', `target_id` BIGINT UNSIGNED NOT NULL COMMENT '目标ID(文章ID或评论ID)', `target_type` TINYINT NOT NULL COMMENT '目标类型:1-文章,2-评论', `is_deleted` TINYINT(1) DEFAULT 0 COMMENT '是否删除:0-否,1-是(取消点赞)', `create_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `update_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), UNIQUE KEY `uk_user_target` (`user_id`, `target_id`, `target_type`, `is_deleted`), KEY `idx_target` (`target_id`, `target_type`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='点赞表'; -- ============================================ -- 7. 收藏表 -- ============================================ DROP TABLE IF EXISTS `blog_favorite`; CREATE TABLE `blog_favorite` ( `id` BIGINT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '收藏ID', `user_id` BIGINT UNSIGNED NOT NULL COMMENT '用户ID', `article_id` BIGINT UNSIGNED NOT NULL COMMENT '文章ID', `folder_name` VARCHAR(50) DEFAULT '默认收藏夹' COMMENT '收藏夹名称', `is_deleted` TINYINT(1) DEFAULT 0 COMMENT '是否删除:0-否,1-是(取消收藏)', `create_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `update_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), UNIQUE KEY `uk_user_article` (`user_id`, `article_id`, `is_deleted`), KEY `idx_article_id` (`article_id`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='收藏表'; -- ============================================ -- 8. 浏览记录表 -- ============================================ DROP TABLE IF EXISTS `blog_view`; CREATE TABLE `blog_view` ( `id` BIGINT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '浏览记录ID', `article_id` BIGINT UNSIGNED NOT NULL COMMENT '文章ID', `user_id` BIGINT UNSIGNED DEFAULT NULL COMMENT '用户ID(未登录为NULL)', `ip_address` VARCHAR(45) DEFAULT NULL COMMENT 'IP地址', `user_agent` VARCHAR(500) DEFAULT NULL COMMENT '用户代理(浏览器信息)', `duration` INT UNSIGNED DEFAULT 0 COMMENT '浏览时长(秒)', `create_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', PRIMARY KEY (`id`), KEY `idx_article_id` (`article_id`), KEY `idx_user_id` (`user_id`), KEY `idx_create_time` (`create_time`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='浏览记录表'; -- ============================================ -- 9. 草稿箱表 -- ============================================ DROP TABLE IF EXISTS `blog_draft`; CREATE TABLE `blog_draft` ( `id` BIGINT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '草稿ID', `user_id` BIGINT UNSIGNED NOT NULL COMMENT '用户ID', `title` VARCHAR(200) DEFAULT NULL COMMENT '草稿标题', `content` MEDIUMTEXT DEFAULT NULL COMMENT '草稿内容(Markdown格式)', `category_id` BIGINT UNSIGNED DEFAULT NULL COMMENT '分类ID', `cover_image` VARCHAR(500) DEFAULT NULL COMMENT '封面图片URL', `is_deleted` TINYINT(1) DEFAULT 0 COMMENT '是否删除:0-否,1-是', `create_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', `update_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', PRIMARY KEY (`id`), KEY `idx_user_id` (`user_id`), KEY `idx_update_time` (`update_time`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='草稿箱表'; -- ============================================ -- 初始化数据 -- ============================================ -- 初始化分类 INSERT INTO `blog_category` (`name`, `slug`, `description`, `icon`, `parent_id`, `sort_order`) VALUES ('技术分享', 'tech', '分享技术经验和心得', 'icon-tech', 0, 100), ('算法学习', 'algorithm', '算法与数据结构学习笔记', 'icon-algo', 0, 90), ('项目实战', 'project', '项目开发实战经验', 'icon-project', 0, 80), ('面试经验', 'interview', '面试经验总结', 'icon-interview', 0, 70), ('学习笔记', 'note', '日常学习笔记', 'icon-note', 0, 60); -- 初始化标签 INSERT INTO `blog_tag` (`name`, `slug`, `description`, `color`) VALUES ('Java', 'java', 'Java编程语言', '#007396'), ('Python', 'python', 'Python编程语言', '#3776AB'), ('Spring', 'spring', 'Spring框架', '#6DB33F'), ('MyBatis', 'mybatis', 'MyBatis持久层框架', '#DC382D'), ('Redis', 'redis', 'Redis缓存', '#D82C20'), ('MySQL', 'mysql', 'MySQL数据库', '#4479A1'), ('LeetCode', 'leetcode', 'LeetCode刷题', '#FFA116'), ('系统设计', 'system-design', '系统设计相关', '#FF6B6B'), ('微服务', 'microservice', '微服务架构', '#009688'), ('前端开发', 'frontend', '前端开发技术', '#F7DF1E');