- Introduction
- Concepts
- Architecture
- Key Features
- Horizontal Scalability
- MySQL Compatible Syntax
- Replicate from and to MySQL
- Distributed Transactions with Strong Consistency
- Cloud Native Architecture
- Minimize ETL with HTAP
- Fault Tolerance & Recovery with Raft
- Automatic Rebalancing
- Deployment and Orchestration with Ansible, Kubernetes, Docker
- JSON Support
- Spark Integration
- Read Historical Data Without Restoring from Backup
- Fast Import and Restore of Data
- Hybrid of Column and Row Storage
- SQL Plan Management
- Open Source
- Online Schema Changes
- How-to
- Get Started
- Deploy
- Hardware Recommendations
- From Binary Tarball
- Orchestrated Deployment
- Geographic Redundancy
- Data Migration with Ansible
- Configure
- Secure
- Transport Layer Security (TLS)
- Generate Self-signed Certificates
- Monitor
- Migrate
- Maintain
- Common Ansible Operations
- Backup and Restore
- Identify Abnormal Queries
- Scale
- Upgrade
- Troubleshoot
- Reference
- SQL
- MySQL Compatibility
- SQL Language Structure
- Data Types
- Functions and Operators
- Function and Operator Reference
- Type Conversion in Expression Evaluation
- Operators
- Control Flow Functions
- String Functions
- Numeric Functions and Operators
- Date and Time Functions
- Bit Functions and Operators
- Cast Functions and Operators
- Encryption and Compression Functions
- Information Functions
- JSON Functions
- Aggregate (GROUP BY) Functions
- Window Functions
- Miscellaneous Functions
- Precision Math
- List of Expressions for Pushdown
- SQL Statements
ADD COLUMN
ADD INDEX
ADMIN
ADMIN CANCEL DDL
ADMIN CHECKSUM TABLE
ADMIN CHECK [TABLE|INDEX]
ADMIN SHOW DDL [JOBS|QUERIES]
ALTER DATABASE
ALTER TABLE
ALTER USER
ANALYZE TABLE
BEGIN
CHANGE COLUMN
COMMIT
CREATE DATABASE
CREATE INDEX
CREATE ROLE
CREATE TABLE LIKE
CREATE TABLE
CREATE USER
CREATE VIEW
DEALLOCATE
DELETE
DESC
DESCRIBE
DO
DROP COLUMN
DROP DATABASE
DROP INDEX
DROP ROLE
DROP TABLE
DROP USER
DROP VIEW
EXECUTE
EXPLAIN ANALYZE
EXPLAIN
FLUSH PRIVILEGES
FLUSH STATUS
FLUSH TABLES
GRANT <privileges>
GRANT <role>
INSERT
KILL [TIDB]
LOAD DATA
LOAD STATS
MODIFY COLUMN
PREPARE
RECOVER TABLE
RENAME INDEX
RENAME TABLE
REPLACE
REVOKE <privileges>
REVOKE <role>
ROLLBACK
SELECT
SET DEFAULT ROLE
SET [NAMES|CHARACTER SET]
SET PASSWORD
SET ROLE
SET TRANSACTION
SET [GLOBAL|SESSION] <variable>
SHOW ANALYZE STATUS
SHOW CHARACTER SET
SHOW COLLATION
SHOW [FULL] COLUMNS FROM
SHOW CREATE TABLE
SHOW CREATE USER
SHOW DATABASES
SHOW ENGINES
SHOW ERRORS
SHOW [FULL] FIELDS FROM
SHOW GRANTS
SHOW INDEXES [FROM|IN]
SHOW INDEX [FROM|IN]
SHOW KEYS [FROM|IN]
SHOW PRIVILEGES
SHOW [FULL] PROCESSSLIST
SHOW SCHEMAS
SHOW STATUS
SHOW [FULL] TABLES
SHOW TABLE REGIONS
SHOW TABLE STATUS
SHOW [GLOBAL|SESSION] VARIABLES
SHOW WARNINGS
SPLIT REGION
START TRANSACTION
TRACE
TRUNCATE
UPDATE
USE
- Constraints
- Generated Columns
- Partitioning
- Character Set
- SQL Mode
- Views
- Configuration
- Security
- Transactions
- System Databases
- Errors Codes
- Supported Client Drivers
- Garbage Collection (GC)
- Performance
- Overview
- Understanding the Query Execution Plan
- The Blocklist of Optimization Rules and Expression Pushdown
- Introduction to Statistics
- TopN and Limit Push Down
- Optimizer Hints
- Check the TiDB Cluster Status Using SQL Statements
- Execution Plan Binding
- Statement Summary Table
- Tune TiKV
- Operating System Tuning
- Column Pruning
- Key Monitoring Metrics
- Alert Rules
- Best Practices
- TiSpark
- TiKV
- TiDB Binlog
- Tools
- TiDB in Kubernetes
- FAQs
- Support
- Contribute
- Releases
- All Releases
- v3.0
- v2.1
- v2.0
- v1.0
- Glossary
You are viewing the documentation of an older version of the TiDB database (TiDB v3.0).
The System Variables
The system variables in MySQL are the system parameters that modify the operation of the database runtime. These variables have two types of scope, Global Scope and Session Scope. TiDB supports all the system variables in MySQL 5.7. Most of the variables are only supported for compatibility and do not affect the runtime behaviors.
Set the system variables
You can use the SET
statement to change the value of the system variables. Before you change, consider the scope of the variable. For more information, see MySQL Dynamic System Variables.
Set Global variables
Add the GLOBAL
keyword before the variable or use @@global.
as the modifier:
SET GLOBAL autocommit = 1;
SET @@global.autocommit = 1;
In a distributed TiDB database, a variable's GLOBAL
setting is persisted to the storage layer. A single TiDB instance proactively gets the GLOBAL
information and forms gvc
(global variables cache) every 2 seconds. The cache information remains valid within 2 seconds. When you set the GLOBAL
variable, to ensure the effectiveness of new sessions, make sure that the interval between two operations is larger than 2 seconds. For details, see Issue #14531.
Set Session variables
Add the SESSION
keyword before the variable, use @@session.
as the modifier, or use no modifier:
SET SESSION autocommit = 1;
SET @@session.autocommit = 1;
SET @@autocommit = 1;
LOCAL
and @@local.
are the synonyms for SESSION
and @@session.
The working mechanism of system variables
Session variables will only initialize their own values based on global variables when a session is created. Changing a global variable does not change the value of the system variable being used by the session that has already been created.
mysql> SELECT @@GLOBAL.autocommit; +---------------------+ | @@GLOBAL.autocommit | +---------------------+ | ON | +---------------------+ 1 row in set (0.00 sec) mysql> SELECT @@SESSION.autocommit; +----------------------+ | @@SESSION.autocommit | +----------------------+ | ON | +----------------------+ 1 row in set (0.00 sec) mysql> SET GLOBAL autocommit = OFF; Query OK, 0 rows affected (0.01 sec) mysql> SELECT @@SESSION.autocommit; -- Session variables do not change, and the transactions in the session are executed in the form of autocommit. +----------------------+ | @@SESSION.autocommit | +----------------------+ | ON | +----------------------+ 1 row in set (0.00 sec) mysql> SELECT @@GLOBAL.autocommit; +---------------------+ | @@GLOBAL.autocommit | +---------------------+ | OFF | +---------------------+ 1 row in set (0.00 sec) mysql> exit Bye $ mysql -h127.0.0.1 -P4000 -uroot -D test Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 3 Server version: 5.7.25-TiDB-None MySQL Community Server (Apache License 2.0) Copyright (c) 2000, 2019, Oracle and/or its affiliates. All rights reserved. Oracle is a registered trademark of Oracle Corporation and/or its affiliates. Other names may be trademarks of their respective owners. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. mysql> SELECT @@SESSION.autocommit; -- The newly created session uses a new global variable. +----------------------+ | @@SESSION.autocommit | +----------------------+ | OFF | +----------------------+ 1 row in set (0.00 sec)
The fully supported MySQL system variables in TiDB
The following MySQL system variables are fully supported in TiDB and have the same behaviors as in MySQL.
Name | Scope | Description |
---|---|---|
autocommit | GLOBAL | SESSION | whether automatically commit a transaction |
sql_mode | GLOBAL | SESSION | support some of the MySQL SQL modes |
time_zone | GLOBAL | SESSION | the time zone of the database |
tx_isolation | GLOBAL | SESSION | the isolation level of a transaction |
max_execution_time | GLOBAL | SESSION | the execution timeout for a statement, in milliseconds |
innodb_lock_wait_timeout | GLOBAL | SESSION | the lock wait time for pessimistic transactions, in seconds |
interactive_timeout | SESSION | GLOBAL | the idle timeout of the interactive user session, in seconds |
Unlike in MySQL, the max_execution_time
system variable currently works on all kinds of statements in TiDB, not only restricted to the SELECT
statement. The precision of the timeout value is roughly 100ms. This means the statement might not be terminated in accurate milliseconds as you specify.