«
MySQL 批量修改数据表编码及字符集

时间:2022-6-29    作者:网络剑客    分类: mysql


一、 修改数据库编码及字符集

修改数据库编码及字符集比较简单:

ALTER DATABASE db_name CHARACTER SET = utf8mb4 COLLATE = utf8mb4_0900_ai_ci;

db_name: 数据库名称
set =: 后面跟着编码
COLLATE =: 后面跟着字符集

二、修改数据表与表中字段的编码及字符集

注:这里需要分两步处理!

1、利用语句,生成所有实际执行的语句:

SELECT 
CONCAT("ALTER TABLE `", TABLE_NAME,"` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;")
AS target_tables
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_SCHEMA="db_name" # 修改为需要更改的数据库名称
AND TABLE_TYPE="BASE TABLE"

SET \ COLLATE 设置为需要修改为的编码 \ 字符集
TABLE_SCHEMA="db_name":修改为数据库名称

此语句会基于 MySQL 的元数据表,得到一组可直接执行的 SQL 列表,如下:

ALTER TABLE `failed_jobs` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `hotel` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `hotel_host` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `jobs` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `message` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `migrations` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `operation_log` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `password_resets` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `permission` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `role` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `role_permission` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `role_user` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `system_log` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
ALTER TABLE `user` CONVERT TO CHARACTER SET utf8mb4 COLLATE utf8mb4_0900_ai_ci;

2、直接将语句粘贴并执行即可。
注意,这里使用 CONVERT TO 而非 DEFAULT,是因为后者不会修改表中字段的编码和字符集。
此外,对于数据表比较多的数据库,可以先将第一步的执行结果导出到 .sql 文件,再通过该 SQL 文件执行即可。

标签: mysql