content.sql 16 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233
  1. -- ------------------------------
  2. -- 1. 专辑表(已包含已添加的管理字段)
  3. -- ------------------------------
  4. CREATE TABLE `album` (
  5. `id` INT AUTO_INCREMENT PRIMARY KEY,
  6. `album_name` VARCHAR(100) NOT NULL COMMENT '专辑名称',
  7. `artist_id` INT NOT NULL COMMENT '关联artist服务的artist.id',
  8. `artist_name` VARCHAR(16) COMMENT '关联artist服务的artist.name',
  9. `cover_url` VARCHAR(255) COMMENT '专辑封面URL',
  10. `release_time` DATE COMMENT '发行时间',
  11. `description` TEXT COMMENT '专辑描述(介绍专辑主题、曲目等)',
  12. `album_type` TINYINT DEFAULT 1 COMMENT '专辑类型:1-数字专辑,2-实体专辑,3-EP',
  13. `price` DECIMAL(10,2) COMMENT '专辑价格(实体专辑或付费数字专辑使用)',
  14. `create_time` DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
  15. `update_time` DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
  16. -- 已添加的管理字段
  17. `status` TINYINT DEFAULT 0 COMMENT '专辑状态:0--审核中,1-审核失败,2-发布中,3-已上架,4-已下架',
  18. `audit_reason` VARCHAR(500) COMMENT '审核失败原因',
  19. `audit_time` DATETIME COMMENT '审核时间',
  20. `publish_time` DATETIME COMMENT '发布时间',
  21. `shelf_time` DATETIME COMMENT '上架时间',
  22. `off_shelf_time` DATETIME COMMENT '下架时间',
  23. `delete_flag` TINYINT DEFAULT 0 COMMENT '删除标志:0-未删除,1-已删除',
  24. `delete_time` DATETIME COMMENT '删除时间',
  25. INDEX `idx_album_name` (`album_name`),
  26. INDEX `idx_artist_id` (`artist_id`),
  27. INDEX `idx_status` (`status`)
  28. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='专辑表';
  29. -- ------------------------------
  30. -- 2. 歌曲表(已包含已添加的管理字段)
  31. -- ------------------------------
  32. CREATE TABLE `song` (
  33. `id` INT AUTO_INCREMENT PRIMARY KEY,
  34. `song_name` VARCHAR(100) NOT NULL COMMENT '歌曲名称',
  35. `artist_id` INT NOT NULL COMMENT '关联artist服务的artist.id',
  36. `album_id` INT COMMENT '关联本服务的album.id(可为空,单曲不关联专辑)',
  37. `duration` INT COMMENT '时长(秒,如300秒=5分钟)',
  38. `file_url` VARCHAR(255) NOT NULL COMMENT '歌曲音频文件URL',
  39. `cover_url` VARCHAR(255) COMMENT '歌曲封面URL(优先使用专辑封面,无专辑时用此封面)',
  40. `release_time` DATE COMMENT '发行时间',
  41. `lyrics` TEXT COMMENT '歌词(冗余存储,核心歌词)',
  42. `play_count` BIGINT DEFAULT 0 COMMENT '播放量',
  43. `is_paid` TINYINT DEFAULT 0 COMMENT '是否付费:0-免费,1-付费',
  44. `price` DECIMAL(10,2) DEFAULT 0.00 COMMENT '单曲价格',
  45. `create_time` DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
  46. `update_time` DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
  47. -- 已添加的管理字段
  48. `status` TINYINT DEFAULT 0 COMMENT '歌曲状态:0-草稿,1-审核中,2-审核失败,3-发布中,4-已上架,5-已下架',
  49. `audit_reason` VARCHAR(500) COMMENT '审核失败原因',
  50. `audit_time` DATETIME COMMENT '审核时间',
  51. `publish_time` DATETIME COMMENT '发布时间',
  52. `shelf_time` DATETIME COMMENT '上架时间',
  53. `off_shelf_time` DATETIME COMMENT '下架时间',
  54. `delete_flag` TINYINT DEFAULT 0 COMMENT '删除标志:0-未删除,1-已删除',
  55. `delete_time` DATETIME COMMENT '删除时间',
  56. `song_type` VARCHAR(50) COMMENT '歌曲类型',
  57. `version` VARCHAR(50) COMMENT '版本',
  58. `work_type` VARCHAR(50) COMMENT '作品类型',
  59. `genre` VARCHAR(255) COMMENT '音乐风格',
  60. `language` VARCHAR(20) COMMENT '语言',
  61. `lyricist` VARCHAR(100) COMMENT '作词人',
  62. `composer` VARCHAR(100) COMMENT '作曲人',
  63. `arranger` VARCHAR(100) COMMENT '编曲人',
  64. `singer_name` VARCHAR(100) COMMENT '演唱者姓名',
  65. FOREIGN KEY (`album_id`) REFERENCES `album` (`id`) ON DELETE SET NULL,
  66. INDEX `idx_song_name` (`song_name`),
  67. INDEX `idx_play_count` (`play_count`),
  68. INDEX `idx_artist_id` (`artist_id`),
  69. INDEX `idx_status` (`status`),
  70. INDEX `idx_delete_flag` (`delete_flag`)
  71. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='歌曲表';
  72. -- ------------------------------
  73. -- 3. 歌单表(关联auth服务的user.id,逻辑关联)
  74. -- ------------------------------
  75. CREATE TABLE `playlist` (
  76. `id` INT AUTO_INCREMENT PRIMARY KEY,
  77. `user_id` INT NOT NULL COMMENT '关联auth服务的user.id',
  78. `playlist_name` VARCHAR(100) NOT NULL COMMENT '歌单名称',
  79. `cover_url` VARCHAR(255) COMMENT '歌单封面URL',
  80. `description` TEXT COMMENT '歌单描述',
  81. `tag` VARCHAR(255) COMMENT '歌单标签(多个用逗号分隔)',
  82. `status` Boolean DEFAULT true COMMENT '0-公开,1-私密',
  83. `song_count` INT DEFAULT 0 COMMENT '歌单歌曲数量',
  84. `play_count` BIGINT DEFAULT 0 COMMENT '歌单播放量',
  85. `create_time` DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
  86. `update_time` DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
  87. INDEX `idx_playlist_name` (`playlist_name`),
  88. INDEX `idx_user_id` (`user_id`) -- 逻辑关联索引
  89. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='歌单表';
  90. -- ------------------------------
  91. -- 4. 歌单-歌曲关联表(关联本服务的playlist和song表)
  92. -- ------------------------------
  93. CREATE TABLE `playlist_song` (
  94. `id` INT AUTO_INCREMENT PRIMARY KEY,
  95. `playlist_id` INT NOT NULL COMMENT '关联本服务的playlist.id',
  96. `song_id` INT NOT NULL COMMENT '关联本服务的song.id',
  97. `order_num` INT NOT NULL COMMENT '歌曲在歌单中的排序序号',
  98. `add_time` DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '歌曲添加时间',
  99. FOREIGN KEY (`playlist_id`) REFERENCES `playlist` (`id`) ON DELETE CASCADE,
  100. FOREIGN KEY (`song_id`) REFERENCES `song` (`id`) ON DELETE CASCADE,
  101. UNIQUE KEY `uk_playlist_song` (`playlist_id`, `song_id`),
  102. INDEX `idx_order_num` (`order_num`)
  103. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='歌单-歌曲关联表';
  104. -- ------------------------------
  105. -- 10. 歌词表(关联本服务的song.id、auth服务的user.id)
  106. -- ------------------------------
  107. CREATE TABLE `lyric` (
  108. `id` INT AUTO_INCREMENT PRIMARY KEY,
  109. `lyric_name` VARCHAR(32) NOT NULL COMMENT '歌词名',
  110. `song_id` INT NOT NULL COMMENT '关联本服务的song.id',
  111. `lyrics` TEXT NOT NULL COMMENT 'LRC格式歌词文本',
  112. `language` VARCHAR(20) DEFAULT 'zh' COMMENT '歌词语言(zh-中文,en-英文等)',
  113. `version` VARCHAR(50) COMMENT '歌词版本(如艺人原版、用户翻译版)',
  114. `upload_user_id` INT NOT NULL COMMENT '上传用户ID,关联auth服务的user.id',
  115. `status` TINYINT DEFAULT 0 COMMENT '状态:0-待审核,1-已通过,2-已驳回',
  116. `lyric_reason` VARCHAR(500) COMMENT '审核失败原因',
  117. `create_time` DATETIME DEFAULT CURRENT_TIMESTAMP,
  118. FOREIGN KEY (`song_id`) REFERENCES `song` (`id`) ON DELETE CASCADE,
  119. INDEX `idx_song_id` (`song_id`),
  120. INDEX `idx_upload_user_id` (`upload_user_id`) -- 逻辑关联索引
  121. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='歌词表(多版本支持)';
  122. -- ------------------------------
  123. -- 5. 每日推荐表(关联auth服务的user.id、本服务的song.id)
  124. -- ------------------------------
  125. CREATE TABLE `daily_recommend` (
  126. `id` INT AUTO_INCREMENT PRIMARY KEY,
  127. `user_id` INT NOT NULL COMMENT '关联auth服务的user.id',
  128. `song_id` INT NOT NULL COMMENT '关联本服务的song.id',
  129. `recommend_date` DATE NOT NULL COMMENT '推荐日期',
  130. `reason` VARCHAR(255) COMMENT '推荐理由',
  131. `create_time` DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
  132. UNIQUE KEY `uk_user_song_date` (`user_id`, `song_id`, `recommend_date`),
  133. INDEX `idx_recommend_date` (`recommend_date`),
  134. INDEX `idx_user_id` (`user_id`), -- 逻辑关联索引
  135. INDEX `idx_song_id` (`song_id`)
  136. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='每日推荐表';
  137. -- ------------------------------
  138. -- 6. 我喜欢的音乐表(关联auth服务的user.id、本服务的song.id)
  139. -- ------------------------------
  140. CREATE TABLE `user_favorite_song` (
  141. `id` INT AUTO_INCREMENT PRIMARY KEY,
  142. `user_id` INT NOT NULL COMMENT '关联auth服务的user.id',
  143. `song_id` INT NOT NULL COMMENT '关联本服务的song.id',
  144. `create_time` DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '收藏时间',
  145. UNIQUE KEY `uk_user_song` (`user_id`, `song_id`),
  146. INDEX `idx_user_id` (`user_id`), -- 逻辑关联索引
  147. INDEX `idx_song_id` (`song_id`)
  148. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='我喜欢的音乐表';
  149. -- ------------------------------
  150. -- 7. 我喜欢的歌手表(关联auth服务的user.id、artist服务的artist.id)
  151. -- ------------------------------
  152. CREATE TABLE `user_favorite_artist` (
  153. `id` INT AUTO_INCREMENT PRIMARY KEY,
  154. `user_id` INT NOT NULL COMMENT '关联auth服务的user.id',
  155. `artist_id` INT NOT NULL COMMENT '关联artist服务的artist.id',
  156. `create_time` DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '关注时间',
  157. UNIQUE KEY `uk_user_artist` (`user_id`, `artist_id`),
  158. INDEX `idx_user_id` (`user_id`), -- 逻辑关联索引
  159. INDEX `idx_artist_id` (`artist_id`) -- 逻辑关联索引
  160. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='我喜欢的歌手表';
  161. -- ------------------------------
  162. -- 8. 我关注的用户表(关联auth服务的user.id)
  163. -- ------------------------------
  164. CREATE TABLE `user_follow` (
  165. `id` INT AUTO_INCREMENT PRIMARY KEY,
  166. `follower_id` INT NOT NULL COMMENT '关注者ID,关联auth服务的user.id',
  167. `followed_id` INT NOT NULL COMMENT '被关注者ID,关联auth服务的user.id',
  168. `create_time` DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '关注时间',
  169. UNIQUE KEY `uk_follower_followed` (`follower_id`, `followed_id`),
  170. INDEX `idx_follower_id` (`follower_id`), -- 逻辑关联索引
  171. INDEX `idx_followed_id` (`followed_id`) -- 逻辑关联索引
  172. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='我关注的用户表';
  173. -- ------------------------------
  174. -- 9. 收藏歌单表(关联auth服务的user.id、本服务的playlist.id)
  175. -- ------------------------------
  176. CREATE TABLE `user_playlist_favorite` (
  177. `id` INT AUTO_INCREMENT PRIMARY KEY,
  178. `user_id` INT NOT NULL COMMENT '关联auth服务的user.id',
  179. `playlist_id` INT NOT NULL COMMENT '关联本服务的playlist.id',
  180. `create_time` DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '收藏时间',
  181. FOREIGN KEY (`playlist_id`) REFERENCES `playlist` (`id`) ON DELETE CASCADE,
  182. UNIQUE KEY `uk_user_playlist` (`user_id`, `playlist_id`),
  183. INDEX `idx_user_id` (`user_id`) -- 逻辑关联索引
  184. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='我收藏的歌单表';
  185. -- ------------------------------
  186. -- 11. 歌曲推广表(关联artist服务的artist.id、本服务的song.id)
  187. -- ------------------------------
  188. CREATE TABLE `song_promotion` (
  189. `id` INT AUTO_INCREMENT PRIMARY KEY,
  190. `song_id` INT NOT NULL COMMENT '关联本服务的song.id',
  191. `artist_id` INT NOT NULL COMMENT '关联artist服务的artist.id',
  192. `promotion_type` TINYINT NOT NULL COMMENT '推广类型:1-首页推荐,2-热门榜单,3-新歌推荐,4-个性化推荐',
  193. `start_time` DATETIME NOT NULL COMMENT '推广开始时间',
  194. `end_time` DATETIME NOT NULL COMMENT '推广结束时间',
  195. `sort` INT DEFAULT 0 COMMENT '推荐排序权重(数值越小越靠前)',
  196. `status` TINYINT DEFAULT 1 COMMENT '状态:0-未生效,1-生效中,2-已过期',
  197. `create_time` DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
  198. `update_time` DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
  199. UNIQUE KEY `uk_song_type` (`song_id`, `promotion_type`),
  200. INDEX `idx_promotion_type` (`promotion_type`),
  201. INDEX `idx_status` (`status`),
  202. INDEX `idx_time_range` (`start_time`, `end_time`),
  203. INDEX `idx_artist_id` (`artist_id`) -- 逻辑关联索引
  204. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='歌曲推广表';
  205. -- ------------------------------
  206. -- 12. 推广效果统计表(关联本服务的song_promotion表)
  207. -- ------------------------------
  208. CREATE TABLE `promotion_stat` (
  209. `id` INT AUTO_INCREMENT PRIMARY KEY,
  210. `promotion_id` INT NOT NULL COMMENT '关联本服务的song_promotion.id',
  211. `stat_date` DATE NOT NULL COMMENT '统计日期',
  212. `click_count` INT DEFAULT 0 COMMENT '点击量',
  213. `play_count` INT DEFAULT 0 COMMENT '播放量',
  214. `collect_count` INT DEFAULT 0 COMMENT '收藏量',
  215. `share_count` INT DEFAULT 0 COMMENT '分享量',
  216. `create_time` DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
  217. FOREIGN KEY (`promotion_id`) REFERENCES `song_promotion` (`id`) ON DELETE CASCADE,
  218. UNIQUE KEY `uk_promotion_date` (`promotion_id`, `stat_date`),
  219. INDEX `idx_stat_date` (`stat_date`)
  220. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='推广效果统计表';