MySQL 8.4 Reference Manual Including MySQL NDB Cluster 8.4
The MySQL implementation of foreign key constraints differs from the SQL standard in the following key respects:
If there are several rows in the parent table with the
same referenced key value,
InnoDB
performs a foreign key
check as if the other parent rows with the same key value
do not exist. For example, if you define a
RESTRICT
type constraint, and there is
a child row with several parent rows,
InnoDB
does not permit the deletion of
any of the parent rows. This is shown in the following
example:
mysql>CREATE TABLE parent (
->id INT,
->INDEX (id)
->) ENGINE=InnoDB;
Query OK, 0 rows affected (0.04 sec) mysql>CREATE TABLE child (
->id INT,
->parent_id INT,
->INDEX par_ind (parent_id),
->FOREIGN KEY (parent_id)
->REFERENCES parent(id)
->ON DELETE RESTRICT
->) ENGINE=InnoDB;
Query OK, 0 rows affected (0.02 sec) mysql>INSERT INTO parent (id)
->VALUES ROW(1), ROW(2), ROW(3), ROW(1);
Query OK, 4 rows affected (0.01 sec) Records: 4 Duplicates: 0 Warnings: 0 mysql>INSERT INTO child (id,parent_id)
->VALUES ROW(1,1), ROW(2,2), ROW(3,3);
Query OK, 3 rows affected (0.01 sec) Records: 3 Duplicates: 0 Warnings: 0 mysql>DELETE FROM parent WHERE id=1;
ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails (`test`.`child`, CONSTRAINT `child_ibfk_1` FOREIGN KEY (`parent_id`) REFERENCES `parent` (`id`) ON DELETE RESTRICT)
If ON UPDATE CASCADE
or ON
UPDATE SET NULL
recurses to update the
same table it has previously updated
during the same cascade, it acts like
RESTRICT
. This means that you cannot
use self-referential ON UPDATE CASCADE
or ON UPDATE SET NULL
operations. This
is to prevent infinite loops resulting from cascaded
updates. A self-referential ON DELETE SET
NULL
, on the other hand, is possible, as is a
self-referential ON DELETE CASCADE
.
Cascading operations may not be nested more than 15 levels
deep.
In an SQL statement that inserts, deletes, or updates many
rows, foreign key constraints (like unique constraints)
are checked row-by-row. When performing foreign key
checks, InnoDB
sets shared
row-level locks on child or parent records that it must
examine. MySQL checks foreign key constraints immediately;
the check is not deferred to transaction commit. According
to the SQL standard, the default behavior should be
deferred checking. That is, constraints are only checked
after the entire SQL statement has
been processed. This means that it is not possible to
delete a row that refers to itself using a foreign key.
No storage engine, including InnoDB
,
recognizes or enforces the MATCH
clause
used in referential-integrity constraint definitions. Use
of an explicit MATCH
clause does not
have the specified effect, and it causes ON
DELETE
and ON UPDATE
clauses
to be ignored. Specifying the MATCH
should be avoided.
The MATCH
clause in the SQL standard
controls how NULL
values in a composite
(multiple-column) foreign key are handled when comparing
to a primary key in the referenced table. MySQL
essentially implements the semantics defined by
MATCH SIMPLE
, which permits a foreign
key to be all or partially NULL
. In
that case, a (child table) row containing such a foreign
key can be inserted even though it does not match any row
in the referenced (parent) table. (It is possible to
implement other semantics using triggers.)
A FOREIGN KEY
constraint that
references a non-UNIQUE
key is not
standard SQL but rather an
InnoDB
extension that is now
deprecated, and must be enabled by setting
restrict_fk_on_non_standard_key
.
You should expect support for use of nonstandard keys to
be removed in a future version of MySQL, and migrate away
from them now.
The NDB
storage engine
requires an explicit unique key (or primary key) on any
column referenced as a foreign key, as per the SQL
standard.
For storage engines that do not support foreign keys (such
as MyISAM
), MySQL Server
parses and ignores foreign key specifications.
MySQL parses but ignores “inline
REFERENCES
specifications” (as
defined in the SQL standard) where the references are
defined as part of the column specification. MySQL accepts
REFERENCES
clauses only when specified
as part of a separate FOREIGN KEY
specification.
Defining a column to use a REFERENCES
clause has no actual effect and serves only as a
memo or comment to you that the column which you are
currently defining is intended to refer to a column in
another table. It is important to realize when
using this syntax that:
tbl_name
(col_name
)
MySQL does not perform any sort of check to make sure
that col_name
actually
exists in tbl_name
(or even
that tbl_name
itself
exists).
MySQL does not perform any sort of action on
tbl_name
such as deleting
rows in response to actions taken on rows in the table
which you are defining; in other words, this syntax
induces no ON DELETE
or ON
UPDATE
behavior whatsoever. (Although you
can write an ON DELETE
or
ON UPDATE
clause as part of the
REFERENCES
clause, it is also
ignored.)
This syntax creates a column; it does not create any sort of index or key.
You can use a column so created as a join column, as shown here:
CREATE TABLE person ( id SMALLINT UNSIGNED NOT NULL AUTO_INCREMENT, name CHAR(60) NOT NULL, PRIMARY KEY (id) ); CREATE TABLE shirt ( id SMALLINT UNSIGNED NOT NULL AUTO_INCREMENT, style ENUM('t-shirt', 'polo', 'dress') NOT NULL, color ENUM('red', 'blue', 'orange', 'white', 'black') NOT NULL, owner SMALLINT UNSIGNED NOT NULL REFERENCES person(id), PRIMARY KEY (id) ); INSERT INTO person VALUES (NULL, 'Antonio Paz'); SELECT @last := LAST_INSERT_ID(); INSERT INTO shirt VALUES ROW(NULL, 'polo', 'blue', @last), ROW(NULL, 'dress', 'white', @last), ROW(NULL, 't-shirt', 'blue', @last); INSERT INTO person VALUES (NULL, 'Lilliana Angelovska'); SELECT @last := LAST_INSERT_ID(); INSERT INTO shirt VALUES ROW(NULL, 'dress', 'orange', @last), ROW(NULL, 'polo', 'red', @last), ROW(NULL, 'dress', 'blue', @last), ROW(NULL, 't-shirt', 'white', @last); SELECT * FROM person; +----+---------------------+ | id | name | +----+---------------------+ | 1 | Antonio Paz | | 2 | Lilliana Angelovska | +----+---------------------+ SELECT * FROM shirt; +----+---------+--------+-------+ | id | style | color | owner | +----+---------+--------+-------+ | 1 | polo | blue | 1 | | 2 | dress | white | 1 | | 3 | t-shirt | blue | 1 | | 4 | dress | orange | 2 | | 5 | polo | red | 2 | | 6 | dress | blue | 2 | | 7 | t-shirt | white | 2 | +----+---------+--------+-------+ SELECT s.* FROM person p INNER JOIN shirt s ON s.owner = p.id WHERE p.name LIKE 'Lilliana%' AND s.color <> 'white'; +----+-------+--------+-------+ | id | style | color | owner | +----+-------+--------+-------+ | 4 | dress | orange | 2 | | 5 | polo | red | 2 | | 6 | dress | blue | 2 | +----+-------+--------+-------+
When used in this fashion, the
REFERENCES
clause is not displayed in
the output of SHOW CREATE
TABLE
or
DESCRIBE
:
mysql> SHOW CREATE TABLE shirt\G
*************************** 1. row ***************************
Table: shirt
Create Table: CREATE TABLE `shirt` (
`id` smallint(5) unsigned NOT NULL auto_increment,
`style` enum('t-shirt','polo','dress') NOT NULL,
`color` enum('red','blue','orange','white','black') NOT NULL,
`owner` smallint(5) unsigned NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
For information about foreign key constraints, see Section 15.1.20.5, “FOREIGN KEY Constraints”.