- 2.1. The Server SQL Mode
- 2.2. MySQL Identifier Syntax and Naming Rules
- 2.3. Case Sensitivity in SQL Statements
- 2.4. Character Set Support
- 2.5. Selecting, Creating, Dropping, and Altering Databases
- 2.6. Creating, Dropping, Indexing, and Altering Tables
- 2.7. Obtaining Database Metadata
- 2.8. Performing Multiple-Table Retrievals with Joins
- 2.9. Performing Multiple-Table Retrievals with Subqueries
- 2.10. Performing Multiple-Table Retrievals with UNION
- 2.11. Multiple-Table Deletes and Updates
- 2.12. Performing Transactions
- 2.13. Foreign Keys and Referential Integrity
- 2.14. Using FULLTEXT Searches
2.13. Foreign Keys and Referential Integrity
A foreign key relationship enables you to declare that an index in one table is related to an index in another. It also enables you to place constraints on what may be done to the tables in the relationship. The database enforces the rules of this relationship to maintain referential integrity. For example, the score table in the sampdb sample database contains a student_id column, which we use to relate score rows to students in the student table. When we created these tables in Chapter 1, “Getting Started with MySQL,” we set up some explicit relationships between them. For example, we declared score.student_id to be a foreign key for the student.student_id column. That prevents a row from being entered into the score table unless its student_id value exists in the student table. In other words, the foreign key prevents entry of scores for nonexistent students.
Foreign keys are not useful just for row entry, but for deletes and updates as well. For example, we could set up a constraint such that if a student is deleted from the student table, all corresponding rows for the student in the score table are deleted automatically as well. This is called “cascaded delete” because the effect of the delete cascades from one table to another. Cascaded update is possible as well. For example, with cascaded update, changing a student’s student_id value in the student table also changes the value in the student’s corresponding score table rows.
Foreign keys maintain the consistency of your data, and they provide a certain measure of convenience. Without foreign keys, you are responsible for keeping track of inter-table dependencies and maintaining their consistency from within your applications. In some cases, doing this might not be much more work than issuing a few extra DELETE statements to make sure that when you delete a row from one table, you also delete the corresponding rows in any related tables. But it is extra work, and if the database engine will perform consistency checks for you, why not let it? Automatic checking capability is especially useful if your tables have particularly complex relationships. You likely will not want to be responsible for implementing these dependencies in your applications.
In MySQL, the InnoDB storage engine provides foreign key support. This section describes how to set up InnoDB tables to define foreign keys, and how foreign keys affect the way you use tables. First, it’s necessary to define some terms:
- The parent is the table that contains the original key values.
- The child is the related table that refers to key values in the parent.
Parent table key values are used to associate the two tables. Specifically, an index in the child table refers to an index in the parent. The child index values must match those in the parent or else be set to NULL to indicate that there is no associated parent table row. The index in the child table is known as the “foreign key”—that is, the key that is foreign (external) to the parent table but contains values that point to the parent. A foreign key relationship can be set up to reject NULL values, in which case all foreign key values must match a value in the parent table.
InnoDB enforces these rules to guarantee that the foreign key relationship stays intact with no mismatches. This is called “referential integrity.”
The following syntax shows how to define a foreign key in a child table:
[CONSTRAINT constraint_name] FOREIGN KEY [fk_name] (index_columns) REFERENCES tbl_name (index_columns) [ON DELETE action] [ON UPDATE action] [MATCH FULL | MATCH PARTIAL | MATCH SIMPLE]
Although all parts of this syntax are parsed, InnoDB does not implement the semantics for all the clauses: The MATCH clause is not supported and is ignored if you specify it. Also, some action values are recognized but have no effect. (For storage engines other than InnoDB, the entire FOREIGN KEY definition is parsed but ignored.)
InnoDB pays attention to the following parts of the definition:
- The CONSTRAINT clause, if given, supplies a name for the foreign key constraint. If you omit it, InnoDB creates a name.
- FOREIGN KEY indicates the indexed columns in the child table that must match index values in the parent table. fk_name is the foreign key ID. If given, it is ignored unless InnoDB automatically creates an index for the foreign key; in that case, fk_name becomes the index name.
- REFERENCES names the parent table and the index columns in that table to which the foreign key in the child table refers. The index_columns part of the REFERENCES clause must have the same number of columns as the index_columns that follows the FOREIGN KEY keywords.
- ON DELETE enables you to specify what happens to the child table when parent table rows are deleted. The default if no ON DELETE clause is present is to reject any attempt to delete rows in the parent table that have child rows pointing to them. To specify an action value explicitly, use one of the following clauses:
- ON DELETE NO ACTION and ON DELETE RESTRICT are the same as omitting the ON DELETE clause. Some database systems have deferred checks, and NO ACTION is a deferred check. For InnoDB, foreign key constraints are checked immediately, so NO ACTION and RESTRICT are the same.
- ON DELETE CASCADE causes matching child rows to be deleted when the corresponding parent row is deleted. In essence, the effect of the delete is cascaded from the parent to the child. This enables you to perform multiple-table deletes by deleting rows only from the parent table and letting InnoDB delete the corresponding rows from the child table.
- ON DELETE SET NULL causes index columns in matching child rows to be set to NULL when the parent row is deleted. If you use this option, all the indexed child table columns named in the foreign key definition must be defined to permit NULL values. (One implication of using this action is that you cannot define the foreign key to be a PRIMARY KEY; primary keys do not permit NULL values.)
- ON DELETE SET DEFAULT is recognized but unimplemented and InnoDB issues an error.
- ON UPDATE enables you to specify what happens to the child table when parent table rows are updated. The default if no ON UPDATE clause is present is to reject any inserts or updates in the child table that result in foreign key values that don’t have any match in the parent table index, and to prevent updates to parent table index values to which child rows point. The possible action values are the same as for ON DELETE and have similar effects.
To set up a foreign key relationship, follow these guidelines:
- The child table must have an index where the foreign key columns are listed as its first columns. The parent table must also have an index in which the columns in the REFERENCES clause are listed as its first columns. (In other words, the key columns must be indexed in the tables on both ends of the foreign key relationship.) You must create the parent table index explicitly before defining the foreign key relationship. InnoDB automatically creates an index on foreign key columns (the referencing columns) in the child table if the CREATE TABLE statement does not include such an index. This makes it easier to write the CREATE TABLE statement in some cases. However, an automatically created index will be a nonunique index and will include only the foreign key columns. You should define the index in the child table explicitly if you want it to be a PRIMARY KEY or UNIQUE index, or if it should include other columns in addition to those in the foreign key.
- Corresponding columns in the parent and child indexes must have compatible types. For example, you cannot match an INT column with a CHAR column. Corresponding character columns must be the same length. Corresponding integer columns must have the same size and must both be signed or both UNSIGNED.
- You cannot index prefixes of string columns in foreign key relationships. (That is, for string columns, you must index the entire column, not just a leading prefix of it.)
In Chapter 1, “Getting Started with MySQL,” we created tables for the grade-keeping project that have simple foreign key relationships. Now let’s work through an example that is more complex. Begin by creating tables named parent and child, such that the child table contains a foreign key that references the par_id column in the parent table:
CREATE TABLE parent ( par_id INT NOT NULL, PRIMARY KEY (par_id) ) ENGINE = INNODB; CREATE TABLE child ( par_id INT NOT NULL, child_id INT NOT NULL, PRIMARY KEY (par_id, child_id), FOREIGN KEY (par_id) REFERENCES parent (par_id) ON DELETE CASCADE ON UPDATE CASCADE ) ENGINE = INNODB;
The foreign key in this case uses ON DELETE CASCADE to specify that when a row is deleted from the parent table, MySQL also should remove child rows with a matching par_id value automatically. ON UPDATE CASCADE indicates that if a parent row par_id value is changed, MySQL also should change any matching par_id values in the child table to the new value.
Now insert a few rows into the parent table, and then add some rows to the child table that have related key values:
mysql> INSERT INTO parent (par_id) VALUES(1),(2),(3); mysql> INSERT INTO child (par_id,child_id) VALUES(1,1),(1,2); mysql> INSERT INTO child (par_id,child_id) VALUES(2,1),(2,2),(2,3); mysql> INSERT INTO child (par_id,child_id) VALUES(3,1);
These statements result in the following table contents, where each par_id value in the child table matches a par_id value in the parent table:
mysql> SELECT * FROM parent; +--------+ | par_id | +--------+ | 1 | | 2 | | 3 | +--------+ mysql> SELECT * FROM child; +--------+----------+ | par_id | child_id | +--------+----------+ | 1 | 1 | | 1 | 2 | | 2 | 1 | | 2 | 2 | | 2 | 3 | | 3 | 1 | +--------+----------+
To verify that InnoDB enforces the key relationship for insertion, try adding a row to the child table that has a par_id value not found in the parent table:
mysql> INSERT INTO child (par_id,child_id) VALUES(4,1); ERROR 1452 (23000): Cannot add or update a child row: a foreign key constraint fails (`sampdb`.`child`, CONSTRAINT `child_ibfk_1` FOREIGN KEY (`par_id`) REFERENCES `parent` (`par_id`) ON DELETE CASCADE ON UPDATE CASCADE)
To test cascaded delete, see what happens when you delete a parent row:
mysql> DELETE FROM parent WHERE par_id = 1;
MySQL deletes the row from the parent table:
mysql> SELECT * FROM parent; +--------+ | par_id | +--------+ | 2 | | 3 | +--------+
In addition, it cascades the effect of the DELETE statement to the child table:
mysql> SELECT * FROM child; +--------+----------+ | par_id | child_id | +--------+----------+ | 2 | 1 | | 2 | 2 | | 2 | 3 | | 3 | 1 | +--------+----------+
To test cascaded update, see what happens when you update a parent row:
mysql> UPDATE parent SET par_id = 100 WHERE par_id =2; mysql> SELECT * FROM parent; +--------+ | par_id | +--------+ | 3 | | 100 | +--------+ mysql> SELECT * FROM child; +--------+----------+ | par_id | child_id | +--------+----------+ | 3 | 1 | | 100 | 1 | | 100 | 2 | | 100 | 3 | +--------+----------+
The preceding example shows how to arrange for deletes or updates of a parent row to cause cascaded deletes or updates of any corresponding child rows. The ON DELETE and ON UPDATE clauses permit other actions. For example, one possibility is to let the child rows remain in the table but have their foreign key columns set to NULL. To do this, it’s necessary to make several changes to the definition of the child table:
- Use ON DELETE SET NULL rather than ON DELETE CASCADE. This tells InnoDB to set the foreign key column (par_id) to NULL instead of deleting the rows.
- Use ON UPDATE SET NULL rather than ON UPDATE CASCADE. This tells InnoDB to set the foreign key column (par_id) to NULL when matching parent rows are updated.
- The original definition of child defines par_id as NOT NULL. That won’t work with ON DELETE SET NULL or ON UPDATE SET NULL, so the column definition must be changed to permit NULL.
- The original definition of child also defines par_id to be part of a PRIMARY KEY. However, a PRIMARY KEY cannot contain NULL values. Changing par_id to permit NULL therefore also requires that the PRIMARY KEY be changed to a UNIQUE index. UNIQUE indexes enforce uniqueness except for NULL values, which can occur multiple times in the index.
To see the effect of these changes, re-create the parent table using the original definition and load the same initial rows into it. Then create the child table using the new definition shown here:
CREATE TABLE child ( par_id INT NULL, child_id INT NOT NULL, UNIQUE (par_id, child_id), FOREIGN KEY (par_id) REFERENCES parent (par_id) ON DELETE SET NULL ON UPDATE SET NULL ) ENGINE = INNODB;
With respect to inserting new rows, the child table behaves similarly to the original definition. That is, it permits insertion of rows with par_id values found in the parent table, but prohibits entry of values that aren’t listed there:
mysql> INSERT INTO child (par_id,child_id) VALUES(1,1),(1,2); mysql> INSERT INTO child (par_id,child_id) VALUES(2,1),(2,2),(2,3); mysql> INSERT INTO child (par_id,child_id) VALUES(3,1); mysql> INSERT INTO child (par_id,child_id) VALUES(4,1); ERROR 1452 (23000): Cannot add or update a child row: a foreign key constraint fails (`sampdb`.`child`, CONSTRAINT `child_ibfk_1` FOREIGN KEY (`par_id`) REFERENCES `parent` (`par_id`) ON DELETE SET NULL ON UPDATE SET NULL)
There is one difference with respect to inserting rows. Because the par_id column now is defined as NULL, you can explicitly insert rows into the child table that contain NULL and no error occurs. A difference in behavior also occurs when you delete a parent row. Try removing a parent row and then check the contents of the child table to see what happens:
mysql> DELETE FROM parent WHERE par_id = 1; mysql> SELECT * FROM child; +--------+----------+ | par_id | child_id | +--------+----------+ | NULL | 1 | | NULL | 2 | | 2 | 1 | | 2 | 2 | | 2 | 3 | | 3 | 1 | +--------+----------+
In this case, the child rows that had 1 in the par_id column are not deleted. Instead, the par_id column is set to NULL, as specified by the ON DELETE SET NULL constraint.
Updating a parent row has a similar effect:
mysql> UPDATE parent SET par_id = 100 WHERE par_id = 2; mysql> SELECT * FROM child; +--------+----------+ | par_id | child_id | +--------+----------+ | NULL | 1 | | NULL | 1 | | NULL | 2 | | NULL | 2 | | NULL | 3 | | 3 | 1 | +--------+----------+
To see what foreign key relationships an InnoDB table has, use the SHOW CREATE TABLE statement.
If an error occurs when you attempt to create a table that has a foreign key, use the SHOW ENGINE INNODB STATUS statement to get the full error message.