文章思维导图
当MySQL表字段设置unique key
或者primary key
时,被约束的字段就必须是唯一的。新插入数据直接使用insert into
,如果出现唯一性冲突,就会抛出异常。我们应该根据需求选择合适的插入语句。
为了演示,我们先新建一张user表,SQL语句如下:
CREATE TABLE `user` (
`id` bigint(20) UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '无意义自增id',
`username` varchar(64) DEFAULT NULL COMMENT '用户名',
`password` varchar(64) DEFAULT NULL COMMENT '密码',
`mobile_phone_number` varchar(20) DEFAULT NULL COMMENT '手机号码',
`email` varchar(64) DEFAULT NULL COMMENT '邮箱',
`delete_state` tinyint(1) UNSIGNED DEFAULT 0 COMMENT '用户状态,1表示删除,0表示未删除',
`create_time` datetime(0) NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`update_time` datetime(0) DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`id`),
UNIQUE INDEX `uk_username`(`username`) COMMENT '用户名唯一'
) ENGINE = InnoDB;
-- ----------------------------
-- Records of user
-- ----------------------------
INSERT INTO `user`(username,password,mobile_phone_number,email,delete_state,create_time,update_time) VALUES('JourWon', '123456', '13800000000', 'JourWon@163.com', 0, CURRENT_TIMESTAMP, NULL);
INSERT INTO `user`(username,password,mobile_phone_number,email,delete_state,create_time,update_time) VALUES('马云', '123456', '13800000011', 'JackMa@163.com', 0, CURRENT_TIMESTAMP, NULL);
INSERT INTO `user`(username,password,mobile_phone_number,email,delete_state,create_time,update_time) VALUES('马化腾', '123456', '13800000022', 'PonyMa@163.com', 0, CURRENT_TIMESTAMP, NULL);
INSERT INTO `user`(username,password,mobile_phone_number,email,delete_state,create_time,update_time) VALUES('李彦宏', '123456', '13800000033', 'RobinLee@163.com', 0, CURRENT_TIMESTAMP, NULL);
INSERT INTO `user`(username,password,mobile_phone_number,email,delete_state,create_time,update_time) VALUES('任正非', '123456', '13800000044', 'RenZhengfei@163.com', 0, CURRENT_TIMESTAMP, NULL);
INSERT INTO `user`(username,password,mobile_phone_number,email,delete_state,create_time,update_time) VALUES('Jobs', '123456', '13800000055', 'Jobs@163.com', 0, CURRENT_TIMESTAMP, NULL);
INSERT INTO `user`(username,password,mobile_phone_number,email,delete_state,create_time,update_time) VALUES('Bill Gates', '123456', '13800000066', 'Bill Gates@163.com', 0, CURRENT_TIMESTAMP, NULL);
INSERT INTO `user`(username,password,mobile_phone_number,email,delete_state,create_time,update_time) VALUES('Buffett', '123456', '13800000077', 'Buffett@163.com', 0, CURRENT_TIMESTAMP, NULL);
mysql> select * from user;
+----+------------+----------+---------------------+---------------------+--------------+---------------------+-------------+
| id | username | password | mobile_phone_number | email | delete_state | create_time | update_time |
+----+------------+----------+---------------------+---------------------+--------------+---------------------+-------------+
| 1 | JourWon | 123456 | 13800000000 | JourWon@163.com | 0 | 2021-03-03 11:16:39 | NULL |
| 2 | 马云 | 123456 | 13800000011 | JackMa@163.com | 0 | 2021-03-03 11:16:39 | NULL |
| 3 | 马化腾 | 123456 | 13800000022 | PonyMa@163.com | 0 | 2021-03-03 11:16:39 | NULL |
| 4 | 李彦宏 | 123456 | 13800000033 | RobinLee@163.com | 0 | 2021-03-03 11:16:39 | NULL |
| 5 | 任正非 | 123456 | 13800000044 | RenZhengfei@163.com | 0 | 2021-03-03 11:16:39 | NULL |
| 6 | Jobs | 123456 | 13800000055 | Jobs@163.com | 0 | 2021-03-03 11:16:39 | NULL |
| 7 | Bill Gates | 123456 | 13800000066 | Bill Gates@163.com | 0 | 2021-03-03 11:16:39 | NULL |
| 8 | Buffett | 123456 | 13800000077 | Buffett@163.com | 0 | 2021-03-03 11:16:40 | NULL |
+----+------------+----------+---------------------+---------------------+--------------+---------------------+-------------+
8 rows in set (0.00 sec)
常用插入语句
insert into
当插入数据时,如果唯一性校验出现重复问题,则报错;
如果没有重复性问题,则执行插入操作。
简单总结:重复则直接报错,sql 语句不执行,不重复则插入。
示例
INSERT INTO `user`(username,password,mobile_phone_number,email,delete_state,create_time,update_time) VALUES('Buffett', '123456', '13800000077', 'Buffett@163.com', 0, CURRENT_TIMESTAMP, NULL);
执行结果
mysql> INSERT INTO `user`(username,password,mobile_phone_number,email,delete_state,create_time,update_time) VALUES('Buffett', '123456', '13800000077', 'Buffett@163.com', 0, CURRENT_TIMESTAMP, NULL);
ERROR 1062 (23000): Duplicate entry 'Buffett' for key 'uk_username'
insert ignore into
当插入数据时,如果唯一性校验出现重复问题,则忽略错误,只以警告形式返回,不执行此SQL语句;
如果没有重复性问题,则执行插入操作。
简单总结:重复则忽略,sql 语句不执行,不重复则插入。
示例
insert ignore into `user`(username,password,mobile_phone_number,email,delete_state,create_time,update_time) VALUES('Buffett', '123456', '13800000077', 'Buffett@163.com', 0, CURRENT_TIMESTAMP, NULL);
执行结果
mysql> insert ignore into `user`(username,password,mobile_phone_number,email,delete_state,create_time,update_time) VALUES('Buffett', '123456', '13800000077', 'Buffett@163.com', 0, CURRENT_TIMESTAMP, NULL);
Query OK, 0 rows affected, 1 warning (0.00 sec)
mysql> show warnings;
+---------+------+-------------------------------------------------+
| Level | Code | Message |
+---------+------+-------------------------------------------------+
| Warning | 1062 | Duplicate entry 'Buffett' for key 'uk_username' |
+---------+------+-------------------------------------------------+
1 row in set (0.00 sec)
mysql> select * from user where username='Buffett';
+----+----------+----------+---------------------+-----------------+--------------+---------------------+-------------+
| id | username | password | mobile_phone_number | email | delete_state | create_time | update_time |
+----+----------+----------+---------------------+-----------------+--------------+---------------------+-------------+
| 8 | Buffett | 123456 | 13800000077 | Buffett@163.com | 0 | 2021-03-03 11:16:40 | NULL |
+----+----------+----------+---------------------+-----------------+--------------+---------------------+-------------+
1 row in set (0.00 sec)
insert into ... on duplicate key update
当插入数据时,如果唯一性校验出现重复问题,则在原有记录基础上,更新指定字段内容,其它字段内容保留;
如果没有重复性问题,则执行插入操作。
简单总结:重复则更新指定字段,不重复则插入。
示例
INSERT INTO `user` ( username, PASSWORD, mobile_phone_number, email ) VALUES('Buffett', '123456', '13800000088', 'Buffett@163.com' ) ON DUPLICATE KEY UPDATE mobile_phone_number = '13800000088';
执行结果
mysql> INSERT INTO `user` ( username, PASSWORD, mobile_phone_number, email ) VALUES('Buffett', '123456', '13800000088', 'Buffett@163.com' ) ON DUPLICATE KEY UPDATE mobile_phone_number = '13800000088';
Query OK, 2 rows affected (0.00 sec)
表记录,mobile_phone_number
从 '13800000077' 更新为 '13800000088' 了,update_time
也从NULL
更新为有值了,但是id
没有变:
mysql> select * from user where username='Buffett';
+----+----------+----------+---------------------+-----------------+--------------+---------------------+---------------------+
| id | username | password | mobile_phone_number | email | delete_state | create_time | update_time |
+----+----------+----------+---------------------+-----------------+--------------+---------------------+---------------------+
| 8 | Buffett | 123456 | 13800000088 | Buffett@163.com | 0 | 2021-03-03 11:16:40 | 2021-03-03 11:19:30 |
+----+----------+----------+---------------------+-----------------+--------------+---------------------+---------------------+
1 row in set (0.00 sec)
replace into
replace into表示插入替换数据,当插入数据时,如果唯一性校验出现重复问题,删除旧记录,插入新记录;
如果没有重复性问题,则执行插入操作,效果和insert into是一样的。
简单总结:重复则先删除再插入新记录,不重复则插入
。
示例
replace into `user` (username, password, mobile_phone_number, email ) values('Buffett', '123456', '13800000099', 'Buffett@163.com');
执行结果
mysql> replace into `user` (username, password, mobile_phone_number, email ) values('Buffett', '123456', '13800000099', 'Buffett@163.com');
Query OK, 2 rows affected (0.00 sec)
表记录,id
和mobile_phone_number
变了,update_time
变为了字段默认值NULL
:
mysql> select * from user where username='Buffett';
+----+----------+----------+---------------------+-----------------+--------------+---------------------+-------------+
| id | username | password | mobile_phone_number | email | delete_state | create_time | update_time |
+----+----------+----------+---------------------+-----------------+--------------+---------------------+-------------+
| 12 | Buffett | 123456 | 13800000099 | Buffett@163.com | 0 | 2021-03-03 14:40:31 | NULL |
+----+----------+----------+---------------------+-----------------+--------------+---------------------+-------------+
1 row in set (0.00 sec)
replace into 的“坑”
replace into
执行的逻辑:
- 遇到
PRIMARY KEY
或UNIQUE
索引的,新记录与旧记录有冲突的(这里实际产生了异常duplicate key error
),replace into
会把旧记录删除,然后再插入新记录,insert into ... on deplicate key update
则只会更新。 - 若是新记录没有冲突,就直接插入一条新记录,与
insert into
一样。
示例一
INSERT INTO `user` (username, PASSWORD, mobile_phone_number, email ) VALUES('Buffett', '123456', '13800000088', 'Buffett@163.com' ) ON DUPLICATE KEY UPDATE mobile_phone_number = '13800000088';
示例一insert into ... on deplicate key update
操作在binlog
中记录为:
### UPDATE `zlz`.`user`
### WHERE
### @1=8 /* LONGINT meta=0 nullable=0 is_null=0 */
### @2='Buffett' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @3='123456' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @4='13800000077' /* VARSTRING(60) meta=60 nullable=1 is_null=0 */
### @5='Buffett@163.com' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @6=0 /* TINYINT meta=0 nullable=1 is_null=0 */
### @7='2021-03-03 11:25:22' /* DATETIME(0) meta=0 nullable=0 is_null=0 */
### @8=NULL /* DATETIME(0) meta=0 nullable=1 is_null=1 */
### SET
### @1=8 /* LONGINT meta=0 nullable=0 is_null=0 */
### @2='Buffett' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @3='123456' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @4='13800000088' /* VARSTRING(60) meta=60 nullable=1 is_null=0 */
### @5='Buffett@163.com' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @6=0 /* TINYINT meta=0 nullable=1 is_null=0 */
### @7='2021-03-03 11:16:40' /* DATETIME(0) meta=0 nullable=0 is_null=0 */
### @8='2021-03-03 11:19:30' /* DATETIME(0) meta=0 nullable=1 is_null=0 */
示例二
replace into `user` ( username, password, mobile_phone_number, email ) values('Buffett', '123456', '13800000099', 'Buffett@163.com' );
示例二replace into
操作在binlog中记录为:
### UPDATE `zlz`.`user`
### WHERE
### @1=8 /* LONGINT meta=0 nullable=0 is_null=0 */
### @2='Buffett' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @3='123456' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @4='13800000088' /* VARSTRING(60) meta=60 nullable=1 is_null=0 */
### @5='Buffett@163.com' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @6=0 /* TINYINT meta=0 nullable=1 is_null=0 */
### @7='2021-03-03 11:16:40' /* DATETIME(0) meta=0 nullable=0 is_null=0 */
### @8='2021-03-03 11:19:30' /* DATETIME(0) meta=0 nullable=1 is_null=0 */
### SET
### @1=12 /* LONGINT meta=0 nullable=0 is_null=0 */
### @2='Buffett' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @3='123456' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @4='13800000099' /* VARSTRING(60) meta=60 nullable=1 is_null=0 */
### @5='Buffett@163.com' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @6=0 /* TINYINT meta=0 nullable=1 is_null=0 */
### @7='2021-03-03 14:40:31' /* DATETIME(0) meta=0 nullable=0 is_null=0 */
### @8=NULL /* DATETIME(0) meta=0 nullable=1 is_null=1 */
从示例可以看出,使用replace into
会有以下问题:
- 把旧记录删除是删除的整行记录,之后,插入的新记录只是插入了那些指定的字段,原本不想更新的字段,此时直接为默认值了,会导致数据丢失;
- 自增主键
id
会更新。若旧记录的id跟其他表是有关联的,更新后新记录会产生新的id
,导致这种关联丢失; - 当执行
replace into
时,如果遇到unique key
冲突,mysql
执行的是delete+insert
两步操作,但是binlog
只会保存一条update
语句,造成主库中AUTO_INCREAMENT
进行+1操作。从库不执行该操作,造成mysql
主从的AUTO_INCREMEN
不一致,
当mysql
主从切换后,从库变为主库,其中新主库(原从库)AUTO_INCREMENT
较为落后,导致新插入的数据主键可能已经存在数据表中,新插入数据会出现异常,直到AUTO_INCREMENT
增加到原来主机器的值为止。
REPLACE is a MySQL extension to the SQL standard. It either inserts, or deletes and inserts. For another MySQL extension to standard SQL—that either inserts or updates—see Section 13.2.5.2, “INSERT ... ON DUPLICATE KEY UPDATE Statement”.
如何避“坑”
- 用
INSERT INTO … ON DUPLICATE KEY UPDATE
代替REPLACE INTO
。 很多使用REPLACE INTO
的场景,实际上需要的可能是INSERT INTO … ON DUPLICATE KEY UPDATE
,在正确理解REPLACE INTO
行为和副作用的前提下,谨慎使用REPLACE INTO
。 - 使用
REPLACE INTO
时指定表中所有列的值(包括主键)或MySQL8.0
版本。
示例
replace into `user`(id,username, password, mobile_phone_number, email,delete_state,create_time,update_time) values(8,'Buffett', '123456', '13800000077', 'Buffett@163.com',0, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP);
执行结果
mysql> replace into `user`(id,username, password, mobile_phone_number, email,delete_state,create_time,update_time) values(8,'Buffett', '123456', '13800000077', 'Buffett@163.com',0, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP);
Query OK, 2 rows affected (0.00 sec)
因为全部列都是指定的值,所以,相当于所有字段全部更新了一次。
mysql> select * from user where username='Buffett';
+----+----------+----------+---------------------+-----------------+--------------+---------------------+---------------------+
| id | username | password | mobile_phone_number | email | delete_state | create_time | update_time |
+----+----------+----------+---------------------+-----------------+--------------+---------------------+---------------------+
| 8 | Buffett | 123456 | 13800000077 | Buffett@163.com | 0 | 2021-03-03 15:24:49 | 2021-03-03 15:24:49 |
+----+----------+----------+---------------------+-----------------+--------------+---------------------+---------------------+
1 row in set (0.00 sec)
binlog
中的记录:
### UPDATE `zlz`.`user`
### WHERE
### @1=14 /* LONGINT meta=0 nullable=0 is_null=0 */
### @2='Buffett' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @3='123456' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @4='13800000099' /* VARSTRING(60) meta=60 nullable=1 is_null=0 */
### @5='Buffett@163.com' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @6=0 /* TINYINT meta=0 nullable=1 is_null=0 */
### @7='2021-03-03 15:17:13' /* DATETIME(0) meta=0 nullable=0 is_null=0 */
### @8=NULL /* DATETIME(0) meta=0 nullable=1 is_null=1 */
### SET
### @1=8 /* LONGINT meta=0 nullable=0 is_null=0 */
### @2='Buffett' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @3='123456' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @4='13800000077' /* VARSTRING(60) meta=60 nullable=1 is_null=0 */
### @5='Buffett@163.com' /* VARSTRING(192) meta=192 nullable=1 is_null=0 */
### @6=0 /* TINYINT meta=0 nullable=1 is_null=0 */
### @7='2021-03-03 15:24:49' /* DATETIME(0) meta=0 nullable=0 is_null=0 */
### @8='2021-03-03 15:24:49' /* DATETIME(0) meta=0 nullable=1 is_null=0 */
使用场景总结
如果出现重复异常,希望捕获异常,则使用insert into
;
如果出现重复异常,希望保存旧纪录,忽略新纪录,则使用insert ignore into
;
如果出现重复异常,希望更新指定字段,则使用insert into … on duplicate key update
;
如果出现重复异常,希望删除旧记录,插入新记录,则使用replace into
。