Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
43 commits
Select commit Hold shift + click to select a range
452c572
Merge pull request #1 from pingcap/master
KASSADAR Jun 24, 2020
e91cb07
Create View.md
KASSADAR Jun 24, 2020
c890d6e
Update View.md
KASSADAR Jun 24, 2020
240e154
Update View.md
KASSADAR Jun 24, 2020
8cfe36c
Update View.md
KASSADAR Jun 24, 2020
94fa431
Update View.md
KASSADAR Jun 24, 2020
196d8da
Create view
KASSADAR Jul 8, 2020
8574ad1
Update view
KASSADAR Jul 8, 2020
11caa50
Create Constraint
KASSADAR Jul 8, 2020
5d9253e
Rename Constraint to constraint.md
KASSADAR Jul 8, 2020
02a2e1e
Delete View.md
KASSADAR Jul 8, 2020
a4117d7
Rename view to view.md
KASSADAR Jul 8, 2020
33c62a5
Update view.md
KASSADAR Jul 8, 2020
7352458
Update views.md
KASSADAR Jul 8, 2020
2ccd094
Update views.md
KASSADAR Jul 8, 2020
853b80a
Update constraint.md
KASSADAR Jul 8, 2020
44c61f1
Update constraints.md
KASSADAR Jul 8, 2020
6d9fe48
Delete constraint.md
KASSADAR Jul 8, 2020
0fa24b1
Merge branch 'master' into master
yikeke Jul 8, 2020
014fd21
Update constraints.md
KASSADAR Jul 8, 2020
d6988a8
Update constraints.md
KASSADAR Jul 8, 2020
5e455a0
Update constraints.md
KASSADAR Jul 8, 2020
ebe95f7
Update constraints.md
KASSADAR Jul 8, 2020
14570b5
Update constraints.md
KASSADAR Jul 8, 2020
5615c20
Update constraints.md
KASSADAR Jul 8, 2020
dad8547
Update constraints.md
KASSADAR Jul 8, 2020
30cd301
Update constraints.md
KASSADAR Jul 8, 2020
e48a54e
Update constraints.md
KASSADAR Jul 8, 2020
d4d76d9
Update constraints.md
KASSADAR Jul 8, 2020
2443e1e
Update constraints.md
KASSADAR Jul 8, 2020
a21a6e2
Update constraints.md
KASSADAR Jul 8, 2020
5a32598
Update constraints.md
KASSADAR Jul 8, 2020
5da6b65
Update constraints.md
KASSADAR Jul 8, 2020
1ae15c3
Update constraints.md
KASSADAR Jul 8, 2020
823db87
Delete view.md
KASSADAR Jul 8, 2020
9ca6ff2
Update views.md
KASSADAR Jul 8, 2020
456ee19
update format and wording
ran-huang Jul 9, 2020
f7fdabd
fix a dead anchor
ran-huang Jul 9, 2020
4eca55a
Apply suggestions from code review
ran-huang Jul 9, 2020
449211c
Merge branch 'master' into master
ran-huang Jul 16, 2020
1c2fbe7
Apply suggestions from code review
ran-huang Jul 16, 2020
3e7a0cb
Merge branch 'master' into master
ran-huang Jul 17, 2020
7533b72
Merge branch 'master' into master
ran-huang Jul 17, 2020
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
305 changes: 200 additions & 105 deletions constraints.md
Original file line number Diff line number Diff line change
Expand Up @@ -6,138 +6,123 @@ aliases: ['/docs/dev/constraints/','/docs/dev/reference/sql/constraints/']

# Constraints

## Overview
TiDB supports almost the same constraint as MySQL.

TiDB supports the same basic constraints supported in MySQL with the following exceptions:
## NOT NULL

- `PRIMARY KEY` and `UNIQUE` constraints are checked lazily by default. By batching checks until when the transaction commits, TiDB is able to reduce network communication. This behavior can be changed by setting `tidb_constraint_check_in_place` to `TRUE`.
NOT NULL constraints supported by TiDB are the same as those supported by MySQL.

- `FOREIGN KEY` constraints are not currently enforced by DML.
For example:

## Foreign Key

TiDB currently only supports `FOREIGN KEY` creation in DDL commands. For example:
{{< copyable "sql" >}}

```sql
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)
age INT NOT NULL,
last_login TIMESTAMP
);

mysql> 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" >}}

```sql
ALTER TABLE orders DROP FOREIGN KEY fk_user_id;
ALTER TABLE orders ADD FOREIGN KEY fk_user_id (user_id) REFERENCES users(id);
INSERT INTO users (id,age,last_login) VALUES (NULL,123,NOW());
```

### Notes

* TiDB supports foreign keys so that no errors are reported for this syntax when migrating data from other databases. Currently, foreign keys are not enforced as part of DML operations. For example, even though there is no such record as `id=123` in the `users` table, the following transaction commits successfully in TiDB:
```
Query OK, 1 row affected (0.02 sec)
```

```
START TRANSACTION;
INSERT INTO orders (user_id, doc) VALUES (123, NULL);
COMMIT;
```
{{< copyable "sql" >}}

* In TiDB, the foreign key information is not displayed in the execution result of the `SHOW CREATE TABLE` statement.
```sql
INSERT INTO users (id,age,last_login) VALUES (NULL,NULL,NOW());
```

## Not Null
```
ERROR 1048 (23000): Column 'age' cannot be null
```

TiDB supports the `NOT NULL` constraint with identical semantics to MySQL. For example:
{{< copyable "sql" >}}

```sql
CREATE TABLE users (
id INT NOT NULL PRIMARY KEY AUTO_INCREMENT,
age INT NOT NULL,
last_login TIMESTAMP
);

mysql> INSERT INTO users (id,age,last_login) VALUES (NULL,123,NOW());
Query OK, 1 row affected (0.02 sec)

mysql> 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);
```

mysql> INSERT INTO users (id,age,last_login) VALUES (NULL,123,NULL);
```
Query OK, 1 row affected (0.03 sec)
```

* The first `INSERT` statement succeeded because `NULL` is permitted as a special value for columns defined as `AUTO_INCREMENT`. This results in the next auto-value being allocated.
* 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.

* The second `INSERT` statement fails because the `age` column was defined as `NOT NULL`.
## UNIQUE KEY

* The third `INSERT` statement succeeds because `last_login` did not explicitly specify the column as `NOT NULL`. The default behavior is to permit `NULL` values.
In TiDB's optimistic transaction mode, UNIQUE constraints are [checked lazily](/transaction-overview.md#lazy-check-of-constraints) by default. By batching checks when the transaction is committed, TiDB can reduce network overhead and improve performance.

## Primary Key
For example:

In TiDB, `PRIMARY KEY` constraints are checked lazily by default. By batching checks until when the transaction commits, TiDB is able to reduce network communication. For example:
{{< copyable "sql" >}}

```sql
mysql> CREATE TABLE t1 (id INT NOT NULL PRIMARY KEY);
Query OK, 0 rows affected (0.01 sec)
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" >}}

mysql> INSERT INTO t1 VALUES (1);
Query OK, 1 row affected (0.00 sec)
```sql
START TRANSACTION;
```

mysql> START TRANSACTION;
```
Query OK, 0 rows affected (0.00 sec)
```

mysql> INSERT INTO t1 VALUES (1); -- does not error
Query OK, 1 row affected (0.00 sec)
{{< copyable "sql" >}}

mysql> INSERT INTO t1 VALUES (2);
Query OK, 1 row affected (0.00 sec)
```sql
INSERT INTO users (username) VALUES ('jane'), ('chris'), ('bill');
```

mysql> COMMIT; -- triggers an error
ERROR 1062 (23000): Duplicate entry '1' for key 'PRIMARY'
```
Query OK, 3 rows affected (0.00 sec)
Records: 3 Duplicates: 0 Warnings: 0
```

`PRIMARY KEY` constraints otherwise have similar behavior and restrictions to MySQL:
{{< copyable "sql" >}}

```sql
mysql> CREATE TABLE t1 (a INT NOT NULL PRIMARY KEY);
Query OK, 0 rows affected (0.12 sec)
INSERT INTO users (username) VALUES ('steve'),('elizabeth');
```

mysql> 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
```
Query OK, 2 rows affected (0.00 sec)
Records: 2 Duplicates: 0 Warnings: 0
```

mysql> CREATE TABLE t3 (a INT NOT NULL PRIMARY KEY, b INT NOT NULL PRIMARY KEY);
ERROR 1068 (42000): Multiple primary key defined
{{< copyable "sql" >}}

mysql> CREATE TABLE t4 (a INT NOT NULL, b INT NOT NULL, PRIMARY KEY (a,b));
Query OK, 0 rows affected (0.10 sec)
```sql
COMMIT;
```

* Table `t2` failed to be created because the column `a` permitted `NULL` values.
* Table `t3` failed because there can only be one `PRIMARY KEY` on a table.
* Table `t4` was successful, because even though there can only be one primary key, it may be defined as a composite of multiple columns.
```
ERROR 1062 (23000): Duplicate entry 'bill' for key 'username'
```

In addition to these semantics, TiDB also imposes the restriction that once a table is created, the `PRIMARY KEY` can not be changed.
The first `INSERT` statement will not cause duplicate key errors, which is consistent with MySQL's rules. This check will be delayed until the transaction is committed.

## Unique
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. If this behavior is disabled, the unique constraint is checked when the statement is executed.

In TiDB, `UNIQUE` constraints are checked lazily by default. By batching checks until when the transaction commits, TiDB is able to reduce network communication. For example:
For example:

```sql
DROP TABLE IF EXISTS users;
Expand All @@ -147,45 +132,155 @@ CREATE TABLE users (
UNIQUE KEY (username)
);
INSERT INTO users (username) VALUES ('dave'), ('sarah'), ('bill');
```

{{< copyable "sql" >}}

mysql> START TRANSACTION;
```sql
SET tidb_constraint_check_in_place = 1;
```

```
Query OK, 0 rows affected (0.00 sec)
```

mysql> INSERT INTO users (username) VALUES ('jane'), ('chris'), ('bill');
Query OK, 3 rows affected (0.00 sec)
Records: 3 Duplicates: 0 Warnings: 0
{{< copyable "sql" >}}

mysql> INSERT INTO users (username) VALUES ('steve'),('elizabeth');
Query OK, 2 rows affected (0.00 sec)
Records: 2 Duplicates: 0 Warnings: 0
```sql
START TRANSACTION;
```

mysql> COMMIT;
```
Query OK, 0 rows affected (0.00 sec)
```

{{< copyable "sql" >}}

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

## 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:

{{< copyable "sql" >}}

```sql
CREATE TABLE t1 (a INT NOT NULL PRIMARY KEY);
```

* The first `INSERT` statement does not cause a duplicate key error, as it would in MySQL. This check is deferred until the `COMMIT` statement is executed.
```
Query OK, 0 rows affected (0.12 sec)
```

By changing `tidb_constraint_check_in_place` to `TRUE`, `UNIQUE` constraints will be checked as statements are executed. For example:
{{< copyable "sql" >}}

```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" >}}

```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" >}}

```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 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, by default, TiDB has an additional restriction that once a table is successfully created, its primary key cannot be changed. If you need to add/remove the primary key, you need to set `alter-primary-key` to `true` in the TiDB configuration file, and restart the TiDB instance to make it effective.

When the add/delete primary key feature is enabled, TiDB allows adding/deleting primary key to the table. However, it should be noted that, if a table with an integer type primary key has been created before the feature is enabled, you cannot delete its primary key constraint even when you enable the add/delete primary key feature.

## FOREIGN KEY

> **Note:**
>
> TiDB has limited support for foreign key constraints.

TiDB supports creating `FOREIGN KEY` constraints in DDL commands.

For example:

```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)
doc JSON
);
INSERT INTO users (username) VALUES ('dave'), ('sarah'), ('bill');
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)
);
```

mysql> SET tidb_constraint_check_in_place = TRUE;
Query OK, 0 rows affected (0.00 sec)
{{< copyable "sql" >}}

mysql> START TRANSACTION;
Query OK, 0 rows affected (0.00 sec)
```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');
```

mysql> INSERT INTO users (username) VALUES ('jane'), ('chris'), ('bill');
ERROR 1062 (23000): Duplicate entry 'bill' for key 'username'
```
+------------+-------------+-----------------+-----------------------+------------------------+
| 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" >}}

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

* The first `INSERT` statement causes a duplicate key error. This results in additional network communication, and will likely decrease insert throughput.
### Notes

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

```sql
START TRANSACTION;
INSERT INTO orders (user_id, doc) VALUES (123, NULL);
COMMIT;
```

* TiDB does not display foreign key information in the result of executing the `SHOW CREATE TABLE` statement.
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This may be fixed in pingcap/tidb#18360 before your PR merges. It will still be relevant to TiDB 4.0 and earlier, but not master.

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I think this PR can be merged within today. We can update the related content later when #18360 is merged.😄

2 changes: 1 addition & 1 deletion transaction-overview.md
Original file line number Diff line number Diff line change
Expand Up @@ -106,7 +106,7 @@ For DDL statements, the transaction is committed automatically and does not supp

## Lazy check of constraints

**Lazy check** means that by default TiDB will not check [primary key](/constraints.md#primary-key) or [unique constraints](/constraints.md#unique) when an `INSERT` statement is executed, but instead checks when the transaction is committed. In TiDB, the lazy check is performed for values written by ordinary `INSERT` statements.
**Lazy check** means that by default TiDB will not check [primary key](/constraints.md#primary-key) or [unique constraints](/constraints.md#unique-key) when an `INSERT` statement is executed, but instead checks when the transaction is committed. In TiDB, the lazy check is performed for values written by ordinary `INSERT` statements.

For example:

Expand Down
Loading