title | summary | aliases | ||
---|---|---|---|---|
Constraints |
Learn how SQL Constraints apply to TiDB. |
|
TiDB supports almost the same constraint as MySQL.
NOT NULL constraints supported by TiDB are the same as those supported by MySQL.
For example:
{{< copyable "sql" >}}
CREATE TABLE users (
id INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
age INT NOT NULL,
last_login TIMESTAMP
);
{{< copyable "sql" >}}
INSERT INTO users (id,age,last_login) VALUES (NULL,123,NOW());
Query OK, 1 row affected (0.02 sec)
{{< copyable "sql" >}}
INSERT INTO users (id,age,last_login) VALUES (NULL,NULL,NOW());
ERROR 1048 (23000): Column 'age' cannot be null
{{< copyable "sql" >}}
INSERT INTO users (id,age,last_login) VALUES (NULL,123,NULL);
Query OK, 1 row affected (0.03 sec)
- The first
INSERT
statement succeeds because it is possible to assignNULL
to theAUTO_INCREMENT
column. TiDB generates sequence numbers automatically. - The second
INSERT
statement fails because theage
column is defined asNOT NULL
. - The third
INSERT
statement succeeds because thelast_login
column is not explicitly defined asNOT NULL
. NULL values are allowed by default.
TiDB parses but ignores CHECK
constraints. This is MySQL 5.7 compatible behavior.
For example:
{{< copyable "sql" >}}
DROP TABLE IF EXISTS users;
CREATE TABLE users (
id INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
username VARCHAR(60) NOT NULL,
UNIQUE KEY (username),
CONSTRAINT min_username_length CHECK (CHARACTER_LENGTH(username) >=4)
);
INSERT INTO users (username) VALUES ('a');
SELECT * FROM users;
Depending on the transaction mode and the value of tidb_constraint_check_in_place
, TiDB might check UNIQUE
constraints lazily. This helps improve performance by batching network access.
For example:
{{< copyable "sql" >}}
DROP TABLE IF EXISTS users;
CREATE TABLE users (
id INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
username VARCHAR(60) NOT NULL,
UNIQUE KEY (username)
);
INSERT INTO users (username) VALUES ('dave'), ('sarah'), ('bill');
With the default of pessimistic locking:
{{< copyable "sql" >}}
BEGIN;
INSERT INTO users (username) VALUES ('jane'), ('chris'), ('bill');
ERROR 1062 (23000): Duplicate entry 'bill' for key 'username'
With optimistic locking and tidb_constraint_check_in_place=0
:
{{< copyable "sql" >}}
BEGIN OPTIMISTIC;
INSERT INTO users (username) VALUES ('jane'), ('chris'), ('bill');
Query OK, 0 rows affected (0.00 sec)
Query OK, 3 rows affected (0.00 sec)
Records: 3 Duplicates: 0 Warnings: 0
{{< copyable "sql" >}}
INSERT INTO users (username) VALUES ('steve'),('elizabeth');
Query OK, 2 rows affected (0.00 sec)
Records: 2 Duplicates: 0 Warnings: 0
{{< copyable "sql" >}}
COMMIT;
ERROR 1062 (23000): Duplicate entry 'bill' for key 'username'
In the optimistic example, the unique check was delayed until the transaction is committed. This resulted in a duplicate key error, because the value bill
was already present.
You can disable this behavior by setting tidb_constraint_check_in_place
to 1
. This variable setting does not take effect on pessimistic transactions, because in the pessimistic transaction mode the constraints are always checked when the statement is executed. When tidb_constraint_check_in_place=1
, the unique constraint is checked when the statement is executed.
For example:
DROP TABLE IF EXISTS users;
CREATE TABLE users (
id INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
username VARCHAR(60) NOT NULL,
UNIQUE KEY (username)
);
INSERT INTO users (username) VALUES ('dave'), ('sarah'), ('bill');
{{< copyable "sql" >}}
SET tidb_constraint_check_in_place = 1;
Query OK, 0 rows affected (0.00 sec)
{{< copyable "sql" >}}
BEGIN OPTIMISTIC;
Query OK, 0 rows affected (0.00 sec)
{{< copyable "sql" >}}
INSERT INTO users (username) VALUES ('jane'), ('chris'), ('bill');
ERROR 1062 (23000): Duplicate entry 'bill' for key 'username'
..
The first INSERT
statement caused a duplicate key error. This causes additional network communication overhead and may reduce the throughput of insert operations.
Like MySQL, primary key constraints contain unique constraints, that is, creating a primary key constraint is equivalent to having a unique constraint. In addition, other primary key constraints of TiDB are also similar to those of MySQL.
For example:
{{< copyable "sql" >}}
CREATE TABLE t1 (a INT NOT NULL PRIMARY KEY);
Query OK, 0 rows affected (0.12 sec)
{{< copyable "sql" >}}
CREATE TABLE t2 (a INT NULL PRIMARY KEY);
ERROR 1171 (42000): All parts of a PRIMARY KEY must be NOT NULL; if you need NULL in a key, use UNIQUE instead
{{< copyable "sql" >}}
CREATE TABLE t3 (a INT NOT NULL PRIMARY KEY, b INT NOT NULL PRIMARY KEY);
ERROR 1068 (42000): Multiple primary key defined
{{< copyable "sql" >}}
CREATE TABLE t4 (a INT NOT NULL, b INT NOT NULL, PRIMARY KEY (a,b));
Query OK, 0 rows affected (0.10 sec)
- Table
t2
failed to be created, because columna
is defined as the primary key and does not allow NULL values. - Table
t3
failed to be created, because a table can only have one primary key. - Table
t4
was created successfully, because even though there can be only one primary key, TiDB supports defining multiple columns as the composite primary key.
In addition to the rules above, TiDB currently only supports adding and deleting the primary keys of the NONCLUSTERED
type. For example:
{{< copyable "sql" >}}
CREATE TABLE t5 (a INT NOT NULL, b INT NOT NULL, PRIMARY KEY (a,b) CLUSTERED);
ALTER TABLE t5 DROP PRIMARY KEY;
ERROR 8200 (HY000): Unsupported drop primary key when the table is using clustered index
{{< copyable "sql" >}}
CREATE TABLE t5 (a INT NOT NULL, b INT NOT NULL, PRIMARY KEY (a,b) NONCLUSTERED);
ALTER TABLE t5 DROP PRIMARY KEY;
Query OK, 0 rows affected (0.10 sec)
For more details about the primary key of the CLUSTERED
type, refer to clustered index.
Note:
TiDB has limited support for foreign key constraints.
TiDB supports creating FOREIGN KEY
constraints in DDL commands.
For example:
CREATE TABLE users (
id INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
doc JSON
);
CREATE TABLE orders (
id INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
user_id INT NOT NULL,
doc JSON,
FOREIGN KEY fk_user_id (user_id) REFERENCES users(id)
);
{{< copyable "sql" >}}
SELECT table_name, column_name, constraint_name, referenced_table_name, referenced_column_name
FROM information_schema.key_column_usage WHERE table_name IN ('users', 'orders');
+------------+-------------+-----------------+-----------------------+------------------------+
| table_name | column_name | constraint_name | referenced_table_name | referenced_column_name |
+------------+-------------+-----------------+-----------------------+------------------------+
| users | id | PRIMARY | NULL | NULL |
| orders | id | PRIMARY | NULL | NULL |
| orders | user_id | fk_user_id | users | id |
+------------+-------------+-----------------+-----------------------+------------------------+
3 rows in set (0.00 sec)
TiDB also supports the syntax to DROP FOREIGN KEY
and ADD FOREIGN KEY
via the ALTER TABLE
command.
{{< copyable "sql" >}}
ALTER TABLE orders DROP FOREIGN KEY fk_user_id;
ALTER TABLE orders ADD FOREIGN KEY fk_user_id (user_id) REFERENCES users(id);
-
TiDB supports foreign keys to avoid errors caused by this syntax when you migrate data from other databases to TiDB.
However, TiDB does not perform constraint checking on foreign keys in DML statements. For example, even if there is no record with id=123 in the users table, the following transactions can be submitted successfully.
START TRANSACTION; INSERT INTO orders (user_id, doc) VALUES (123, NULL); COMMIT;