schema.sql 7.2 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185
  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. status ENUM('pending','processing','completed','failed','cancelled') DEFAULT 'pending',
  93. scheduled_at TIMESTAMP NULL,
  94. published_at TIMESTAMP NULL,
  95. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  96. updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
  97. FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE
  98. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  99. -- 发布结果表
  100. CREATE TABLE IF NOT EXISTS publish_results (
  101. id INT PRIMARY KEY AUTO_INCREMENT,
  102. task_id INT NOT NULL,
  103. account_id INT NOT NULL,
  104. platform VARCHAR(50),
  105. status ENUM('success','failed'),
  106. video_url VARCHAR(500),
  107. platform_video_id VARCHAR(100),
  108. error_message TEXT,
  109. published_at TIMESTAMP NULL,
  110. FOREIGN KEY (task_id) REFERENCES publish_tasks(id) ON DELETE CASCADE,
  111. FOREIGN KEY (account_id) REFERENCES platform_accounts(id) ON DELETE CASCADE
  112. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  113. -- 评论表(关联用户)
  114. CREATE TABLE IF NOT EXISTS comments (
  115. id INT PRIMARY KEY AUTO_INCREMENT,
  116. user_id INT NOT NULL,
  117. account_id INT NOT NULL,
  118. platform VARCHAR(50),
  119. video_id VARCHAR(100),
  120. platform_video_url VARCHAR(500),
  121. comment_id VARCHAR(100) UNIQUE,
  122. parent_comment_id VARCHAR(100),
  123. author_id VARCHAR(100),
  124. author_name VARCHAR(100),
  125. author_avatar VARCHAR(500),
  126. content TEXT,
  127. like_count INT DEFAULT 0,
  128. reply_content TEXT,
  129. replied_at TIMESTAMP NULL,
  130. is_read BOOLEAN DEFAULT FALSE,
  131. is_top BOOLEAN DEFAULT FALSE,
  132. comment_time TIMESTAMP NULL,
  133. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  134. FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
  135. FOREIGN KEY (account_id) REFERENCES platform_accounts(id) ON DELETE CASCADE,
  136. INDEX idx_comment_user_read (user_id, is_read),
  137. INDEX idx_comment_account (account_id)
  138. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  139. -- 数据统计表(关联用户)
  140. CREATE TABLE IF NOT EXISTS analytics_data (
  141. id INT PRIMARY KEY AUTO_INCREMENT,
  142. user_id INT NOT NULL,
  143. account_id INT NOT NULL,
  144. date DATE NOT NULL,
  145. fans_count INT DEFAULT 0,
  146. fans_increase INT DEFAULT 0,
  147. views_count INT DEFAULT 0,
  148. likes_count INT DEFAULT 0,
  149. comments_count INT DEFAULT 0,
  150. shares_count INT DEFAULT 0,
  151. income DECIMAL(10,2) DEFAULT 0,
  152. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  153. FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
  154. FOREIGN KEY (account_id) REFERENCES platform_accounts(id) ON DELETE CASCADE,
  155. UNIQUE KEY uk_account_date (account_id, date),
  156. INDEX idx_analytics_user_date (user_id, date)
  157. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
  158. -- 操作日志表(审计追踪)
  159. CREATE TABLE IF NOT EXISTS operation_logs (
  160. id INT PRIMARY KEY AUTO_INCREMENT,
  161. user_id INT NOT NULL,
  162. action VARCHAR(50) NOT NULL,
  163. target_type VARCHAR(50),
  164. target_id INT,
  165. detail JSON,
  166. ip_address VARCHAR(50),
  167. user_agent VARCHAR(255),
  168. created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
  169. FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE,
  170. INDEX idx_log_user_time (user_id, created_at)
  171. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;