Skip to content

Latest commit

 

History

History
140 lines (101 loc) · 5.4 KB

sql-statement-set-variable.md

File metadata and controls

140 lines (101 loc) · 5.4 KB
title summary aliases
SET [GLOBAL|SESSION] <variable>
TiDB 数据库中 SET [GLOBAL|SESSION] <variable> 的使用概况。
/docs-cn/dev/sql-statements/sql-statement-set-variable/
/docs-cn/dev/reference/sql/statements/set-variable/

SET [GLOBAL|SESSION] <variable>

SET [GLOBAL|SESSION] 语句用于在 SESSIONGLOBAL 的范围内,对某个 TiDB 的内置变量进行更改。

注意:

与 MySQL 类似,对 GLOBAL 变量的更改不适用于已有连接或本地连接,只有新会话才会反映值的变化。

语法图

SetStmt:

SetStmt

VariableAssignment:

VariableAssignment

示例

获取 sql_mode 的值:

{{< copyable "sql" >}}

SHOW GLOBAL 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.00 sec)

{{< copyable "sql" >}}

SHOW SESSION 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.00 sec)

更新全局的 sql_mode

{{< copyable "sql" >}}

SET GLOBAL sql_mode = 'STRICT_TRANS_TABLES,NO_AUTO_CREATE_USER';
Query OK, 0 rows affected (0.03 sec)

检查更新之后的 sql_mode 的取值,可以看到 SESSION 级别的值没有更新:

{{< copyable "sql" >}}

SHOW GLOBAL VARIABLES LIKE 'sql_mode';
+---------------+-----------------------------------------+
| Variable_name | Value                                   |
+---------------+-----------------------------------------+
| sql_mode      | STRICT_TRANS_TABLES,NO_AUTO_CREATE_USER |
+---------------+-----------------------------------------+
1 row in set (0.00 sec)

{{< copyable "sql" >}}

SHOW SESSION 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.00 sec)

SET SESSION 则可以立即生效:

{{< copyable "sql" >}}

SET SESSION sql_mode = 'STRICT_TRANS_TABLES,NO_AUTO_CREATE_USER';
Query OK, 0 rows affected (0.01 sec)

{{< copyable "sql" >}}

SHOW SESSION VARIABLES LIKE 'sql_mode';
+---------------+-----------------------------------------+
| Variable_name | Value                                   |
+---------------+-----------------------------------------+
| sql_mode      | STRICT_TRANS_TABLES,NO_AUTO_CREATE_USER |
+---------------+-----------------------------------------+
1 row in set (0.00 sec)

MySQL 兼容性

使用 SET [GLOBAL|SESSION] <variable> 更改系统变量上,TiDB 与 MySQL 存在以下差异

  • 与 MySQL 不同,TiDB 中使用 SET GLOBAL 所作的修改会应用于集群中的全部 TiDB 实例。而在 MySQL 中,修改不会应用于副本。
  • TiDB 中的若干变量可读又可设置,这是与 MySQL 相兼容的要求,因为应用程序和连接器常读取 MySQL 变量。例如:JDBC 连接器同时读取和设置缓存查询的参数,尽管并不依赖这一行为。
  • 即使在 TiDB 服务器重启后,SET GLOBAL 的更改也仍然有效。这样,TiDB 中的 SET GLOBAL 更类似于 MySQL 8.0 及更高版本中的 SET PERSIST

另请参阅