- Docs Home
- About TiDB Cloud
- Get Started
- Develop Applications
- Overview
- Quick Start
- Build a TiDB Developer Cluster
- CRUD SQL in TiDB
- Build a Simple CRUD App with TiDB
- Example Applications
- Connect to TiDB
- Design Database Schema
- Write Data
- Read Data
- Transaction
- Optimize
- Troubleshoot
- Reference
- Cloud Native Development Environment
- Manage Cluster
- Plan Your Cluster
- Create a TiDB Cluster
- Connect to Your TiDB Cluster
- Set Up VPC Peering Connections
- Use an HTAP Cluster with TiFlash
- Scale a TiDB Cluster
- Upgrade a TiDB Cluster
- Delete a TiDB Cluster
- Use TiDB Cloud API (Beta)
- Migrate Data
- Import Sample Data
- Migrate Data into TiDB
- Configure Amazon S3 Access and GCS Access
- Migrate from MySQL-Compatible Databases
- Migrate Incremental Data from MySQL-Compatible Databases
- Migrate from Amazon Aurora MySQL in Bulk
- Import or Migrate from Amazon S3 or GCS to TiDB Cloud
- Import CSV Files from Amazon S3 or GCS into TiDB Cloud
- Import Apache Parquet Files from Amazon S3 or GCS into TiDB Cloud
- Troubleshoot Access Denied Errors during Data Import from Amazon S3
- Export Data from TiDB
- Back Up and Restore
- Monitor and Alert
- Overview
- Built-in Monitoring
- Built-in Alerting
- Third-Party Monitoring Integrations
- Tune Performance
- Overview
- Analyze Performance
- SQL Tuning
- Overview
- Understanding the Query Execution Plan
- SQL Optimization Process
- Overview
- Logic Optimization
- Physical Optimization
- Prepare Execution Plan Cache
- Control Execution Plans
- TiKV Follower Read
- Coprocessor Cache
- Garbage Collection (GC)
- Tune TiFlash performance
- Manage User Access
- Billing
- Reference
- TiDB Cluster Architecture
- TiDB Cloud Cluster Limits and Quotas
- TiDB Limitations
- SQL
- Explore SQL with TiDB
- SQL Language Structure and Syntax
- 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 INDEX
ALTER TABLE
ALTER TABLE COMPACT
ALTER USER
ANALYZE TABLE
BATCH
BEGIN
CHANGE COLUMN
COMMIT
CHANGE DRAINER
CHANGE PUMP
CREATE [GLOBAL|SESSION] BINDING
CREATE DATABASE
CREATE INDEX
CREATE ROLE
CREATE SEQUENCE
CREATE TABLE LIKE
CREATE TABLE
CREATE USER
CREATE VIEW
DEALLOCATE
DELETE
DESC
DESCRIBE
DO
DROP [GLOBAL|SESSION] BINDING
DROP COLUMN
DROP DATABASE
DROP INDEX
DROP ROLE
DROP SEQUENCE
DROP STATS
DROP TABLE
DROP USER
DROP VIEW
EXECUTE
EXPLAIN ANALYZE
EXPLAIN
FLASHBACK TABLE
FLUSH PRIVILEGES
FLUSH STATUS
FLUSH TABLES
GRANT <privileges>
GRANT <role>
INSERT
KILL [TIDB]
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 [GLOBAL|SESSION] BINDINGS
SHOW BUILTINS
SHOW CHARACTER SET
SHOW COLLATION
SHOW [FULL] COLUMNS FROM
SHOW CREATE SEQUENCE
SHOW CREATE TABLE
SHOW CREATE USER
SHOW DATABASES
SHOW DRAINER STATUS
SHOW ENGINES
SHOW ERRORS
SHOW [FULL] FIELDS FROM
SHOW GRANTS
SHOW INDEX [FROM|IN]
SHOW INDEXES [FROM|IN]
SHOW KEYS [FROM|IN]
SHOW MASTER STATUS
SHOW PLUGINS
SHOW PRIVILEGES
SHOW [FULL] PROCESSSLIST
SHOW PROFILES
SHOW PUMP STATUS
SHOW SCHEMAS
SHOW STATS_HEALTHY
SHOW STATS_HISTOGRAMS
SHOW STATS_META
SHOW STATUS
SHOW TABLE NEXT_ROW_ID
SHOW TABLE REGIONS
SHOW TABLE STATUS
SHOW [FULL] TABLES
SHOW [GLOBAL|SESSION] VARIABLES
SHOW WARNINGS
SHUTDOWN
SPLIT REGION
START TRANSACTION
TABLE
TRACE
TRUNCATE
UPDATE
USE
WITH
- Data Types
- Functions and Operators
- Overview
- 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
- Locking Functions
- Information Functions
- JSON Functions
- Aggregate (GROUP BY) Functions
- Window Functions
- Miscellaneous Functions
- Precision Math
- Set Operations
- List of Expressions for Pushdown
- TiDB Specific Functions
- Clustered Indexes
- Constraints
- Generated Columns
- SQL Mode
- Table Attributes
- Transactions
- Views
- Partitioning
- Temporary Tables
- Cached Tables
- Character Set and Collation
- Read Historical Data
- System Tables
mysql
- INFORMATION_SCHEMA
- Overview
ANALYZE_STATUS
CLIENT_ERRORS_SUMMARY_BY_HOST
CLIENT_ERRORS_SUMMARY_BY_USER
CLIENT_ERRORS_SUMMARY_GLOBAL
CHARACTER_SETS
CLUSTER_INFO
COLLATIONS
COLLATION_CHARACTER_SET_APPLICABILITY
COLUMNS
DATA_LOCK_WAITS
DDL_JOBS
DEADLOCKS
ENGINES
KEY_COLUMN_USAGE
PARTITIONS
PROCESSLIST
REFERENTIAL_CONSTRAINTS
SCHEMATA
SEQUENCES
SESSION_VARIABLES
SLOW_QUERY
STATISTICS
TABLES
TABLE_CONSTRAINTS
TABLE_STORAGE_STATS
TIDB_HOT_REGIONS_HISTORY
TIDB_INDEXES
TIDB_SERVERS_INFO
TIDB_TRX
TIFLASH_REPLICA
TIKV_REGION_PEERS
TIKV_REGION_STATUS
TIKV_STORE_STATUS
USER_PRIVILEGES
VIEWS
- System Variables
- API Reference
- Storage Engines
- Dumpling
- Table Filter
- Troubleshoot Inconsistency Between Data and Indexes
- FAQs
- Release Notes
- Support
- Glossary
CREATE SEQUENCE
The CREATE SEQUENCE
statement creates sequence objects in TiDB. The sequence is a database object that is on a par with the table and the View
object. The sequence is used to generate serialized IDs in a customized way.
Synopsis
- CreateSequenceStmt
- IfNotExists
- TableName
- CreateSequenceOptionListOpt
- SequenceOptionList
- SequenceOption
CreateSequenceStmt ::=
'CREATE' 'SEQUENCE' IfNotExists TableName CreateSequenceOptionListOpt CreateTableOptionListOpt
IfNotExists ::=
('IF' 'NOT' 'EXISTS')?
TableName ::=
Identifier ('.' Identifier)?
CreateSequenceOptionListOpt ::=
SequenceOption*
SequenceOptionList ::=
SequenceOption
SequenceOption ::=
( 'INCREMENT' ( '='? | 'BY' ) | 'START' ( '='? | 'WITH' ) | ( 'MINVALUE' | 'MAXVALUE' | 'CACHE' ) '='? ) SignedNum
| 'NOMINVALUE'
| 'NO' ( 'MINVALUE' | 'MAXVALUE' | 'CACHE' | 'CYCLE' )
| 'NOMAXVALUE'
| 'NOCACHE'
| 'CYCLE'
| 'NOCYCLE'
Syntax
CREATE [TEMPORARY] SEQUENCE [IF NOT EXISTS] sequence_name
[ INCREMENT [ BY | = ] increment ]
[ MINVALUE [=] minvalue | NO MINVALUE | NOMINVALUE ]
[ MAXVALUE [=] maxvalue | NO MAXVALUE | NOMAXVALUE ]
[ START [ WITH | = ] start ]
[ CACHE [=] cache | NOCACHE | NO CACHE]
[ CYCLE | NOCYCLE | NO CYCLE]
[table_options]
Parameters
Parameters | Default value | Description |
---|---|---|
TEMPORARY | false | TiDB currently does not support the TEMPORARY option and provides only syntax compatibility for it. |
INCREMENT | 1 | Specifies the increment of a sequence. Its positive or negative values can control the growth direction of the sequence. |
MINVALUE | 1 or -9223372036854775807 | Specifies the minimum value of a sequence. When INCREMENT > 0 , the default value is 1 . When INCREMENT < 0 , the default value is -9223372036854775807 . |
MAXVALUE | 9223372036854775806 or -1 | Specifies the maximum value of a sequence. When INCREMENT > 0 , the default value is 9223372036854775806 . When INCREMENT < 0 , the default value is -1 . |
START | MINVALUE or MAXVALUE | Specifies the initial value of a sequence. When INCREMENT > 0 , the default value is MINVALUE . When INCREMENT < 0 , the default value is MAXVALUE . |
CACHE | 1000 | Specifies the local cache size of a sequence in TiDB. |
CYCLE | NO CYCLE | Specifies whether a sequence restarts from the minimum value (or maximum for the descending sequence). When INCREMENT > 0 , the default value is MINVALUE . When INCREMENT < 0 , the default value is MAXVALUE . |
SEQUENCE
function
You can control a sequence through the following expression functions:
NEXTVAL
orNEXT VALUE FOR
Essentially, both are the
nextval()
function that gets the next valid value of a sequence object. The parameter of thenextval()
function is theidentifier
of the sequence.LASTVAL
This function gets the last used value of this session. If the value does not exist,
NULL
is used. The parameter of this function is theidentifier
of the sequence.SETVAL
This function sets the progression of the current value for a sequence. The first parameter of this function is the
identifier
of the sequence; the second parameter isnum
.
In the implementation of a sequence in TiDB, the SETVAL
function cannot change the initial progression or cycle progression of this sequence. This function only returns the next valid value based on this progression.
Examples
Create a sequence object with the default parameter:
CREATE SEQUENCE seq;
Query OK, 0 rows affected (0.06 sec)
Use the
nextval()
function to get the next value of the sequence object:SELECT nextval(seq);
+--------------+ | nextval(seq) | +--------------+ | 1 | +--------------+ 1 row in set (0.02 sec)
Use the
lastval()
function to get the value generated by the last call to a sequence object in this session:SELECT lastval(seq);
+--------------+ | lastval(seq) | +--------------+ | 1 | +--------------+ 1 row in set (0.02 sec)
Use the
setval()
function to set the current value (or the current position) of the sequence object:SELECT setval(seq, 10);
+-----------------+ | setval(seq, 10) | +-----------------+ | 10 | +-----------------+ 1 row in set (0.01 sec)
You can also use the
next value for
syntax to get the next value of the sequence:SELECT next value for seq;
+--------------------+ | next value for seq | +--------------------+ | 11 | +--------------------+ 1 row in set (0.00 sec)
Create a sequence object with default custom parameters:
CREATE SEQUENCE seq2 start 3 increment 2 minvalue 1 maxvalue 10 cache 3;
Query OK, 0 rows affected (0.01 sec)
When the sequence object has not been used in this session, the
lastval()
function returns aNULL
value.SELECT lastval(seq2);
+---------------+ | lastval(seq2) | +---------------+ | NULL | +---------------+ 1 row in set (0.01 sec)
The first valid value of the
nextval()
function for the sequence object is the value ofSTART
parameter.SELECT nextval(seq2);
+---------------+ | nextval(seq2) | +---------------+ | 3 | +---------------+ 1 row in set (0.00 sec)
Although the
setval()
function can change the current value of the sequence object, it cannot change the arithmetic progression rule for the next value.SELECT setval(seq2, 6);
+-----------------+ | setval(seq2, 6) | +-----------------+ | 6 | +-----------------+ 1 row in set (0.00 sec)
When you use
nextval()
to get the next value, the next value will follow the arithmetic progression rule defined by the sequence.SELECT next value for seq2;
+---------------------+ | next value for seq2 | +---------------------+ | 7 | +---------------------+ 1 row in set (0.00 sec)
You can use the next value of the sequence as the default value for the column, as in the following example.
CREATE table t(a int default next value for seq2);
Query OK, 0 rows affected (0.02 sec)
In the following example, the value is not specified, so the default value of
seq2
is used.INSERT into t values();
Query OK, 1 row affected (0.00 sec)
SELECT * from t;
+------+ | a | +------+ | 9 | +------+ 1 row in set (0.00 sec)
In the following example, the value is not specified, so the default value of
seq2
is used. But the next value ofseq2
is not within the range defined in the above example (CREATE SEQUENCE seq2 start 3 increment 2 minvalue 1 maxvalue 10 cache 3;
), so an error is returned.INSERT into t values();
ERROR 4135 (HY000): Sequence 'test.seq2' has run out
MySQL compatibility
This statement is a TiDB extension. The implementation is modeled on sequences available in MariaDB.
Except for the SETVAL
function, all other functions have the same progressions as MariaDB. Here "progression" means that the numbers in a sequence follow a certain arithmetic progression rule defined by the sequence. Although you can use SETVAL
to set the current value of a sequence, the subsequent values of the sequence still follow the original progression rule.
For example:
1, 3, 5, ... // The sequence starts from 1 and increments by 2.
select setval(seq, 6) // Sets the current value of a sequence to 6.
7, 9, 11, ... // Subsequent values still follow the progression rule.
In the CYCLE
mode, the initial value of a sequence in the first round is the value of the START
parameter, and the initial value in the subsequent rounds is the value of MinValue
(INCREMENT
> 0) or MaxValue
(INCREMENT
< 0).