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