参考官方文档:
mysql可以为不同的客户端设置不同的sql_mode,并且每个应用能够设置他自己的会话级别的sql_mode。sql_mode会影响sql语法以及mysql显示数据的正确性。
When working with InnoDB tables, consider also the innodb_strict_mode system variable. It enables additional error checks for InnoDB tables.
官方文档建议:当使用innodb存储引擎表时,考虑使用innodb_strict_mode模式的sql_mode,它能增量额外的错误检测功能。
mysql5.7默认的sql mode值如下:
root@(none) 05:48:26>show variables like "sql_mode"; +---------------+-------------------------------------------------------------------------------------------------------------------------------------------+ | Variable_name | Value | +---------------+-------------------------------------------------------------------------------------------------------------------------------------------+ | sql_mode | ONLY_FULL_GROUP_BY,STRICT_TRANS_TABLES,NO_ZERO_IN_DATE,NO_ZERO_DATE,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION | +---------------+-------------------------------------------------------------------------------------------------------------------------------------------+ 1 row in set (0.02 sec) root@(none) 05:48:34>
在服务启动之前在配置文件中设置sql mode:
sql_mode="ONLY_FULL_GROUP_BY,STRICT_TRANS_TABLES,NO_ZERO_DATE,NO_ZERO_IN_DATE,ERROR_FOR_DIVISION_BY_ZERO,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION"
或者在启动mysql的时候使用--sql-mode="value"来指定sql mode的值。
可以在命令行设置全局的sql mode,也可以设置会话级别的。
set global sql_mode="modes"; #全局的设置影响连接的每一个客户端, set session sql_mode="modes"; #会话级别的设置只影响当前的客户端, (需要说明的是,在命令行的设置重启服务后会失效)
If a value could not be inserted as given into a transactional table, abort the statement. For a nontransactional table, abort the statement if the value occurs in a single-row statement or the first row of a multiple-row statement. #对于事务表,给的值不能插入则终止该语句。对于非事务表,若是单行语句或者多行语句的第一行则中断()
root@testdb 06:19:08>create table tb2(l1 date); Query OK, 0 rows affected (0.22 sec) root@testdb 06:23:23>set session sql_mode="ALLOW_INVALID_DATES"; Query OK, 0 rows affected, 1 warning (0.00 sec) root@testdb 06:23:41>insert into tb2 values("2012-02-30"); Query OK, 1 row affected (0.00 sec) root@testdb 06:23:45>select * from tb2; +------------+ | l1 | +------------+ | 2012-02-30 | +------------+ 1 row in set (0.00 sec) root@testdb 06:23:56>insert into tb2 values("2012-04-31"); Query OK, 1 row affected (0.09 sec) root@testdb 06:24:44>select * from tb2; +------------+ | l1 | +------------+ | 2012-02-30 | | 2012-04-31 | +------------+ 2 rows in set (0.00 sec) root@testdb 06:24:46>set session sql_mode="TRADITIONAL"; Query OK, 0 rows affected, 1 warning (0.00 sec) root@testdb 06:26:26>insert into tb2 values("2012-06-31"); ERROR 1292 (22007): Incorrect date value: '2012-06-31' for column 'l1' at row 1 root@testdb 06:26:38>测试结果
root@testdb 06:35:17>create table tb2(name varchar(20)); Query OK, 0 rows affected (0.04 sec) root@testdb 06:35:54>set session sql_mode="ANSI_QUOTES"; Query OK, 0 rows affected, 1 warning (0.00 sec) root@testdb 06:36:04>insert into tb2 values("puting"); #双引号不能使用 ERROR 1054 (42S22): Unknown column 'puting' in 'field list' root@testdb 06:36:24>insert into tb2 values('puting'); #使用单引号引用字符串 Query OK, 1 row affected (0.03 sec) root@testdb 06:36:35>insert into tb2 values('"'); #把双引号作为字符串插入 Query OK, 1 row affected (0.01 sec) root@testdb 06:36:59>select * from tb2; +--------+ | name | +--------+ | puting | | " | +--------+ 2 rows in set (0.00 sec) root@testdb 06:37:06>测试结果
NO_BACKSLASH_ESCAPES
:(禁用反斜线转义)这个模式启用,反斜线将会变成一个普通的字符串。NO_DIR_IN_CREATE
:在创建表时忽略所有的index directory和data directory选项。root@testdb 10:07:04>select cast(0 as unsigned) -1 ; ERROR 1690 (22003): BIGINT UNSIGNED value is out of range in '(cast(0 as unsigned) - 1)' root@testdb 10:15:14>
若启用了这个模式,结果将是负数。
root@testdb 10:15:14>set session sql_mode="NO_UNSIGNED_SUBTRACTION"; Query OK, 0 rows affected (0.00 sec) root@testdb 10:16:19>select cast(0 as unsigned) -1 ; +------------------------+ | cast(0 as unsigned) -1 | +------------------------+ | -1 | +------------------------+ 1 row in set (0.00 sec) root@testdb 10:16:21>
如果这个结果被用于更新一个unsigned整型的字段,结果将会被裁减为最大值或者裁减为0,如果NO_UNSIGNED_SUBTRACTION这个模式启用。在严格模式下将会发生错误。
启用NO_UNSIGNED_SUBTRACTION模式: root@testdb 10:06:26>set session sql_mode="NO_FIELD_OPTIONS"; Query OK, 0 rows affected (0.01 sec) root@testdb 10:16:21>create table tb3(c1 int unsigned); Query OK, 0 rows affected (0.04 sec) root@testdb 10:21:22>insert into tb3 select cast(0 as unsigned) -1; Query OK, 1 row affected, 1 warning (0.02 sec) Records: 1 Duplicates: 0 Warnings: 1 root@testdb 10:21:44>select * from tb3; +------+ | c1 | +------+ | 0 | +------+ 1 row in set (0.00 sec) root@testdb 10:21:54> #默认已经启用了严格模式,在新的连接中插入此值。 root@(none) 10:22:07>use testdb; Database changed root@testdb 10:22:12>insert into tb3 select cast(0 as unsigned) -1; ERROR 1690 (22003): BIGINT UNSIGNED value is out of range in '(cast(0 as unsigned) - 1)' root@testdb 10:22:19>测试结果
不存在于group_by中的字段需要使用,可以使用聚合函数。
有如下表中数据:
root@testdb 11:12:36>select * from emp; +------+----------+--------+--------+ | id | ename | sal | deptno | +------+----------+--------+--------+ | 1001 | emp_1001 | 100.00 | 10 | | 1002 | emp_1002 | 200.00 | 10 | | 1003 | emp_1003 | 300.00 | 20 | | 1004 | emp_1004 | 400.00 | 20 | | 1005 | emp_1005 | 500.00 | 30 | | 1006 | emp_1006 | 600.00 | 30 | +------+----------+--------+--------+ 6 rows in set (0.00 sec) #在mysql5.6中我们的如下查询是正确的 root@testdb 11:12:26>select id, ename, sal,deptno from emp group by deptno; +------+----------+--------+--------+ | id | ename | sal | deptno | +------+----------+--------+--------+ | 1001 | emp_1001 | 100.00 | 10 | | 1003 | emp_1003 | 300.00 | 20 | | 1005 | emp_1005 | 500.00 | 30 | +------+----------+--------+--------+ 3 rows in set (0.05 sec) 但是在mysql5.7中就会报错,因为在select的查询字段中出现来group by之外的字段旧报错了 root@testdb 11:11:09>select id, ename, sal,deptno from emp group by deptno; ERROR 1055 (42000): Expression #1 of SELECT list is not in GROUP BY clause and contains nonaggregated column 'testdb.emp.id' which is not functionally dependent on columns in GROUP BY clause; this is incompatible with sql_mode=only_full_group_by
PAD_CHAR_TO_FULL_LENGTH
:默认情况下,会自动修剪char列的空格。但是若这个模式启用,不会修剪空格,会自动补全。这个模式对varchar字段不起作用。
#创建表 root@testdb 11:36:51>create table tb4(c1 char(6), c2 varchar(6)); Query OK, 0 rows affected (0.09 sec) #插入数据 root@testdb 11:37:33>insert into tb4 values("aa","bb"); Query OK, 1 row affected (0.00 sec) root@testdb 11:38:07>select * from tb4; +------+------+ | c1 | c2 | +------+------+ | aa | bb | +------+------+ 1 row in set (0.00 sec) #查看长度 root@testdb 11:41:25>select char_length(c1), char_length(c2) from tb4; +-----------------+-----------------+ | char_length(c1) | char_length(c2) | +-----------------+-----------------+ | 2 | 2 | +-----------------+-----------------+ row in set (0.00 sec) #修改sql_mode的数值 root@testdb 11:38:13>set session sql_mode="PAD_CHAR_TO_FULL_LENGTH"; Query OK, 0 rows affected, 1 warning (0.00 sec) root@testdb 11:38:56>select * from tb4; #可以看到aa列的值的宽度 +--------+------+ | c1 | c2 | +--------+------+ | aa | bb | +--------+------+ 1 row in set (0.00 sec) #看到这里c1的长度为6 root@testdb 11:40:52>select char_length(c1), char_length(c2) from tb4; +-----------------+-----------------+ | char_length(c1) | char_length(c2) | +-----------------+-----------------+ | 6 | 2 | +-----------------+-----------------+ row in set (0.00 sec)
PIPES_AS_CONCAT
:将 “||”作为并运算符(像concat一样),而不是逻辑运算符or.REAL_AS_FLOAT
: 将real作为float的同义词。默认的,mysql将real作为double的同义词。STRICT_ALL_TABLES
:启动严格模式未所有的存储引擎,不合法的数据将会被拒绝。STRICT_ALL_TABLES
模式将包含: ERROR_FOR_DIVISION_BY_ZERO
, NO_ZERO_DATE
, and NO_ZERO_IN_DATE
模式。STRICT_TRANS_TABLES
:启动严格模式未事务存储引擎,STRICT_TRANS_TABLES
将包含 ERROR_FOR_DIVISION_BY_ZERO
, NO_ZERO_DATE
, and NO_ZERO_IN_DATE
模式的影响。以下组合模式未几种sql_mode组合的简写。
组合sql mode不再说明,可以查看官网:就是一个组合的简写相当于几个sql mode的配置。官网地址:https://dev.mysql.com/doc/refman/5.7/en/sql-mode.html#sql-mode-changes
有关严格模式的一些说明,官方文档给了比较详细的说明。