
一、事故还原
CREATE TABLE `student_info` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT '学号',
`name` varchar(20) CHARACTER SET utf8 DEFAULT NULL COMMENT '姓名', PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='学生基本信息表';
#尾部无空格
INSERT INTO `student_info` (`name`) VALUES ('fossi');
#尾部带一个空格
INSERT INTO `student_info` (`name`) VALUES ('fossi ');
#尾部带两个空格
INSERT INTO `student_info` (`name`) VALUES ('fossi ');
mysql> select length(name) from student_info;
+--------------+
| length(name) |
+--------------+
| 5 |
| 6 |
| 7 |
+--------------+
3 rows in set (0.00 sec)
#不带空格的fossi
mysql> select * from student_info where name='fossi';
+----+---------+
| id | name |
+----+---------+
| 1 | fossi |
| 2 | fossi |
| 3 | fossi |
+----+---------+
3 rows in set (0.00 sec)
#带一个空格
mysql> select * from student_info where name='fossi ';
+----+---------+
| id | name |
+----+---------+
| 1 | fossi |
| 2 | fossi |
| 3 | fossi |
+----+---------+
3 rows in set (0.00 sec)
#带两个空格
mysql> select * from student_info where name='fossi ';
+----+---------+
| id | name |
+----+---------+
| 1 | fossi |
| 2 | fossi |
| 3 | fossi |
+----+---------+
3 rows in set (0.00 sec)
#前面无空格
INSERT INTO `student_info` (`name`) VALUES ('fossi');
#前面带一个空格
INSERT INTO `student_info` (`name`) VALUES (' fossi');
#前面带两个空格
INSERT INTO `student_info` (`name`) VALUES (' fossi');
mysql> select * from student_info;
+----+---------+
| id | name |
+----+---------+
| 1 | fossi |
| 2 | fossi |
| 3 | fossi |
+----+---------+
3 rows in set (0.00 sec)
mysql> select length(name) from student_info;
+--------------+
| length(name) |
+--------------+
| 5 |
| 6 |
| 7 |
+--------------+
3 rows in set (0.00 sec)
#不带空格的fossi
mysql> select * from student_info where name='fossi';
+----+-------+
| id | name |
+----+-------+
| 1 | fossi |
+----+-------+
1 row in set (0.00 sec)
#带一个空格
mysql> select * from student_info where name=' fossi';
+----+--------+
| id | name |
+----+--------+
| 2 | fossi |
+----+--------+
1 row in set (0.00 sec)
#带两个空格
mysql> select * from student_info where name=' fossi';
+----+---------+
| id | name |
+----+---------+
| 3 | fossi |
+----+---------+
1 row in set (0.00 sec)

二、合理推测
CREATE TABLE `student_info` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT '学号',
`name` varchar(20) CHARACTER SET utf8 DEFAULT NULL COMMENT '姓名',
UNIQUE KEY uk_name (name),
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='学生基本信息表';
mysql> #尾部无空格
mysql> INSERT INTO `student_info` (`name`) VALUES ('fossi');
Query OK, 1 row affected (0.00 sec)
mysql> #尾部带一个空格
mysql> INSERT INTO `student_info` (`name`) VALUES ('fossi ');
ERROR 1062 (23000): Duplicate entry 'fossi ' for key 'uk_name'
mysql> #尾部带两个空格
mysql> INSERT INTO `student_info` (`name`) VALUES ('fossi ');
ERROR 1062 (23000): Duplicate entry 'fossi ' for key 'uk_name'

三、权威文档


四、解决思路
🧷思路一:LIKE

#不带空格的fossi
mysql> select * from student_info where name like 'fossi';
+----+-------+
| id | name |
+----+-------+
| 1 | fossi |
+----+-------+
1 row in set (0.00 sec)
#带一个空格
mysql> select * from student_info where name like 'fossi ';
+----+--------+
| id | name |
+----+--------+
| 2 | fossi |
+----+--------+
1 row in set (0.00 sec)
#带两个空格
mysql> select * from student_info where name like 'fossi ';
+----+---------+
| id | name |
+----+---------+
| 3 | fossi |
+----+---------+
1 row in set (0.00 sec)
-
LIKE后面的字段可以不带通配符; -
LIKE是基于逐个字符进行比较的,这样就不会忽略尾部的空格
🧷思路二:BINARY

#不带空格的fossi
mysql> select * from student_info where name = BINARY 'fossi';
+----+-------+
| id | name |
+----+-------+
| 1 | fossi |
+----+-------+
1 row in set (0.00 sec)
#带一个空格
mysql> select * from student_info where name = BINARY 'fossi ';
+----+--------+
| id | name |
+----+--------+
| 2 | fossi |
+----+--------+
1 row in set (0.00 sec)
#带两个空格
mysql> select * from student_info where name = BINARY 'fossi ';
+----+---------+
| id | name |
+----+---------+
| 3 | fossi |
+----+---------+
1 row in set (0.00 sec)

五、总结
本文的结论如下:
-
在存储时,不会自动截断尾部的空格,会按原值存储;
-
MySQL的CHAR、VARCHAR、TEXT等字符串字段在等值比较(”=”)时,基于PAD SPACE校对规则,会忽略掉尾部的空格;
-
如果想要精确查询就不能用等值查询(”=”),而应改用LIKE或BINARY;
原文始发于微信公众号(幕后哈土奇):10|第十话:基础篇- MySQL字符串等值查询的一个有趣现象
版权声明:本文内容由互联网用户自发贡献,该文观点仅代表作者本人。本站仅提供信息存储空间服务,不拥有所有权,不承担相关法律责任。如发现本站有涉嫌侵权/违法违规的内容, 请发送邮件至 举报,一经查实,本站将立刻删除。
文章由极客之音整理,本文链接:https://www.bmabk.com/index.php/post/112848.html