sql_mode是个容易被忽视的变量,在5.5默认值是空值,在这种设置下是可以允许一些非法操作的,比如允许一些非法数据的插入。在5.6中强化了该值设置,5.7中更注重了安全规范性,这个值默认为严格模式
create table test(name varchar(10),value int);
insert into test values ('a',1),('a',20),('b',23),('c',15),('c',30);
#默认情况是可能会写出无意义或错误的聚合语句:
SET sql_mode='';
select * from test group by name;
select value,sum(value) from test group by name;
# 使用该模式后,写法必须标准
SET sql_mode='ONLY_FULL_GROUP_BY';
select name,sum(value) from test group by name;
-- 错误写法则报错
select value,sum(value) from test group by name;
# 报错终止
ERROR 1055 (42000): Expression #1 of SELECT list is not in GROUP BY clause and contains nonaggregated column 'test.test.value' which is not functionally dependent on columns in GROUP BY clause; this is incompatible with sql_mode=only_full_group_by
create table test(value int(1));
SET sql_mode=''; #默认只要第一个值
insert into test(value) values('a'),(1); #不报错
insert into test(value) values(2),('a'); #不报错
select * from test;
+------------+
| value |
+------------+
| 0 |
| 1 |
| 2 |
| 0 |
+------------+
#后面删除表不再说明!
drop table test;
create table test(value int(1));
SET sql_mode='STRICT_TRANS_TABLES'; #每个值都判断
insert into test(value) values('a'),(1);
#报错,第一行'a'错误。
ERROR 1366 (HY000): Incorrect integer value: 'a' for column 'value' at row 1
create table test(value date);
SET sql_mode='';
insert into test(value) values('2020-00-00'); #结果为 '2020-00-00'
SET sql_mode='NO_ZERO_IN_DATE';
insert into test(value) values('2021-00-00'); #不符合,转为 '0000-00-00'
create table test(value date);
SET sql_mode='';
insert into test(value) values('0000-00-00'); #无警告 warning
SET sql_mode='STRICT_TRANS_TABLES';
insert into test(value) values('0000-00-00'); #无警告 warning
SET sql_mode='NO_ZERO_DATE';
insert into test(value) values('0000-00-00'); #有警告 warning
SET sql_mode='NO_ZERO_DATE,STRICT_TRANS_TABLES'
insert into test(value) values('0000-00-00');
# 报错终止
ERROR 1292 (22007): Incorrect date value: '0000-00-00' for column 'value' at row 1
create table test(value int);
SET sql_mode='';
select 10/0; #无警告 warning
insert into test(value) values(10/0); #无警告 warning
SET sql_mode='STRICT_TRANS_TABLES';
select 10/0; #无警告 warning
insert into test(value) values(10/0); #无警告 warning
SET sql_mode='ERROR_FOR_DIVISION_BY_ZERO';
select 10/0; #有警告 warning
insert into test(value) values(10/0); #有警告 warning
SET sql_mode='ERROR_FOR_DIVISION_BY_ZERO,STRICT_TRANS_TABLES';
select 10/0; #有警告 warning
insert into test(value) values(10/0);
#报错:ERROR 1365 (22012): Division by 0
SET sql_mode='';
grant all on test.* to test01@'localhost'; #不报错(无需要设置密码)
SET sql_mode='NO_AUTO_CREATE_USER';
# 报错
ERROR 1133 (42000): Can't find any matching row in the user table
#正确 写法,需要设置密码
grant all on test.* to test01@'localhost' identified by 'test01...';
# 查看当前支持的存储引擎
show engines;
set sql_mode='';
create table test(id int) ENGINE="test";
Query OK, 0 rows affected, 2 warnings (0.03 sec)
select table_name,engine from information_schema.tables where table_schema='test' and table_name='test'; # 转为默认存储引擎
+------------+--------+
| table_name | engine |
+------------+--------+
| test | InnoDB |
+------------+--------+
SET sql_mode='NO_ENGINE_SUBSTITUTION';
create table test(id int) ENGINE=test;
# 报错
ERROR 1286 (42000): Unknown storage engine 'test'
> show variables like '%sql_mode%';
> set @@sql_mode="NO_ENGINE_SUBSTITUTION"
> set session sql_mode='STRICT_TRANS_TABLES';
# vim /etc/my.cnf
[mysqld]
......
sql_mode="NO_ENGINE_SUBSTITUTION"
......
SQL_MODE在非严格模式下,会出现很多意料不到的结果。建议线上开启严格模式。但对于线上老的环境,如果一开始就运行在非严格模式下,切忌直接调整,毕竟两者的差异性还是相当巨大。
官方默认的SQL_MODE一直在发生变化,MySQL 5.5, 5.6, 5.7就不尽相同,但总体是趋严的,在对数据库进行升级时,其必须考虑默认的SQL_MODE是否需要调整。
在进行数据库迁移时,可通过调整SQL_MODE来兼容其它数据库的语法。