- 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).
Read Historical Data
This document describes how TiDB reads data from the history versions, how TiDB manages the data versions, as well as an example to show how to use the feature.
Feature description
TiDB implements a feature to read history data using the standard SQL interface directly without special clients or drivers. By using this feature:
- Even when data is updated or removed, its history versions can be read using the SQL interface.
- Even if the table structure changes after the data is updated, TiDB can use the old structure to read the history data.
How TiDB reads data from history versions
The tidb_snapshot
system variable is introduced to support reading history data. About the tidb_snapshot
variable:
- The variable is valid in the
Session
scope. - Its value can be modified using the
Set
statement. - The data type for the variable is text.
- The variable accepts TSO (Timestamp Oracle) and datetime. TSO is a globally unique time service, which is obtained from PD. The acceptable datetime format is "2016-10-08 16:45:26.999". Generally, the datetime can be set using second precision, for example "2016-10-08 16:45:26".
- When the variable is set, TiDB creates a Snapshot using its value as the timestamp, just for the data structure and there is no any overhead. After that, all the
Select
operations will read data from this Snapshot.
Because the timestamp in TiDB transactions is allocated by Placement Driver (PD), the version of the stored data is also marked based on the timestamp allocated by PD. When a Snapshot is created, the version number is based on the value of the tidb_snapshot
variable. If there is a large difference between the local time of the TiDB server and the PD server, use the time of the PD server.
After reading data from history versions, you can read data from the latest version by ending the current Session or using the Set
statement to set the value of the tidb_snapshot
variable to "" (empty string).
How TiDB manages the data versions
TiDB implements Multi-Version Concurrency Control (MVCC) to manage data versions. The history versions of data are kept because each update/removal creates a new version of the data object instead of updating/removing the data object in-place. But not all the versions are kept. If the versions are older than a specific time, they will be removed completely to reduce the storage occupancy and the performance overhead caused by too many history versions.
In TiDB, Garbage Collection (GC) runs periodically to remove the obsolete data versions. For GC details, see TiDB Garbage Collection (GC)
Pay special attention to the following two variables:
tikv_gc_life_time
: It is used to configure the retention time of the history version. You can modify it manually.tikv_gc_safe_point
: It records the currentsafePoint
. You can safely create the snapshot to read the history data using the timestamp that is later thansafePoint
.safePoint
automatically updates every time GC runs.
Example
At the initial stage, create a table and insert several rows of data:
create table t (c int);
Query OK, 0 rows affected (0.01 sec)
insert into t values (1), (2), (3);
Query OK, 3 rows affected (0.00 sec)
View the data in the table:
select * from t;
+------+ | c | +------+ | 1 | | 2 | | 3 | +------+ 3 rows in set (0.00 sec)
View the timestamp of the table:
select now();
+---------------------+ | now() | +---------------------+ | 2016-10-08 16:45:26 | +---------------------+ 1 row in set (0.00 sec)
Update the data in one row:
update t set c=22 where c=2;
Query OK, 1 row affected (0.00 sec)
Make sure the data is updated:
select * from t;
+------+ | c | +------+ | 1 | | 22 | | 3 | +------+ 3 rows in set (0.00 sec)
Set the
tidb_snapshot
variable whose scope is Session. The variable is set so that the latest version before the value can be read.NoteIn this example, the value is set to be the time before the update operation.
set @@tidb_snapshot="2016-10-08 16:45:26";
Query OK, 0 rows affected (0.00 sec)
NoteYou should use
@@
instead of@
beforetidb_snapshot
because@@
is used to denote the system variable while@
is used to denote the user variable.Result: The read from the following statement is the data before the update operation, which is the history data.
select * from t;
+------+ | c | +------+ | 1 | | 2 | | 3 | +------+ 3 rows in set (0.00 sec)
Set the
tidb_snapshot
variable to be "" (empty string) and you can read the data from the latest version:set @@tidb_snapshot="";
Query OK, 0 rows affected (0.00 sec)
select * from t;
+------+ | c | +------+ | 1 | | 22 | | 3 | +------+ 3 rows in set (0.00 sec)
NoteYou should use
@@
instead of@
beforetidb_snapshot
because@@
is used to denote the system variable while@
is used to denote the user variable.