diff --git a/netease_music/sql/neteasemusic.sql b/netease_music/sql/neteasemusic.sql new file mode 100644 index 0000000..5df4938 --- /dev/null +++ b/netease_music/sql/neteasemusic.sql @@ -0,0 +1,351 @@ +/* + Source Server : MySQL 8.0 + Source Server Type : MySQL + Source Schema : neteasemusic +*/ + +CREATE DATABASE `neteaseMusic` CHARACTER SET 'utf8mb4' COLLATE 'utf8mb4_0900_ai_ci'; +USE `neteaseMusic`; + +SET NAMES utf8mb4; +SET FOREIGN_KEY_CHECKS = 0; + +-- ---------------------------- +-- Table structure for album +-- ---------------------------- +DROP TABLE IF EXISTS `album`; +CREATE TABLE `album` ( + `album_id` int(10) UNSIGNED NOT NULL COMMENT '专辑id', + `title` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '专辑名', + `description` varchar(1500) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '专辑简介', + `full_description` text CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL COMMENT '专辑简介(全)', + `image` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '封面图 http://p1.music.126.net/ 后面的部分', + `pub_date` varchar(100) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '发布日期', + `company` varchar(100) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '发行公司', + `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', + `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', + `version` tinyint(4) NOT NULL DEFAULT 1 COMMENT '数据记录版本(如果有字段调整则整体+1)', + PRIMARY KEY (`album_id`) USING BTREE, + INDEX `album_id`(`album_id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for analysis +-- ---------------------------- +DROP TABLE IF EXISTS `analysis`; +CREATE TABLE `analysis` ( + `key` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '参数名', + `value` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '参数值', + `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', + UNIQUE INDEX `key`(`key`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for artist +-- ---------------------------- +DROP TABLE IF EXISTS `artist`; +CREATE TABLE `artist` ( + `artist_id` int(10) UNSIGNED NOT NULL COMMENT '歌手id', + `title` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '歌手名', + `description` varchar(1500) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '歌手简介', + `image` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '封面图 http://p1.music.126.net/ 后面的部分', + `pub_date` varchar(100) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '发布日期', + `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', + `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', + PRIMARY KEY (`artist_id`) USING BTREE, + INDEX `artist_id`(`artist_id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for category +-- ---------------------------- +DROP TABLE IF EXISTS `category`; +CREATE TABLE `category` ( + `id` int(11) NOT NULL AUTO_INCREMENT COMMENT '分类id', + `title` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '分类名称', + `netease_id` int(11) NULL DEFAULT NULL COMMENT '网易音乐id', + `qianqian_id` int(11) NULL DEFAULT NULL COMMENT '千千音乐id', + `alias` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '分类别名', + `qianqian_group` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '千千音乐 分类所属分组', + `qianqian_group_chinese` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '千千音乐 分类所属分组(中文)', + `netease_group_chinese` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '网易音乐 分类所属分组(中文)', + PRIMARY KEY (`id`) USING BTREE, + UNIQUE INDEX `title`(`title`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for comment +-- ---------------------------- +DROP TABLE IF EXISTS `comment`; +CREATE TABLE `comment` ( + `comment_id` bigint(20) UNSIGNED NOT NULL COMMENT '评论id', + `parent_comment_id` bigint(20) UNSIGNED NOT NULL COMMENT '父评论id', + `user_id` bigint(20) UNSIGNED NOT NULL COMMENT '用户id', + `song_id` int(10) UNSIGNED NOT NULL COMMENT '歌曲id', + `content` text CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '评论内容', + `time` varchar(50) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL DEFAULT '' COMMENT '评论时间', + `like_count` int(11) NOT NULL COMMENT '点赞数', + `comment_type` tinyint(4) UNSIGNED NOT NULL COMMENT '评论类型 0-comments 1-hotComments 2-topComments', + `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', + `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', + PRIMARY KEY (`comment_id`) USING BTREE, + INDEX `song_id`(`song_id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for comment_progress +-- ---------------------------- +DROP TABLE IF EXISTS `comment_progress`; +CREATE TABLE `comment_progress` ( + `song_id` int(10) UNSIGNED NOT NULL COMMENT '歌曲id', + `max_time` bigint(20) NOT NULL DEFAULT 0 COMMENT '开始爬取/开始增量爬取的时候 最新一条评论的时间', + `min_time` bigint(20) NOT NULL DEFAULT 0 COMMENT '上一次爬取时最后一条评论的时间 第一次爬取时为0', + `current_time` bigint(20) NOT NULL DEFAULT 0 COMMENT '本次爬取/增量时,最早的一条评论时间', + `current_status` tinyint(4) UNSIGNED NOT NULL DEFAULT 0 COMMENT '爬取进度 0-等待爬取/增量爬取 1-爬取中 2-完成', + `total` int(10) NOT NULL DEFAULT 0 COMMENT '评论总数', + `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', + `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', + PRIMARY KEY (`song_id`) USING BTREE, + INDEX `current_status`(`current_status`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for log +-- ---------------------------- +DROP TABLE IF EXISTS `log`; +CREATE TABLE `log` ( + `id` int(10) UNSIGNED NOT NULL COMMENT 'id', + `name` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '方法/数据库', + `msg` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '出错信息', + `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', + INDEX `id`(`id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for lyric +-- ---------------------------- +DROP TABLE IF EXISTS `lyric`; +CREATE TABLE `lyric` ( + `song_id` int(10) UNSIGNED NOT NULL COMMENT '歌曲id', + `version` int(10) UNSIGNED NOT NULL COMMENT '歌词版本 -1代表没有数据', + `lyric` text CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '歌词', + `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', + `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', + PRIMARY KEY (`song_id`, `version`) USING BTREE, + INDEX `song_id`(`song_id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for playlist +-- ---------------------------- +DROP TABLE IF EXISTS `playlist`; +CREATE TABLE `playlist` ( + `playlist_id` bigint(20) UNSIGNED NOT NULL COMMENT '歌单id', + `title` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '歌单名', + `english_title` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '歌单名(英文)', + `description` varchar(1500) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '歌单简介', + `user_id` bigint(20) UNSIGNED NOT NULL COMMENT '用户id', + `tags` json NULL COMMENT '歌单标签(JSON格式数组)', + `alg_tags` json NULL COMMENT '歌单标签(JSON格式数组)', + `playlist_create_time` bigint(20) UNSIGNED NULL DEFAULT NULL COMMENT '创建日期', + `playlist_update_time` bigint(20) UNSIGNED NULL DEFAULT NULL COMMENT '更新日期', + `track_count` int(10) UNSIGNED NOT NULL COMMENT '歌单歌曲数', + `play_count` int(10) UNSIGNED NOT NULL COMMENT '歌单播放数', + `subscribed_count` int(10) UNSIGNED NOT NULL COMMENT '歌单收藏数', + `share_count` int(10) UNSIGNED NOT NULL COMMENT '歌单分享数', + `comment_count` int(10) UNSIGNED NOT NULL COMMENT '歌单评论数', + `cover_image` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '封面图 http://p1.music.126.net/ 后面的部分', + `title_image` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '封面图 http://p1.music.126.net/ 后面的部分', + `background_cover` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '封面图 http://p1.music.126.net/ 后面的部分', + `ordered` tinyint(4) NULL DEFAULT NULL COMMENT '排序 0-false 1-true', + `copied` tinyint(4) NULL DEFAULT NULL COMMENT '是否复制 0-false 1-true', + `status` tinyint(4) NULL DEFAULT NULL COMMENT '保留状态码', + `privacy` tinyint(4) NULL DEFAULT NULL COMMENT '保留状态码', + `ad_type` tinyint(4) NULL DEFAULT NULL COMMENT '保留状态码', + `special_type` int(11) NULL DEFAULT NULL COMMENT '保留状态码', + `official_playlist_type` varchar(20) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '保留状态码', + `op_recommend` tinyint(4) NULL DEFAULT NULL COMMENT '保留状态码 0-false 1-true', + `high_quality` tinyint(4) NULL DEFAULT NULL COMMENT '保留状态码 0-false 1-true', + `new_imported` tinyint(4) NULL DEFAULT NULL COMMENT '保留状态码 0-false 1-true', + `update_frequency` varchar(100) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '保留字段', + `grade_status` varchar(20) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '保留字段', + `score` varchar(20) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '保留字段', + `creator` json NULL COMMENT '保留字段(JSON格式数组)', + `video_ids` json NULL COMMENT '保留字段(JSON格式数组)', + `videos` json NULL COMMENT '保留字段(JSON格式数组)', + `banned_track_ids` json NULL COMMENT '保留字段(JSON格式数组)', + `remix_video` json NULL COMMENT '保留字段(JSON格式数组)', + `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', + `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', + PRIMARY KEY (`playlist_id`) USING BTREE, + INDEX `playlist_id`(`playlist_id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for song +-- ---------------------------- +DROP TABLE IF EXISTS `song`; +CREATE TABLE `song` ( + `song_id` int(10) UNSIGNED NOT NULL COMMENT '歌曲id', + `title` varchar(500) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '歌曲名', + `type` tinyint(4) NOT NULL COMMENT ' 0: 一般类型 1: 通过云盘上传的音乐,网易云不存在公开对应 2: 通过云盘上传的音乐,网易云存在公开对应', + `alias` json NULL COMMENT '歌曲别名(JSON格式数组)', + `pop` float NULL DEFAULT NULL COMMENT '歌曲热度', + `fee` tinyint(4) NULL DEFAULT NULL COMMENT '版权 0: 免费或无版权 1: VIP 歌曲 4: 购买专辑 8: 非会员可免费播放低音质,会员可播放高音质及下载 fee 为 1 或 8 的歌曲均可单独购买 2 元单曲', + `quality` varchar(500) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '高/中/低/无损质量文件信息', + `cd` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT 'None或如\"04\", \"1/2\", \"3\", \"null\"的字符串,表示歌曲属于专辑中第几张CD,对应音频文件的Tag', + `no` int(10) UNSIGNED NULL DEFAULT NULL COMMENT '表示歌曲属于CD中第几曲,0表示没有这个字段,对应音频文件的Tag', + `dj_id` int(10) UNSIGNED NULL DEFAULT NULL COMMENT '0: 不是DJ节目 其他:是DJ节目,表示DJ ID', + `s_id` int(10) UNSIGNED NULL DEFAULT NULL COMMENT '对于t == 2的歌曲,表示匹配到的公开版本歌曲ID', + `origin_cover_type` tinyint(4) NOT NULL DEFAULT 0 COMMENT '0: 未知 1: 原曲 2: 翻唱', + `image` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '封面图 http://p1.music.126.net/ 后面的部分', + `pub_date` varchar(100) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '发布日期(弃用)', + `pub_time` bigint(20) UNSIGNED NULL DEFAULT NULL COMMENT '发布日期 毫秒为单位的Unix时间戳', + `no_copyright_rcmd` varchar(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT 'None表示可以播,非空表示无版权', + `mv` int(10) UNSIGNED NULL DEFAULT NULL COMMENT '非零表示有MV ID', + `single` tinyint(4) NULL DEFAULT NULL COMMENT '0: 有专辑信息或者是DJ节目 1: 未知专辑', + `version` int(10) UNSIGNED NOT NULL DEFAULT 1 COMMENT '歌曲版本信息', + `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', + `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', + `data_version` tinyint(4) NOT NULL DEFAULT 1 COMMENT '数据记录版本(如果有字段调整则整体+1)', + PRIMARY KEY (`song_id`) USING BTREE, + INDEX `song_id`(`song_id`) USING BTREE, + INDEX `data_version`(`data_version`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for song_album_relation +-- ---------------------------- +DROP TABLE IF EXISTS `song_album_relation`; +CREATE TABLE `song_album_relation` ( + `song_id` int(10) UNSIGNED NOT NULL COMMENT '歌曲id', + `album_id` int(10) UNSIGNED NOT NULL COMMENT '专辑id', + `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', + `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', + PRIMARY KEY (`song_id`, `album_id`) USING BTREE, + INDEX `song_id`(`song_id`) USING BTREE, + INDEX `album_id`(`album_id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for song_artist_relation +-- ---------------------------- +DROP TABLE IF EXISTS `song_artist_relation`; +CREATE TABLE `song_artist_relation` ( + `song_id` int(10) UNSIGNED NOT NULL COMMENT '歌曲id', + `artist_id` int(10) UNSIGNED NOT NULL COMMENT '歌手id', + `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', + `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', + PRIMARY KEY (`song_id`, `artist_id`) USING BTREE, + INDEX `song_id`(`song_id`) USING BTREE, + INDEX `artist_id`(`artist_id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for song_playlist_relation +-- ---------------------------- +DROP TABLE IF EXISTS `song_playlist_relation`; +CREATE TABLE `song_playlist_relation` ( + `song_id` int(10) UNSIGNED NOT NULL COMMENT '歌曲id', + `playlist_id` int(10) UNSIGNED NOT NULL COMMENT '歌单id', + `alg` varchar(20) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '保留字段', + `rcmd_reason` varchar(20) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NULL DEFAULT NULL COMMENT '保留字段', + `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', + `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', + PRIMARY KEY (`song_id`, `playlist_id`) USING BTREE, + INDEX `song_id`(`song_id`) USING BTREE, + INDEX `playlist_id`(`playlist_id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for user +-- ---------------------------- +DROP TABLE IF EXISTS `user`; +CREATE TABLE `user` ( + `user_id` bigint(20) UNSIGNED NOT NULL COMMENT '用户id', + `user_type` varchar(50) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '用户类型', + `nickname` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '用户昵称', + `avatar_url` varchar(200) CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci NOT NULL COMMENT '用户头像 http://p1.music.126.net/ 后面的部分', + `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', + `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', + PRIMARY KEY (`user_id`) USING BTREE, + INDEX `user_id`(`user_id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for wait_check_album +-- ---------------------------- +DROP TABLE IF EXISTS `wait_check_album`; +CREATE TABLE `wait_check_album` ( + `id` bigint(20) UNSIGNED NOT NULL COMMENT 'id', + PRIMARY KEY (`id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for wait_check_artist +-- ---------------------------- +DROP TABLE IF EXISTS `wait_check_artist`; +CREATE TABLE `wait_check_artist` ( + `id` bigint(20) UNSIGNED NOT NULL COMMENT 'id', + PRIMARY KEY (`id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for wait_check_lyric +-- ---------------------------- +DROP TABLE IF EXISTS `wait_check_lyric`; +CREATE TABLE `wait_check_lyric` ( + `id` bigint(20) UNSIGNED NOT NULL COMMENT 'id', + PRIMARY KEY (`id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for wait_check_song +-- ---------------------------- +DROP TABLE IF EXISTS `wait_check_song`; +CREATE TABLE `wait_check_song` ( + `id` bigint(20) UNSIGNED NOT NULL COMMENT 'id', + PRIMARY KEY (`id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for wait_fetch_album +-- ---------------------------- +DROP TABLE IF EXISTS `wait_fetch_album`; +CREATE TABLE `wait_fetch_album` ( + `id` bigint(20) UNSIGNED NOT NULL COMMENT 'id', + `partition` tinyint(4) UNSIGNED NULL DEFAULT NULL COMMENT '分区 0-4', + PRIMARY KEY (`id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for wait_fetch_artist +-- ---------------------------- +DROP TABLE IF EXISTS `wait_fetch_artist`; +CREATE TABLE `wait_fetch_artist` ( + `id` bigint(20) UNSIGNED NOT NULL COMMENT 'id', + `partition` tinyint(4) UNSIGNED NULL DEFAULT NULL COMMENT '分区 0-4', + PRIMARY KEY (`id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for wait_fetch_lyric +-- ---------------------------- +DROP TABLE IF EXISTS `wait_fetch_lyric`; +CREATE TABLE `wait_fetch_lyric` ( + `id` bigint(20) UNSIGNED NOT NULL COMMENT 'id', + `partition` tinyint(4) UNSIGNED NULL DEFAULT NULL COMMENT '分区 0-4', + PRIMARY KEY (`id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +-- ---------------------------- +-- Table structure for wait_fetch_song +-- ---------------------------- +DROP TABLE IF EXISTS `wait_fetch_song`; +CREATE TABLE `wait_fetch_song` ( + `id` bigint(20) UNSIGNED NOT NULL COMMENT 'id', + `partition` tinyint(4) UNSIGNED NULL DEFAULT NULL COMMENT '分区 0-4', + PRIMARY KEY (`id`) USING BTREE +) ENGINE = InnoDB CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci ROW_FORMAT = Dynamic; + +SET FOREIGN_KEY_CHECKS = 1; diff --git a/netease_music/sql/statistic.sql b/netease_music/sql/statistic.sql index d318e74..652f4ca 100644 --- a/netease_music/sql/statistic.sql +++ b/netease_music/sql/statistic.sql @@ -1,3 +1,4 @@ +-- 更新统计数据 INSERT INTO analysis (`key`, `value`) VALUES ('songCount', (SELECT count(*) as count FROM song) ) ON DUPLICATE KEY UPDATE `value` = VALUES(`value`); INSERT INTO analysis (`key`, `value`) VALUES ('songWaiting', (SELECT count(DISTINCT song_id) AS count FROM ( SELECT song_id FROM song_artist_relation UNION SELECT song_id FROM song_album_relation ) t_tmp @@ -17,6 +18,16 @@ INSERT INTO analysis (`key`, `value`) VALUES ('songArtistCount', (SELECT count(* +-- 更新后初次全表扫描 +INSERT IGNORE INTO wait_song (song_id) SELECT song_id FROM song_artist_relation WHERE song_id NOT IN ( SELECT song_id FROM song ) +INSERT IGNORE INTO wait_song (song_id) SELECT song_id FROM song_album_relation WHERE song_id NOT IN ( SELECT song_id FROM song ) +INSERT IGNORE INTO wait_song (song_id) SELECT song_id FROM song_playlist_relation WHERE song_id NOT IN ( SELECT song_id FROM song ) + +-- 后续只需要扫描 wait_check 表 +INSERT IGNORE INTO wait_song (song_id) SELECT song_id FROM wait_check_song WHERE song_id NOT IN ( SELECT song_id FROM song ) + + + -- 查看需要爬取的 song 的分布 SELECT cast( format( t_tmp.song_id / 10000000, 0) * 10000000 as UNSIGNED ) as s, count(*) as count FROM ( @@ -59,6 +70,7 @@ ORDER BY s DESC -- optimize table +optimize table analysis; optimize table album; optimize table artist; optimize table category; @@ -83,6 +95,33 @@ optimize table wait_fetch_song; +-- 移动数据库 +RENAME TABLE neteasemusic.analysis TO neteasemusic_develop.analysis; +RENAME TABLE neteasemusic.album TO neteasemusic_develop.album; +RENAME TABLE neteasemusic.artist TO neteasemusic_develop.artist; +RENAME TABLE neteasemusic.category TO neteasemusic_develop.category; +RENAME TABLE neteasemusic.comment TO neteasemusic_develop.comment; +RENAME TABLE neteasemusic.comment_progress TO neteasemusic_develop.comment_progress; +RENAME TABLE neteasemusic.log TO neteasemusic_develop.log; +RENAME TABLE neteasemusic.lyric TO neteasemusic_develop.lyric; +RENAME TABLE neteasemusic.playlist TO neteasemusic_develop.playlist; +RENAME TABLE neteasemusic.song TO neteasemusic_develop.song; +RENAME TABLE neteasemusic.song_album_relation TO neteasemusic_develop.song_album_relation; +RENAME TABLE neteasemusic.song_artist_relation TO neteasemusic_develop.song_artist_relation; +RENAME TABLE neteasemusic.song_playlist_relation TO neteasemusic_develop.song_playlist_relation; +RENAME TABLE neteasemusic.user TO neteasemusic_develop.user; +RENAME TABLE neteasemusic.wait_check_album TO neteasemusic_develop.wait_check_album; +RENAME TABLE neteasemusic.wait_check_artist TO neteasemusic_develop.wait_check_artist; +RENAME TABLE neteasemusic.wait_check_lyric TO neteasemusic_develop.wait_check_lyric; +RENAME TABLE neteasemusic.wait_check_song TO neteasemusic_develop.wait_check_song; +RENAME TABLE neteasemusic.wait_fetch_album TO neteasemusic_develop.wait_fetch_album; +RENAME TABLE neteasemusic.wait_fetch_artist TO neteasemusic_develop.wait_fetch_artist; +RENAME TABLE neteasemusic.wait_fetch_lyric TO neteasemusic_develop.wait_fetch_lyric; +RENAME TABLE neteasemusic.wait_fetch_song TO neteasemusic_develop.wait_fetch_song; + + + + -- 查询单个数据库里面各个表所占磁盘空间大小包括其索引的大小 SELECT table_schema AS '数据库', @@ -96,4 +135,29 @@ FROM WHERE table_schema = 'neteasemusic' ORDER BY - table_rows DESC; \ No newline at end of file + table_rows DESC; + + + +-- analysis +-- album +-- artist +-- category +-- comment +-- comment_progress +-- log +-- lyric +-- playlist +-- song +-- song_album_relation +-- song_artist_relation +-- song_playlist_relation +-- user +-- wait_check_album +-- wait_check_artist +-- wait_check_lyric +-- wait_check_song +-- wait_fetch_album +-- wait_fetch_artist +-- wait_fetch_lyric +-- wait_fetch_song diff --git a/netease_music/sql/structure.sql b/netease_music/sql/structure.sql index a114d43..797aadb 100644 --- a/netease_music/sql/structure.sql +++ b/netease_music/sql/structure.sql @@ -1,4 +1,4 @@ -CREATE DATABASE `neteaseMusic` CHARACTER SET 'utf8mb4' COLLATE 'utf8mb4_general_ci'; +CREATE DATABASE `neteaseMusic`; USE `neteaseMusic`; CREATE TABLE `song` ( `song_id` int(10) unsigned NOT NULL COMMENT '歌曲id', @@ -26,7 +26,7 @@ CREATE TABLE `song` ( PRIMARY KEY (`song_id`), KEY `song_id` (`song_id`), KEY `data_version` (`data_version`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `artist` ( `artist_id` int(10) unsigned NOT NULL COMMENT '歌手id', @@ -38,7 +38,7 @@ CREATE TABLE `artist` ( `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', PRIMARY KEY (`artist_id`), KEY `artist_id` (`artist_id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `album` ( `album_id` int(10) unsigned NOT NULL COMMENT '专辑id', @@ -53,7 +53,7 @@ CREATE TABLE `album` ( `version` tinyint(4) NOT NULL DEFAULT 1 COMMENT '数据记录版本(如果有字段调整则整体+1)', PRIMARY KEY (`album_id`), KEY `album_id` (`album_id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `playlist` ( `playlist_id` bigint(20) unsigned NOT NULL COMMENT '歌单id', @@ -100,7 +100,7 @@ CREATE TABLE `playlist` ( `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', PRIMARY KEY (`playlist_id`), KEY `playlist_id` (`playlist_id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `song_playlist_relation` ( `song_id` int(10) unsigned NOT NULL COMMENT '歌曲id', @@ -112,7 +112,7 @@ CREATE TABLE `song_playlist_relation` ( PRIMARY KEY (`song_id`, `playlist_id`), KEY `song_id` (`song_id`), KEY `playlist_id` (`playlist_id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `song_album_relation` ( `song_id` int(10) unsigned NOT NULL COMMENT '歌曲id', @@ -122,7 +122,7 @@ CREATE TABLE `song_album_relation` ( PRIMARY KEY (`song_id`,`album_id`), KEY `song_id` (`song_id`), KEY `album_id` (`album_id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `song_artist_relation` ( `song_id` int(10) unsigned NOT NULL COMMENT '歌曲id', @@ -132,7 +132,7 @@ CREATE TABLE `song_artist_relation` ( PRIMARY KEY `song_id` (`song_id`,`artist_id`), KEY `song_id` (`song_id`), KEY `artist_id` (`artist_id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `lyric` ( `song_id` int(10) unsigned NOT NULL COMMENT '歌曲id', @@ -142,7 +142,7 @@ CREATE TABLE `lyric` ( `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', PRIMARY KEY (`song_id`,`version`), KEY `song_id` (`song_id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `user` ( `user_id` bigint(20) unsigned NOT NULL COMMENT '用户id', @@ -153,7 +153,7 @@ CREATE TABLE `user` ( `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', PRIMARY KEY (`user_id`), KEY `user_id` (`user_id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `comment` ( `comment_id` bigint(20) unsigned NOT NULL COMMENT '评论id', @@ -168,7 +168,7 @@ CREATE TABLE `comment` ( `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', PRIMARY KEY (`comment_id`), KEY `song_id` (`song_id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `comment_progress` ( `song_id` int(10) unsigned NOT NULL COMMENT '歌曲id', @@ -181,7 +181,7 @@ CREATE TABLE `comment_progress` ( `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', PRIMARY KEY (`song_id`), KEY `current_status` (`current_status`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `category` ( `id` int NOT NULL AUTO_INCREMENT COMMENT '分类id', @@ -194,7 +194,7 @@ CREATE TABLE `category` ( `netease_group_chinese` varchar(255) DEFAULT NULL COMMENT '网易音乐 分类所属分组(中文)', PRIMARY KEY (`id`), UNIQUE KEY `title` (`title`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `log` ( `id` int(10) unsigned NOT NULL COMMENT 'id', @@ -202,36 +202,36 @@ CREATE TABLE `log` ( `msg` varchar(200) NOT NULL COMMENT '出错信息', `create_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '爬取时间', KEY `id` (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `analysis` ( `key` varchar(255) NOT NULL COMMENT '参数名', `value` varchar(255) DEFAULT NULL COMMENT '参数值', `modify_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '最后更新时间', UNIQUE KEY `key` (`key`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `wait_check_song` ( `id` bigint(20) unsigned NOT NULL COMMENT 'id', PRIMARY KEY (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `wait_check_artist` ( `id` bigint(20) unsigned NOT NULL COMMENT 'id', PRIMARY KEY (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `wait_check_album` ( `id` bigint(20) unsigned NOT NULL COMMENT 'id', PRIMARY KEY (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `wait_check_lyric` ( `id` bigint(20) unsigned NOT NULL COMMENT 'id', PRIMARY KEY (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); @@ -239,22 +239,22 @@ CREATE TABLE `wait_fetch_song` ( `id` bigint(20) unsigned NOT NULL COMMENT 'id', `partition` tinyint(4) unsigned DEFAULT NULL COMMENT '分区 0-4', PRIMARY KEY (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `wait_fetch_artist` ( `id` bigint(20) unsigned NOT NULL COMMENT 'id', `partition` tinyint(4) unsigned DEFAULT NULL COMMENT '分区 0-4', PRIMARY KEY (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `wait_fetch_album` ( `id` bigint(20) unsigned NOT NULL COMMENT 'id', `partition` tinyint(4) unsigned DEFAULT NULL COMMENT '分区 0-4', PRIMARY KEY (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); CREATE TABLE `wait_fetch_lyric` ( `id` bigint(20) unsigned NOT NULL COMMENT 'id', `partition` tinyint(4) unsigned DEFAULT NULL COMMENT '分区 0-4', PRIMARY KEY (`id`) -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; +); diff --git a/netease_music/todo.txt b/netease_music/todo.txt index 5b76264..9f5d90d 100644 --- a/netease_music/todo.txt +++ b/netease_music/todo.txt @@ -53,4 +53,11 @@ alter table song add partition ( PARTITION p3 VALUES LESS THAN (1500000000), PARTITION p4 VALUES LESS THAN (2000000000), PARTITION p5 VALUES LESS THAN MAXVALUE -); \ No newline at end of file +); + + + +SQL文件说明 +sql/structure.sql 中的SQL为最简,不包含字段的编码集 +sql/neteasemusic.sql 中的SQL为数据库导出,包含字段的编码集 +项目数据库 CHARACTER SET 统一使用 'utf8mb4',COLLATE 统一使用 'utf8mb4_general_ci' \ No newline at end of file