schema.sql 11 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262
  1. -- 多自媒体平台账号管理系统数据库表结构
  2. -- MySQL 8.0+
  3. CREATE DATABASE IF NOT EXISTS media_manager
  4. CHARACTER SET utf8mb4
  5. COLLATE utf8mb4_unicode_ci;
  6. USE media_manager;
  7. -- 用户表(软件登录账号)
  8. CREATE TABLE IF NOT EXISTS users (
  9. id INT PRIMARY KEY AUTO_INCREMENT,
  10. username VARCHAR(50) UNIQUE NOT NULL,
  11. email VARCHAR(100) UNIQUE,
  12. password_hash VARCHAR(255) NOT NULL,
  13. avatar_url VARCHAR(500),
  14. nickname VARCHAR(50),
  15. role ENUM('admin', 'editor', 'operator') DEFAULT 'operator',
  16. status ENUM('active', 'disabled', 'pending') DEFAULT 'active',
  17. last_login_at TIMESTAMP NULL,
  18. last_login_ip VARCHAR(50),
  19. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  20. updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
  21. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  22. -- 用户 Token 表(用于 Token 失效管理)
  23. CREATE TABLE IF NOT EXISTS user_tokens (
  24. id INT PRIMARY KEY AUTO_INCREMENT,
  25. user_id INT NOT NULL,
  26. refresh_token VARCHAR(500) NOT NULL,
  27. device_info VARCHAR(255),
  28. ip_address VARCHAR(50),
  29. expires_at TIMESTAMP NOT NULL,
  30. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  31. FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
  32. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  33. -- 系统配置表
  34. CREATE TABLE IF NOT EXISTS system_config (
  35. id INT PRIMARY KEY AUTO_INCREMENT,
  36. config_key VARCHAR(100) UNIQUE NOT NULL,
  37. config_value TEXT,
  38. description VARCHAR(255),
  39. updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP
  40. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  41. -- 初始化系统配置
  42. INSERT INTO system_config (config_key, config_value, description) VALUES
  43. ('allow_registration', 'false', '是否开放用户注册'),
  44. ('default_user_role', 'operator', '新注册用户默认角色')
  45. ON DUPLICATE KEY UPDATE config_key=config_key;
  46. -- 创建默认管理员账号 (密码: admin123)
  47. INSERT INTO users (username, email, password_hash, nickname, role, status) VALUES
  48. ('admin', 'admin@example.com', '$2a$10$rQnM1YFKBqr6.8t5P7H5/.8mJSYvCXsMaJ6fBVdX5xFXQV8u7sSAu', '管理员', 'admin', 'active')
  49. ON DUPLICATE KEY UPDATE username=username;
  50. -- 平台账号分组表(关联用户)
  51. CREATE TABLE IF NOT EXISTS account_groups (
  52. id INT PRIMARY KEY AUTO_INCREMENT,
  53. user_id INT NOT NULL,
  54. name VARCHAR(100) NOT NULL,
  55. description VARCHAR(255),
  56. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  57. FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
  58. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  59. -- 平台账号表(关联用户,核心数据表)
  60. CREATE TABLE IF NOT EXISTS platform_accounts (
  61. id INT PRIMARY KEY AUTO_INCREMENT,
  62. user_id INT NOT NULL,
  63. platform ENUM('douyin','kuaishou','weixin_video','xiaohongshu','bilibili','toutiao','baijiahao','qie','dayuhao') NOT NULL,
  64. account_name VARCHAR(100),
  65. account_id VARCHAR(100),
  66. avatar_url VARCHAR(500),
  67. fans_count INT DEFAULT 0,
  68. works_count INT DEFAULT 0,
  69. cookie_data TEXT,
  70. cookie_expire_at TIMESTAMP NULL,
  71. status ENUM('active','expired','disabled') DEFAULT 'active',
  72. proxy_config JSON,
  73. group_id INT,
  74. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  75. updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
  76. FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
  77. FOREIGN KEY (group_id) REFERENCES account_groups(id) ON DELETE SET NULL,
  78. UNIQUE KEY uk_user_platform_account (user_id, platform, account_id)
  79. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  80. -- 视频发布任务表(关联用户)
  81. CREATE TABLE IF NOT EXISTS publish_tasks (
  82. id INT PRIMARY KEY AUTO_INCREMENT,
  83. user_id INT NOT NULL,
  84. video_path VARCHAR(500),
  85. video_filename VARCHAR(255),
  86. title VARCHAR(200),
  87. description TEXT,
  88. cover_path VARCHAR(500),
  89. tags JSON,
  90. target_accounts JSON,
  91. platform_configs JSON,
  92. publish_proxy JSON,
  93. status ENUM('pending','processing','completed','failed','cancelled') DEFAULT 'pending',
  94. scheduled_at TIMESTAMP NULL,
  95. published_at TIMESTAMP NULL,
  96. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  97. updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
  98. FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
  99. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  100. -- 发布结果表
  101. CREATE TABLE IF NOT EXISTS publish_results (
  102. id INT PRIMARY KEY AUTO_INCREMENT,
  103. task_id INT NOT NULL,
  104. account_id INT NOT NULL,
  105. platform VARCHAR(50),
  106. status ENUM('success','failed'),
  107. video_url VARCHAR(500),
  108. platform_video_id VARCHAR(100),
  109. error_message TEXT,
  110. published_at TIMESTAMP NULL,
  111. FOREIGN KEY (task_id) REFERENCES publish_tasks(id) ON DELETE CASCADE,
  112. FOREIGN KEY (account_id) REFERENCES platform_accounts(id) ON DELETE CASCADE
  113. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  114. -- 评论表(关联用户)
  115. CREATE TABLE IF NOT EXISTS comments (
  116. id INT PRIMARY KEY AUTO_INCREMENT,
  117. user_id INT NOT NULL,
  118. account_id INT NOT NULL,
  119. platform VARCHAR(50),
  120. video_id VARCHAR(100),
  121. platform_video_url VARCHAR(500),
  122. comment_id VARCHAR(100) UNIQUE,
  123. parent_comment_id VARCHAR(100),
  124. author_id VARCHAR(100),
  125. author_name VARCHAR(100),
  126. author_avatar VARCHAR(500),
  127. content TEXT,
  128. like_count INT DEFAULT 0,
  129. reply_content TEXT,
  130. replied_at TIMESTAMP NULL,
  131. is_read BOOLEAN DEFAULT FALSE,
  132. is_top BOOLEAN DEFAULT FALSE,
  133. comment_time TIMESTAMP NULL,
  134. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  135. FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
  136. FOREIGN KEY (account_id) REFERENCES platform_accounts(id) ON DELETE CASCADE,
  137. INDEX idx_comment_user_read (user_id, is_read),
  138. INDEX idx_comment_account (account_id)
  139. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  140. -- 数据统计表(关联用户)
  141. CREATE TABLE IF NOT EXISTS analytics_data (
  142. id INT PRIMARY KEY AUTO_INCREMENT,
  143. user_id INT NOT NULL,
  144. account_id INT NOT NULL,
  145. date DATE NOT NULL,
  146. fans_count INT DEFAULT 0,
  147. fans_increase INT DEFAULT 0,
  148. views_count INT DEFAULT 0,
  149. likes_count INT DEFAULT 0,
  150. comments_count INT DEFAULT 0,
  151. shares_count INT DEFAULT 0,
  152. income DECIMAL(10,2) DEFAULT 0,
  153. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  154. FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
  155. FOREIGN KEY (account_id) REFERENCES platform_accounts(id) ON DELETE CASCADE,
  156. UNIQUE KEY uk_account_date (account_id, date),
  157. INDEX idx_analytics_user_date (user_id, date)
  158. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  159. -- 操作日志表(审计追踪)
  160. CREATE TABLE IF NOT EXISTS operation_logs (
  161. id INT PRIMARY KEY AUTO_INCREMENT,
  162. user_id INT NOT NULL,
  163. action VARCHAR(50) NOT NULL,
  164. target_type VARCHAR(50),
  165. target_id INT,
  166. detail JSON,
  167. ip_address VARCHAR(50),
  168. user_agent VARCHAR(255),
  169. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  170. FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
  171. INDEX idx_log_user_time (user_id, created_at)
  172. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  173. -- 作品表(关联平台账号)
  174. CREATE TABLE IF NOT EXISTS works (
  175. id INT PRIMARY KEY AUTO_INCREMENT,
  176. userId INT NOT NULL,
  177. accountId INT NOT NULL,
  178. platform VARCHAR(20) NOT NULL,
  179. platform_video_id VARCHAR(500) NOT NULL,
  180. title VARCHAR(200) DEFAULT '',
  181. description TEXT,
  182. cover_url VARCHAR(500) DEFAULT '',
  183. video_url TEXT,
  184. duration VARCHAR(20) DEFAULT '00:00',
  185. status VARCHAR(20) DEFAULT 'published',
  186. publish_time DATETIME,
  187. play_count INT DEFAULT 0,
  188. like_count INT DEFAULT 0,
  189. comment_count INT DEFAULT 0,
  190. share_count INT DEFAULT 0,
  191. collect_count INT DEFAULT 0,
  192. created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
  193. updated_at DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
  194. INDEX idx_user_platform (userId, platform),
  195. UNIQUE KEY uk_account_platform_video (accountId, platform_video_id),
  196. FOREIGN KEY (accountId) REFERENCES platform_accounts(id) ON DELETE CASCADE
  197. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  198. -- 作品每日统计表(记录每天的数据快照)
  199. CREATE TABLE IF NOT EXISTS work_day_statistics (
  200. id INT PRIMARY KEY AUTO_INCREMENT,
  201. work_id INT NOT NULL,
  202. record_date DATE NOT NULL,
  203. play_count INT DEFAULT 0 COMMENT '播放数',
  204. exposure_count INT DEFAULT 0 COMMENT '曝光数/展现量',
  205. like_count INT DEFAULT 0 COMMENT '点赞数',
  206. comment_count INT DEFAULT 0 COMMENT '评论数',
  207. share_count INT DEFAULT 0 COMMENT '分享数',
  208. collect_count INT DEFAULT 0 COMMENT '收藏数',
  209. fans_increase INT DEFAULT 0 COMMENT '涨粉数',
  210. cover_click_rate VARCHAR(50) DEFAULT '0' COMMENT '封面点击率',
  211. avg_watch_duration VARCHAR(50) DEFAULT '0' COMMENT '平均观看时长(秒)',
  212. total_watch_duration VARCHAR(50) DEFAULT '0' COMMENT '总观看时长(秒)',
  213. completion_rate VARCHAR(50) DEFAULT '0' COMMENT '完播率',
  214. two_second_exit_rate VARCHAR(50) DEFAULT '0' COMMENT '2秒退出率',
  215. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  216. updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
  217. UNIQUE KEY uk_work_date (work_id, record_date),
  218. INDEX idx_work_id (work_id),
  219. INDEX idx_record_date (record_date),
  220. FOREIGN KEY (work_id) REFERENCES works(id) ON DELETE CASCADE
  221. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='作品每日统计数据';
  222. -- 账号每日统计表(记录每个平台账号的粉丝数和作品数,不关联作品)
  223. CREATE TABLE IF NOT EXISTS user_day_statistics (
  224. id INT PRIMARY KEY AUTO_INCREMENT,
  225. account_id INT NOT NULL COMMENT '账号ID(关联platform_accounts.id)',
  226. record_date DATE NOT NULL COMMENT '记录日期',
  227. fans_count INT DEFAULT 0 COMMENT '粉丝数',
  228. works_count INT DEFAULT 0 COMMENT '作品数',
  229. play_count INT DEFAULT 0 COMMENT '播放数',
  230. comment_count INT DEFAULT 0 COMMENT '评论数',
  231. fans_increase INT DEFAULT 0 COMMENT '涨粉数',
  232. like_count INT DEFAULT 0 COMMENT '点赞数',
  233. share_count INT DEFAULT 0 COMMENT '分享数',
  234. collect_count INT DEFAULT 0 COMMENT '收藏数',
  235. cover_click_rate VARCHAR(50) DEFAULT '0' COMMENT '封面点击率',
  236. avg_watch_duration VARCHAR(50) DEFAULT '0' COMMENT '平均观看时长(秒)',
  237. total_watch_duration VARCHAR(50) DEFAULT '0' COMMENT '观看总时长(秒)',
  238. completion_rate VARCHAR(50) DEFAULT '0' COMMENT '视频完播率',
  239. created_at DATETIME DEFAULT CURRENT_TIMESTAMP,
  240. updated_at DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
  241. UNIQUE KEY uk_account_date (account_id, record_date),
  242. INDEX idx_account_id (account_id),
  243. INDEX idx_record_date (record_date),
  244. FOREIGN KEY (account_id) REFERENCES platform_accounts(id) ON DELETE CASCADE
  245. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='账号每日统计数据(按平台账号统计)';