ä½è ï¼å¾èè£
ç±å¯çååºäº¤ä»æå¡é¨ DBA å¢éæåï¼ä¸»è¦è´è´£MySQLæ éå¤ç以åç¸å ³ææ¯æ¯æãç±å¥½çµå½±ï¼æ¸¸æï¼æ 游以åæ¡çã
æ¬ææ¥æºï¼ååæ稿
*ç±å¯çå¼æºç¤¾åºåºåï¼ååå 容æªç»ææä¸å¾éæ使ç¨ï¼è½¬è½½è¯·èç³»å°ç¼å¹¶æ³¨ææ¥æºã
ä¸ãé®é¢èæ¯
æ客æ·ä¹åéå°ä¸ä¸ª mysql8.0.21 å®ä¾ä¸æåºè§åçæ¥éï¼æ¯å¨è°ç¨è§å¾æ¶æåºï¼æ¥éä¿¡æ¯å¦ä¸ï¼
ERROR 1267 (HY000): Illegal mix of collations (utf8mb4_general_ci,IMPLICIT) and (utf8mb4_0900_ai_ci,IMPLICIT) for operation '='
äºãé®é¢æ¨¡æ
mysql> show create table t1\G;
*************************** 1. row ***************************
Table: t1
Create Table: CREATE TABLE `t1` (
`name1` varchar(12) CHARACTER SET utf8mb4 COLLATE utf8mb4_general_ci DEFAULT NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci
1 row in set (0.00 sec)
mysql> show create table t2\G;
*************************** 1. row ***************************
Table: t2
Create Table: CREATE TABLE `t2` (
`name2` varchar(12) DEFAULT NULL
) ENGINE=InnoDB DEFAULT CHARSET=latin1
1 row in set (0.00 sec)
mysql> CREATE VIEW t3 as select * from t1,t2 where `t1`.`name1`= `t2`.`name2`;
Query OK, 0 rows affected (0.06 sec)
mysql> select * from t3;
ERROR 1267 (HY000): Illegal mix of collations (utf8mb4_general_ci,IMPLICIT) and (utf8mb4_0900_ai_ci,IMPLICIT) for operation '='
ä¸ãé®é¢åæ
éè¿æ¥çè§å¾å®ä¹ï¼å¯ä»¥åç°ç±äºè§å¾ä¸æ¶åå°çä¸¤å¼ è¡¨å符éä¸åï¼æ以å建è§å¾æ¶ MySQL ä¼èªå¨ä½¿ç¨ convert å½æ°è½¬æ¢å符éã
mysql> show create view t3\G;
*************************** 1. row ***************************
View: t3
Create View: CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `t3` AS select `t1`.`name1` AS `name1`,`t2`.`name2` AS `name2` from (`t1` join `t2`) where (`t1`.`name1` = convert(`t2`.`name2` using utf8mb4))
character_set_client: utf8mb4
collation_connection: utf8mb4_general_ci
1 row in set (0.00 sec)
å¨ MySQL 8.0 ä¸ utf8mb4 çé»è®¤æåºè§å为 utf8mb4_0900_ai_ci ï¼èå¨ t1 表çæåºè§å为 utf8mb4_general_ci ï¼é£ä¹æ们è¯çå°æåºè§åç¸å ³çåæ°ä¿®æ¹ååæ§è¡ SQL ççï¼ä¿®æ¹åçç¯å¢åæ°å¦ä¸
mysql> show variables like '%collat%';
+-------------------------------+--------------------+
| Variable_name | Value |
+-------------------------------+--------------------+
| collation_connection | utf8mb4_general_ci |
| collation_database | utf8mb4_bin |
| collation_server | utf8mb4_bin |
| default_collation_for_utf8mb4 | utf8mb4_general_ci |
+-------------------------------+--------------------+
å次æ§è¡ sql åç°è¿æ¯ä¼æ¥ä¸æ ·çéã
mysql> select * from t1,t2 where `t1`.`name1`=convert(`t2`.`name2` using utf8mb4);
ERROR 1267 (HY000): Illegal mix of collations (utf8mb4_general_ci,IMPLICIT) and (utf8mb4_0900_ai_ci,IMPLICIT) for operation '='
éè¿ show collation æ¥æ¥ç utf8mb4 å符é对åºçé»è®¤æåºè§åï¼è¾åºæ¾ç¤ºé»è®¤è§å为 utf8mb4_general_ci ï¼å¹¶ä¸æ¯ utf8mb4_0900_ai_ci ã
mysql> show collation like '%utf8mb4%';
+----------------------------+---------+-----+---------+----------+---------+---------------+
| Collation | Charset | Id | Default | Compiled | Sortlen | Pad_attribute |
+----------------------------+---------+-----+---------+----------+---------+---------------+
| utf8mb4_general_ci | utf8mb4 | 45 | Yes | Yes | 1 | PAD SPACE |
+----------------------------+---------+-----+---------+----------+---------+---------------+
mysql> show character set like '%utf8mb4%';
+---------+---------------+--------------------+--------+
| Charset | Description | Default collation | Maxlen |
+---------+---------------+--------------------+--------+
| utf8mb4 | UTF-8 Unicode | utf8mb4_general_ci | 4 |
+---------+---------------+--------------------+--------+
1 row in set (0.00 sec)
继ç»ææ¥åç°å æ°æ®ä¸çå符éé»è®¤æåºè§åå¦ä¸ï¼é»è®¤è§å为 utf8mb4_0900_ai_ci ã
mysql> select * from INFORMATION_SCHEMA.COLLATIONS where IS_DEFAULT='Yes' and CHARACTER_SET_NAME='utf8mb4'\G;
*************************** 1. row ***************************
COLLATION_NAME: utf8mb4_0900_ai_ci
CHARACTER_SET_NAME: utf8mb4
ID: 255
IS_DEFAULT: Yes
IS_COMPILED: Yes
SORTLEN: 0
PAD_ATTRIBUTE: NO PAD
1 row in set (0.00 sec)
æ£æ¥åæ°åç°ï¼å æ°æ®ä¿¡æ¯ä¸ utf8mb4 å符éé»è®¤æåºè§åæ¯ utf8mb4_0900_ai_ci ï¼show collation/show character è¾åºçé½æ¯ utf8mb4_general_ci ã为ä»ä¹ show æ¾ç¤ºçç»æå INFORMATION_SCHEMA.COLLATIONS 表æ¥å°çä¿¡æ¯è¿ä¸ä¸æ ·å¢ï¼æ¤å¤æ们æä¸æä¸ä¸è¡¨ï¼å±ä»¬å ççå®æ¹ææ¡£ä¸ convert å½æ°ç¨æ³ï¼å ¶ä¸æä¸é¢è¿æ®µåæï¼
If you specify CHARACTER SET charset_name as just shown, the character set and collation of the result are charset_name and the default collation of charset_name. If you omit CHARACTER SET charset_name, the character set and collation of the result are defined by the character_set_connection and collation_connection system variables that determine the default connection character set and collation (see Section 10.4, âConnection Character Sets and Collationsâ).
ä»ä¸è¿°åæå¯ç¥å¦æ convert åªæå®äºå符éï¼é£ä¹è¯¥ç»æçæåºè§åå°±æ¯ææå®å符éçé»è®¤è§åï¼ç±ä¹åçæµè¯æ åµå¯ç¥ï¼convert 使ç¨çæ¯ INFORMATION_SCHEMA.COLLATIONS çæåºè§åï¼èä¸æ¯ default_collation_for_utf8mb4 æå®ç utf8mb4_general_ci ï¼é£æ们æ¥çç default_collation_for_utf8mb4 åæ°ä¸»è¦ä½ç¨åºæ¯ï¼
- SHOW COLLATION and SHOW CHARACTER SET.
- CREATE TABLE and ALTER TABLE having a CHARACTER SET utf8mb4 clause without a COLLATION clause, either for the table character set or for a column character set.
- CREATE DATABASE and ALTER DATABASE having a CHARACTER SET utf8mb4 clause without a COLLATION clause.
- Any statement containing a string literal of the form _utf8mb4'some text' without a COLLATE clause.
å ¶ä¸ï¼ç¬¬ä¸ç¹è§£éäºä¸ºä»ä¹ show æ¥å°çä¿¡æ¯åå æ°æ®ä¸ä¿¡æ¯ä¸ä¸æ ·ï¼default_collation_for_utf8mb4 ä¿®æ¹åå½±å show COLLATION and SHOW CHARACTER SET çæ¥è¯¢ç»æï¼å¹¶ä¸ä¼æ¹åå符éçé»è®¤æåºè§åï¼æ以utf8mb4 çé»è®¤è§åè¿æ¯ utf8mb4_0900_ai_ci ï¼sql æ§è¡ä¾ç¶ä¼æ¥éã
å° convert å½æ°æå®ä¸º t1.name1 å段çæåºè§ååï¼sql æ§è¡æ£å¸¸ã
mysql> select * from t1,t2 where `t1`.`name1` = convert(`t2`.`name2` using utf8mb4) collate utf8mb4_general_ci;
+-------+-------+
| name1 | name2 |
+-------+-------+
| jack | jack |
+-------+-------+
1 row in set (0.00 sec)
å¦å¤ï¼ä¸é¢æµè¯å¯ä»¥éªè¯ default_collation_for_utf8mb4 ç第å个åºæ¯ã
mysql> select * from INFORMATION_SCHEMA.COLLATIONS where IS_DEFAULT='Yes' and CHARACTER_SET_NAME='utf8mb4'\G;
*************************** 1. row ***************************
COLLATION_NAME: utf8mb4_0900_ai_ci
CHARACTER_SET_NAME: utf8mb4
ID: 255
IS_DEFAULT: Yes
IS_COMPILED: Yes
SORTLEN: 0
PAD_ATTRIBUTE: NO PAD
1 row in set (0.00 sec)
mysql> show variables like '%default_collation%';
+-------------------------------+--------------------+
| Variable_name | Value |
+-------------------------------+--------------------+
| default_collation_for_utf8mb4 | utf8mb4_general_ci |
+-------------------------------+--------------------+
1 row in set (0.01 sec)
mysql> set @s1 = _utf8mb4 'jack',@s2 = _utf8mb4 'jack';
Query OK, 0 rows affected (0.00 sec)
mysql> SELECT @s1 = @s2;
+-----------+
| @s1 = @s2 |
+-----------+
| 1 |
+-----------+
1 row in set (0.00 sec)
_utf8mb4声æç@s1å@s2æåºè§åæ¯default_collation_for_utf8mb4åæ°å¼ï¼ä¸ºutf8mb4_general_ci
mysql> SELECT @s1 = CONVERT(@s2 USING utf8mb4);
ERROR 1267 (HY000): Illegal mix of collations (utf8mb4_general_ci,IMPLICIT) and (utf8mb4_0900_ai_ci,IMPLICIT) for operation '='
æ¤æ¶ï¼ç»è¿CONVERTå½æ°å¤çç@s2æåºè§åæ¯utf8mb4_0900_ai_ciï¼æ以ä¼æ¥é
mysql> SELECT @s1 = CONVERT(@s2 USING utf8mb4) collate utf8mb4_general_ci;
+-------------------------------------------------------------+
| @s1 = CONVERT(@s2 USING utf8mb4) collate utf8mb4_general_ci |
+-------------------------------------------------------------+
| 1 |
+-------------------------------------------------------------+
1 row in set (0.00 sec)
åãé®é¢æ»ç»
è¿ç»´ä¸ä¸ºé¿å å符éå¼èµ·çæ¥éé®é¢ï¼æå¦ä¸å»ºè®®å¯ä¾åèï¼ï¼å ·ä½åæ°å¼æ ¹æ®ä¸å¡éæ±éæ©ï¼
- å建æ°æ®åºå®ä¾æ¶éæå®åæ° character_set_databaseï¼é»è®¤å¼ï¼utf8mb4ï¼ï¼character_set_serverï¼é»è®¤å¼ï¼utf8mb4ï¼ã
- å½éè¦å建éé»è®¤å符é database / table æ¶ï¼éè¦å¨ sql ä¸æç¡®æå®å符éåæåºè§åã
- 使ç¨convertå½æ°è½¬æ¢å符éæ¶ï¼å½å段æåºè§åä¸æ¯è½¬æ¢åå符éçé»è®¤æåºè§åï¼éè¦æå®å ·ä½çæåºè§åãSELECT @s1 = CONVERT(@s2 USING utf8mb4) collate utf8mb4_general_ci
- MySQL 5.7è¿ç§»è³MySQL 8.0æ¶ï¼é注æMySQL 5.7çæ¬ä¸utf8mb4é»è®¤æåºè§åæ¯ utf8mb4_general_ciï¼MySQL 8.0ä¸ utf8mb4 é»è®¤æåºè§åæ¯ utf8mb4_0900_ai_ci ã
åè
https://dev.mysql.com/doc/refman/8.0/en/server-system-variables.html
https://dev.mysql.com/doc/refman/8.0/en/charset-connection.html
https://dev.mysql.com/doc/refman/8.0/en/cast-functions.html#function_convert