Constraints

TiDB supports almost the same constraints as MySQL.

NOT NULL

NOT NULL constraints supported by TiDB are the same as those supported by MySQL.

For example:

CREATE TABLE users ( id INT NOT NULL PRIMARY KEY AUTO_INCREMENT, age INT NOT NULL, last_login TIMESTAMP );
INSERT INTO users (id,age,last_login) VALUES (NULL,123,NOW());
Query OK, 1 row affected (0.02 sec)
INSERT INTO users (id,age,last_login) VALUES (NULL,NULL,NOW());
ERROR 1048 (23000): Column 'age' cannot be null
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 assign NULL to the AUTO_INCREMENT column. TiDB generates sequence numbers automatically.
  • The second INSERT statement fails because the age column is defined as NOT NULL.
  • The third INSERT statement succeeds because the last_login column is not explicitly defined as NOT NULL. NULL values ​​are allowed by default.

CHECK

TiDB parses but ignores CHECK constraints. This behavior is only syntax-compatible with MySQL 5.7 and is not supported.

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), CONSTRAINT min_username_length CHECK (CHARACTER_LENGTH(username) >=4) ); INSERT INTO users (username) VALUES ('a'); SELECT * FROM users;

UNIQUE KEY

Unique constraints mean that all non-null values in a unique index and a primary key column are unique.

Optimistic transactions

By default, for optimistic transactions, TiDB checks unique constraints lazily in the execution phase and strictly in the commit phase, which helps reduce network overhead and improve performance.

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');

With optimistic locking and tidb_constraint_check_in_place=OFF:

BEGIN OPTIMISTIC; INSERT INTO users (username) VALUES ('jane'), ('chris'), ('bill');
Query OK, 3 rows affected (0.00 sec) Records: 3 Duplicates: 0 Warnings: 0
INSERT INTO users (username) VALUES ('steve'),('elizabeth');
Query OK, 2 rows affected (0.00 sec) Records: 2 Duplicates: 0 Warnings: 0
COMMIT;
ERROR 1062 (23000): Duplicate entry 'bill' for key 'users.username'

In the preceding optimistic example, the unique check was deferred 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 ON. When tidb_constraint_check_in_place=ON, the unique constraint is checked when a statement is executed. Note that this variable is only applicable to optimistic transactions. For pessimistic transactions, you can control this behavior using the tidb_constraint_check_in_place_pessimistic variable.

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');
SET tidb_constraint_check_in_place = ON;
Query OK, 0 rows affected (0.00 sec)
BEGIN OPTIMISTIC;
Query OK, 0 rows affected (0.00 sec)
INSERT INTO users (username) VALUES ('jane'), ('chris'), ('bill');
ERROR 1062 (23000): Duplicate entry 'bill' for key 'users.username'

The first INSERT statement caused a duplicate key error. This causes additional network communication overhead and may reduce the throughput of insert operations.

Pessimistic transactions

In pessimistic transactions, by default, TiDB checks UNIQUE constraints when a SQL statement that requires inserting or updating unique indexes is executed.

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'); BEGIN PESSIMISTIC; INSERT INTO users (username) VALUES ('jane'), ('chris'), ('bill');
ERROR 1062 (23000): Duplicate entry 'bill' for key 'users.username'

To achieve better performance of pessimistic transactions, you can set the tidb_constraint_check_in_place_pessimistic variable to OFF, which allows TiDB to defer the unique constraint check of a unique index (to the next time when this index requires a lock or to the time when the transaction is committed) and skip the corresponding pessimistic lock. When using this variable, pay attention to the following:

  • Due to the deferred unique constraint check, TiDB might read results that do not meet the unique constraints and return a Duplicate entry error when you commit a pessimistic transaction. When this error occurs, TiDB rolls back the current transaction.

    The following example skips the lock to bill, so TiDB might get results that do not satisfy the uniqueness constraints.

    SET tidb_constraint_check_in_place_pessimistic = OFF; BEGIN PESSIMISTIC; INSERT INTO users (username) VALUES ('jane'), ('chris'), ('bill'); -- Query OK, 3 rows affected SELECT * FROM users FOR UPDATE;

    As in the following example output, the query results of TiDB contain two bills, which does not satisfy the uniqueness constraints.

    +----+----------+ | id | username | +----+----------+ | 1 | dave | | 2 | sarah | | 3 | bill | | 7 | jane | | 8 | chris | | 9 | bill | +----+----------+

    At this time, if the transaction is committed, TiDB will perform a unique constraint check, report a Duplicate entry error, and roll back the transaction.

    COMMIT;
    ERROR 1062 (23000): Duplicate entry 'bill' for key 'users.username'
  • When this variable is disabled, committing a pessimistic transaction that needs to write data might return a Write conflict error. When this error occurs, TiDB rolls back the current transaction.

    As in the following example, if two concurrent transactions need to insert data to the same table, skipping the pessimistic lock causes TiDB to return a Write conflict error when you commit a transaction. And the transaction will be rolled back.

    DROP TABLE IF EXISTS users; CREATE TABLE users ( id INT NOT NULL PRIMARY KEY AUTO_INCREMENT, username VARCHAR(60) NOT NULL, UNIQUE KEY (username) ); SET tidb_constraint_check_in_place_pessimistic = OFF; BEGIN PESSIMISTIC; INSERT INTO users (username) VALUES ('jane'), ('chris'), ('bill'); -- Query OK, 3 rows affected

    At the same time, another session inserts bill to the same table.

    INSERT INTO users (username) VALUES ('bill'); -- Query OK, 1 row affected

    Then, when you commit the transaction in the first session, TiDB reports a Write conflict error.

    COMMIT;
    ERROR 9007 (HY000): Write conflict, txnStartTS=435688780611190794, conflictStartTS=435688783311536129, conflictCommitTS=435688783311536130, key={tableID=74, indexID=1, indexValues={bill, }} primary={tableID=74, indexID=1, indexValues={bill, }}, reason=LazyUniquenessCheck [try again later]
  • When this variable is disabled, if there is a write conflict among multiple pessimistic transactions, the pessimistic lock might be forced to roll back when other pessimistic transactions are committed, thus resulting in a Pessimistic lock not found error. When this error occurs, it means that deferring the unique constraint check of the pessimistic transaction is not suitable for your application scenario. In this case, consider adjusting the application logic to avoid the conflict or retrying the transaction after an error occurs.

  • When this variable is disabled, executing a DML statement in a pessimistic transaction might return an error 8147: LazyUniquenessCheckFailure.

    As in the following example, at the execution of the INSERT statement, TiDB skips a lock. Then, at the execution of the DELETE statement, TiDB locks the unique index and checks the unique constraints, so you will see an error is reported at the DELETE statement.

    SET tidb_constraint_check_in_place_pessimistic = OFF; BEGIN PESSIMISTIC; INSERT INTO users (username) VALUES ('jane'), ('chris'), ('bill'); -- Query OK, 3 rows affected DELETE FROM users where username = 'bill';
    ERROR 8147 (23000): transaction aborted because lazy uniqueness check is enabled and an error occurred: [kv:1062]Duplicate entry 'bill' for key 'users.username'
  • When this variable is disabled, the 1062 Duplicate entry error might be not from the current SQL statement. Therefore, when a transaction operates on multiple tables that have indexes with the same name, you need to check the 1062 error message to find which index the error is actually from.

PRIMARY KEY

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:

CREATE TABLE t1 (a INT NOT NULL PRIMARY KEY);
Query OK, 0 rows affected (0.12 sec)
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
CREATE TABLE t3 (a INT NOT NULL PRIMARY KEY, b INT NOT NULL PRIMARY KEY);
ERROR 1068 (42000): Multiple primary key defined
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 column a 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:

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
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.

FOREIGN KEY

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) );
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.

ALTER TABLE orders DROP FOREIGN KEY fk_user_id; ALTER TABLE orders ADD FOREIGN KEY fk_user_id (user_id) REFERENCES users(id);

Was this page helpful?