22301069 | 0939f5f | 2025-06-09 14:00:43 +0800 | [diff] [blame] | 1 | /* |
| 2 | 数据库设计说明: |
| 3 | 1. 核心表结构: |
| 4 | users:存储用户信息,包含角色管理和账号状态 |
| 5 | posts:核心内容表,支持多模态内容(图文/视频/文档) |
| 6 | behaviors:记录用户互动行为(点赞/收藏/浏览等) |
| 7 | comments:评论系统,支持多级回复 |
| 8 | follows:用户社交关系 |
| 9 | 2. 推荐系统支持: |
| 10 | posts.heat 字段存储动态计算的热度值 |
| 11 | behaviors 表记录用户行为用于协同过滤 |
| 12 | user_tags 表构建用户兴趣画像 |
| 13 | 通过 post_tags 实现内容标签分类 |
| 14 | 3. 多模态内容处理: |
| 15 | posts.media_urls 使用 JSON 类型存储多个资源 URL |
| 16 | posts.type 区分不同类型的内容(图文/视频/文档) |
| 17 | 4. 审核与安全: |
| 18 | audits 表记录内容审核历史 |
| 19 | posts.status 管理内容生命周期状态 |
| 20 | logs 表记录系统操作和访问日志 |
| 21 | 5. 性能优化: |
| 22 | 为查询频繁字段添加索引(热度/行为类型/时间) |
| 23 | 使用 JSON 类型存储灵活数据(通知内容/媒体资源) |
| 24 | 通过 heat 字段预计算支持热门排序 |
| 25 | 6. 扩展性设计: |
| 26 | 用户画像系统通过 user_tags 表实现 |
| 27 | 通知系统支持多种互动类型 |
| 28 | 行为表设计支持未来扩展新行为类型 |
| 29 | */ |
| 30 | |
| 31 | |
| 32 | -- 创建数据库 |
| 33 | CREATE DATABASE IF NOT EXISTS redbook DEFAULT CHARSET utf8mb4 COLLATE utf8mb4_general_ci; |
| 34 | USE redbook; |
| 35 | |
| 36 | -- 用户表 |
| 37 | CREATE TABLE users ( |
| 38 | id INT AUTO_INCREMENT PRIMARY KEY COMMENT '用户ID', |
| 39 | username VARCHAR(50) NOT NULL UNIQUE COMMENT '用户名', |
| 40 | password VARCHAR(255) NOT NULL COMMENT '加密密码', |
| 41 | email VARCHAR(100) NOT NULL UNIQUE COMMENT '邮箱', |
| 42 | avatar VARCHAR(255) COMMENT '头像URL', |
| 43 | role ENUM('user', 'admin') DEFAULT 'user' COMMENT '角色', |
| 44 | bio VARCHAR(255) COMMENT '个人简介', |
| 45 | status ENUM('active', 'banned', 'muted') DEFAULT 'active' COMMENT '账号状态', |
| 46 | created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', |
| 47 | updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间' |
| 48 | ) ENGINE=InnoDB COMMENT='用户表'; |
| 49 | |
| 50 | -- 标签表 |
| 51 | CREATE TABLE tags ( |
| 52 | id INT AUTO_INCREMENT PRIMARY KEY COMMENT '标签ID', |
| 53 | name VARCHAR(50) NOT NULL UNIQUE COMMENT '标签名称', |
| 54 | description VARCHAR(255) COMMENT '标签描述', |
| 55 | created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间' |
| 56 | ) ENGINE=InnoDB COMMENT='内容标签表'; |
| 57 | |
| 58 | -- 话题/超话表 |
| 59 | CREATE TABLE topics ( |
| 60 | id INT AUTO_INCREMENT PRIMARY KEY COMMENT '话题ID', |
| 61 | name VARCHAR(100) NOT NULL UNIQUE COMMENT '话题名称', |
| 62 | description TEXT COMMENT '话题描述', |
| 63 | status ENUM('active', 'archived') DEFAULT 'active' COMMENT '状态', |
| 64 | created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间' |
| 65 | ) ENGINE=InnoDB COMMENT='话题/超话表'; |
| 66 | |
| 67 | -- 内容帖子表 |
| 68 | CREATE TABLE posts ( |
| 69 | id INT AUTO_INCREMENT PRIMARY KEY COMMENT '帖子ID', |
| 70 | user_id INT NOT NULL COMMENT '作者ID', |
| 71 | topic_id INT COMMENT '所属话题ID', |
| 72 | type ENUM('text', 'image', 'video', 'document') DEFAULT 'text' COMMENT '内容类型', |
| 73 | title VARCHAR(255) NOT NULL COMMENT '标题', |
| 74 | content TEXT NOT NULL COMMENT '正文内容', |
| 75 | media_urls JSON COMMENT '媒体资源URL数组', |
| 76 | status ENUM('draft', 'pending', 'published', 'deleted', 'rejected') DEFAULT 'draft' COMMENT '状态', |
| 77 | heat INT DEFAULT 0 COMMENT '热度值', |
| 78 | created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', |
| 79 | updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', |
| 80 | FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, |
| 81 | FOREIGN KEY (topic_id) REFERENCES topics(id) ON DELETE SET NULL |
| 82 | ) ENGINE=InnoDB COMMENT='内容帖子表'; |
| 83 | |
| 84 | -- 帖子标签关联表 |
| 85 | CREATE TABLE post_tags ( |
| 86 | post_id INT NOT NULL COMMENT '帖子ID', |
| 87 | tag_id INT NOT NULL COMMENT '标签ID', |
| 88 | PRIMARY KEY (post_id, tag_id), |
| 89 | FOREIGN KEY (post_id) REFERENCES posts(id) ON DELETE CASCADE, |
| 90 | FOREIGN KEY (tag_id) REFERENCES tags(id) ON DELETE CASCADE |
| 91 | ) ENGINE=InnoDB COMMENT='帖子标签关联表'; |
| 92 | |
| 93 | -- 用户行为表 |
| 94 | CREATE TABLE behaviors ( |
| 95 | id BIGINT AUTO_INCREMENT PRIMARY KEY COMMENT '行为ID', |
| 96 | user_id INT NOT NULL COMMENT '用户ID', |
| 97 | post_id INT NOT NULL COMMENT '帖子ID', |
| 98 | type ENUM('like', 'comment', 'favorite', 'view', 'share') NOT NULL COMMENT '行为类型', |
| 99 | value INT DEFAULT 1 COMMENT '行为值', |
| 100 | created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '行为时间', |
| 101 | FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, |
| 102 | FOREIGN KEY (post_id) REFERENCES posts(id) ON DELETE CASCADE |
| 103 | ) ENGINE=InnoDB COMMENT='用户行为记录表'; |
| 104 | |
| 105 | -- 评论表 |
| 106 | CREATE TABLE comments ( |
| 107 | id INT AUTO_INCREMENT PRIMARY KEY COMMENT '评论ID', |
| 108 | post_id INT NOT NULL COMMENT '帖子ID', |
| 109 | user_id INT NOT NULL COMMENT '用户ID', |
| 110 | parent_id INT DEFAULT NULL COMMENT '父评论ID', |
| 111 | content TEXT NOT NULL COMMENT '评论内容', |
| 112 | status ENUM('active', 'deleted') DEFAULT 'active' COMMENT '状态', |
| 113 | created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', |
| 114 | updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', |
| 115 | FOREIGN KEY (post_id) REFERENCES posts(id) ON DELETE CASCADE, |
| 116 | FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, |
| 117 | FOREIGN KEY (parent_id) REFERENCES comments(id) ON DELETE CASCADE |
| 118 | ) ENGINE=InnoDB COMMENT='评论表'; |
| 119 | |
| 120 | -- 用户关注关系表 |
| 121 | CREATE TABLE follows ( |
| 122 | follower_id INT NOT NULL COMMENT '关注者ID', |
| 123 | followee_id INT NOT NULL COMMENT '被关注者ID', |
| 124 | created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '关注时间', |
| 125 | PRIMARY KEY (follower_id, followee_id), |
| 126 | FOREIGN KEY (follower_id) REFERENCES users(id) ON DELETE CASCADE, |
| 127 | FOREIGN KEY (followee_id) REFERENCES users(id) ON DELETE CASCADE |
| 128 | ) ENGINE=InnoDB COMMENT='用户关注关系表'; |
| 129 | |
| 130 | -- 通知表 |
| 131 | CREATE TABLE notifications ( |
| 132 | id INT AUTO_INCREMENT PRIMARY KEY COMMENT '通知ID', |
| 133 | user_id INT NOT NULL COMMENT '接收用户ID', |
| 134 | type ENUM('like', 'comment', 'follow', 'system', 'audit') NOT NULL COMMENT '通知类型', |
| 135 | content JSON NOT NULL COMMENT '通知内容', |
| 136 | is_read BOOLEAN DEFAULT FALSE COMMENT '是否已读', |
| 137 | created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', |
| 138 | FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE |
| 139 | ) ENGINE=InnoDB COMMENT='用户通知表'; |
| 140 | |
| 141 | -- 审核记录表 |
| 142 | CREATE TABLE audits ( |
| 143 | id INT AUTO_INCREMENT PRIMARY KEY COMMENT '审核ID', |
| 144 | post_id INT NOT NULL COMMENT '帖子ID', |
| 145 | admin_id INT NOT NULL COMMENT '管理员ID', |
| 146 | result ENUM('approved', 'rejected') NOT NULL COMMENT '审核结果', |
| 147 | reason VARCHAR(255) COMMENT '审核原因', |
| 148 | created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '审核时间', |
| 149 | FOREIGN KEY (post_id) REFERENCES posts(id) ON DELETE CASCADE, |
| 150 | FOREIGN KEY (admin_id) REFERENCES users(id) ON DELETE CASCADE |
| 151 | ) ENGINE=InnoDB COMMENT='内容审核记录表'; |
| 152 | |
| 153 | -- 日志表 |
| 154 | CREATE TABLE logs ( |
| 155 | id BIGINT AUTO_INCREMENT PRIMARY KEY COMMENT '日志ID', |
| 156 | user_id INT DEFAULT NULL COMMENT '用户ID', |
| 157 | type ENUM('access', 'error', 'behavior', 'system') NOT NULL COMMENT '日志类型', |
| 158 | content TEXT NOT NULL COMMENT '日志内容', |
| 159 | ip VARCHAR(45) COMMENT 'IP地址', |
| 160 | created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '记录时间', |
| 161 | FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE SET NULL |
| 162 | ) ENGINE=InnoDB COMMENT='系统日志表'; |
| 163 | |
| 164 | -- 用户兴趣标签表(用户画像) |
| 165 | CREATE TABLE user_tags ( |
| 166 | user_id INT NOT NULL COMMENT '用户ID', |
| 167 | tag_id INT NOT NULL COMMENT '标签ID', |
| 168 | weight FLOAT DEFAULT 1.0 COMMENT '兴趣权重', |
| 169 | created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间', |
| 170 | updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间', |
| 171 | PRIMARY KEY (user_id, tag_id), |
| 172 | FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, |
| 173 | FOREIGN KEY (tag_id) REFERENCES tags(id) ON DELETE CASCADE |
| 174 | ) ENGINE=InnoDB COMMENT='用户兴趣标签表'; |
| 175 | |
| 176 | -- 索引优化 |
| 177 | CREATE INDEX idx_posts_heat ON posts(heat); |
| 178 | CREATE INDEX idx_behaviors_type ON behaviors(type); |
| 179 | CREATE INDEX idx_notifications_read ON notifications(is_read); |
| 180 | CREATE INDEX idx_logs_created ON logs(created_at); |
| 181 | CREATE INDEX idx_comments_post ON comments(post_id); |