Philippe Campos is a Senior Consultant of the EMEA Team at MySQL specialized in fine tuning and performance. He graduated in INPG (Grenoble) with a thesis in computer science, and has been involved in numerous databases designs, audit, support, production and migration (to Sybase mainly) over the past 20 years. He has been responsible for performance analysis and database tuning for large databases in application areas as well as data warehousing application.
In 2006, he became a member of the EMEA team as Senior Consultant.
In this article we explore how to program foreign keys into a MySQL Server. This is important when your application requires referential integrity and the storage engine you’d like to use, as in the case of MyISAM or NDB (Cluster), does not support this functionality natively. We should note that InnoDB and the upcoming code-named “Falcon” storage engine, both support foreign keys.
In general, a foreign key is a field within a database record that points to a key (or group of fields forming a key) of another record in a different table. In this arrangement, a foreign key in one table will typically refer to the primary key of another table. This enables references which can be made to link information together. This type of design is a major component of what is known as “database normalization”. It should also be noted, that data, which serves as a foreign key in one record, cannot be removed if there is another record that assumes its existence.
Some of the advantages of foreign key enforcement include:
As we mentioned in the introduction, for storage engines other then InnoDB and the upcoming code-named “Falcon” storage engine, foreign keys are not natively supported. MySQL in turn, parses the FOREIGN KEY syntax in CREATE TABLE statements, but does not use or store it. In the absence of server-side foreign key relationship checking, the workaround described in this article shows you how to handle these relationship issues.
Please note, for technical and performance reasons, the following assumed:
First, we’ll create a table called “error_msg”. This table will hold the error message we’ll send to a user when a foreign key constraint is “violated”.
CREATE TABLE error_msg (error_msg VARCHAR(32) NOT NULL PRIMARY KEY);
Next we’ll insert our error message.
INSERT INTO error_msg VALUES (‘Foreign Key Constraint Violated!’);
In this example we will use programmatic foreign keys to restrict INSERT operations. Below is the SQL for creating three parent tables using the InnoDB, NDB and MyISAM storage engines.
CREATE TABLE innodb_parent ( iparent_id INT NOT NULL, PRIMARY KEY (iparent_id) ) ENGINE=INNODB; CREATE TABLE ndb_parent ( nparent_id INT NOT NULL, PRIMARY KEY (nparent_id) ) ENGINE=NDB; CREATE TABLE myisam_parent ( mparent_id INT NOT NULL, PRIMARY KEY (mparent_id) ) ENGINE=MYISAM;
Next we’ll create three associated child tables for each storage engine.
CREATE TABLE innodb_child ( iparent_id INT NOT NULL, ichild_id INT NOT NULL, PRIMARY KEY (iparent_id, ichild_id), FOREIGN KEY (iparent_id) REFERENCES innodb_parent (iparent_id) ) ENGINE = INNODB; CREATE TABLE ndb_child ( nparent_id INT NOT NULL, nchild_id INT NOT NULL, PRIMARY KEY (nparent_id, nchild_id) ) ENGINE = NDB; CREATE TABLE myisam_child ( mparent_id INT NOT NULL, mchild_id INT NOT NULL, PRIMARY KEY (mparent_id, mchild_id) ) ENGINE = MYISAM;
Please note that the parent_id in the child tables refers to the parent_id of the parent tables.
The next step involves creating triggers for the NDB and MyISAM child tables which will ensure a corresponding parent_id value exists in the parent table when we insert a value into the child table.
CREATE TRIGGER insert_ndb_child BEFORE INSERT ON ndb_child FOR EACH ROW BEGIN IF (SELECT COUNT(*) FROM ndb_parent WHERE nparent_id=new.nparent_id)= 0 THEN INSERT error_msg VALUES ('Foreign Key Constraint Violated!'); END IF; END; CREATE TRIGGER insert_myisam_child BEFORE INSERT ON myisam_child FOR EACH ROW BEGIN IF (SELECT COUNT(*) FROM myisam_parent WHERE mparent_id=new.mparent_id)=0 THEN INSERT error_msg VALUES ('Foreign Key Constraint Violated!'); END IF; END;
Now, we’ll demonstrate how the INSERT validation works by first seeding the parent and child tables with data.
INSERT INTO innodb_parent VALUES (1), (2), (3); INSERT INTO innodb_child VALUES (1,1), (1,2), (2,1), (2,2), (2,3), (3,1); INSERT INTO ndb_parent VALUES (1), (2), (3); INSERT INTO ndb_child VALUES (1,1), (1,2), (2,1), (2,2), (2,3), (3,1); INSERT INTO myisam_parent VALUES (1), (2), (3); INSERT INTO myisam_child VALUES (1,1), (1,2), (2,1), (2,2), (2,3), (3,1);
Let’s try this example with the InnoDB engine
INSERT INTO innodb_child VALUES (4,1); ERROR 1452 (23000): Cannot add or update a child row: a foreign key constraint fails (`fk/innodb_child`, CONSTRAINT `innodb_child_ibfk_1` FOREIGN KEY (`iparent_id`) REFERENCES `innodb_parent` (`iparen t_id`))
Let’s try the same example with the NDB storage engine which leverages programmatically enforced foreign keys.
INSERT INTO ndb_child VALUES (4,1); ERROR 1062 (23000): Duplicate entry 'Foreign Key Constraint Violated!' for key 'PRIMARY'
Finally, let’s try this example with the MyISAM storage engine which also leverages programmatically enforced foreign keys.
INSERT INTO myisam_child VALUES (4,1); ERROR 1062 (23000): Duplicate entry 'Foreign Key Constraint Violated!' for key 'PRIMARY'
In all the examples above we have prohibited the insertion of the values into the child tables because of foreign key violations.
In this example we look at how to program cascading UPDATES and DELETES.
A cascading delete specifies that if an attempt is made to delete a row with a key referenced by foreign keys in existing rows in other tables, all rows that contain those foreign keys are also deleted.
A cascading update specifies that if an attempt is made to update a key value in a row, where the key value is referenced by foreign keys in existing rows in other tables, all the values that make up the foreign key are also updated to the new value specified for the key.
Drop all your previously created objects. Recreate and reseed your base error, parent and child tables. We’ll need to redefine our InnoDB child table as shown.
CREATE TABLE innodb_child ( iparent_id INT NOT NULL, ichild_id INT NOT NULL, PRIMARY KEY (iparent_id, ichild_id), FOREIGN KEY (iparent_id) REFERENCES innodb_parent (iparent_id) ON DELETE CASCADE ON UPDATE CASCADE ) ENGINE=INNODB;
Please note the update and delete will be cascaded from parent to child.
To ensure the parent_id in the child table refers to a valid key whenever an UPDATE SET parent_id= is issued, we’ll need to create the following triggers for the NDB and MyISAM tables.
CREATE TRIGGER update_ndb_child AFTER UPDATE ON ndb_child FOR EACH ROW BEGIN IF (SELECT COUNT(*) FROM ndb_parent WHERE nparent_id=new.nparent_id)=0 THEN INSERT error_msg VALUES ('Foreign Key Constraint Violated!'); END IF; END; CREATE TRIGGER update_myisam_child AFTER UPDATE ON myisam_child FOR EACH ROW BEGIN IF (SELECT COUNT(*) FROM myisam_parent WHERE mparent_id=new.mparent_id)=0 THEN INSERT error_msg VALUES ('Foreign Key Constraint Violated!'); END IF; END;
Next we ensure that referenced rows in the child tables are deleted whenever a corresponding row is deleted from the parent tables. We accomplish this by creating two additional triggers.
CREATE TRIGGER delete_ndb_child BEFORE DELETE ON ndb_parent FOR EACH ROW BEGIN DELETE FROM ndb_child WHERE nparent_id=old.nparent_id; END; CREATE TRIGGER delete_myisam_child BEFORE DELETE ON myisam_parent FOR EACH ROW BEGIN DELETE FROM myisam_child WHERE mparent_id=old.mparent_id; END;
Finally we ensure an update to the referenced key in the child table if there is an update on the parent_id column of the parent table.
CREATE TRIGGER update_ndb_parent AFTER UPDATE ON ndb_parent FOR EACH ROW BEGIN UPDATE ndb_child SET nparent_id=new.nparent_id WHERE nparent_id=old.nparent_id; END; CREATE TRIGGER update_myisam_parent AFTER UPDATE ON myisam_parent FOR EACH ROW BEGIN UPDATE myisam_child SET mparent_id=new.mparent_id WHERE mparent_id=old.mparent_id; END;
First, let’s test the validity of our updates on the InnoDB child table.
UPDATE innodb_child set iparent_id=4 WHERE iparent_id=3; ERROR 1452 (23000): Cannot add or update a child row: a foreign key constraint fails (`fk/innodb_child`, CONSTRAINT `innodb_child_ibfk_1` FOREIGN KEY (`iparent_id`) REFERENCES `innodb_parent` (`iparent_id`) ON DELETE CASCADE ON UPDATE CASCADE)
Next let’s do a similar test on the NDB and MyISAM child tables.
UPDATE ndb_child set nparent_id=4 WHERE nparent_id=3; ERROR 1062 (23000): Duplicate entry 'Foreign Key Constraint Violated!' for key 'PRIMARY' UPDATE myisam_child set mparent_id=4 WHERE mparent_id=3; ERROR 1062 (23000): Duplicate entry 'Foreign Key Constraint Violated!' for key 'PRIMARY'
Now let’s test the cascade on UPDATE constraint using InnoDB.
UPDATE innodb_parent SET iparent_id=4 WHERE iparent_id=3; Query OK, 1 row affected (0.04 sec) Rows matched: 1 Changed: 1 Warnings: 0
Let’s verify the results.
SELECT * FROM innodb_parent; +------------+ | iparent_id | +------------+ | 1 | | 2 | | 4 | +------------+ 3 rows in set (0.00 sec) SELECT * FROM innodb_child; +------------+-----------+ | iparent_id | ichild_id | +------------+-----------+ | 1 | 1 | | 1 | 2 | | 2 | 1 | | 2 | 2 | | 2 | 3 | | 4 | 1 | +------------+-----------+ 6 rows in set (0.00 sec)
Now let’s do the same test on the NDB and MyISAM tables using triggers to enforce the constraints.
UPDATE ndb_parent SET nparent_id=4 WHERE nparent_id=3; Query OK, 1 row affected (0.00 sec) Rows matched: 1 Changed: 1 Warnings: 0 SELECT * FROM ndb_parent; +------------+ | nparent_id | +------------+ | 1 | | 2 | | 4 | +------------+ 3 rows in set (0.00 sec) SELECT * FROM ndb_child; +------------+-----------+ | nparent_id | nchild_id | +------------+-----------+ | 1 | 1 | | 1 | 2 | | 2 | 1 | | 2 | 2 | | 2 | 3 | | 4 | 1 | +------------+-----------+ 6 rows in set (0.00 sec) UPDATE myisam_parent SET mparent_id=4 WHERE mparent_id=3; Query OK, 1 row affected (0.00 sec) Rows matched: 1 Changed: 1 Warnings: 0 SELECT * FROM myisam_parent; +------------+ | mparent_id | +------------+ | 1 | | 2 | | 4 | +------------+ 3 rows in set (0.00 sec) SELECT * FROM myisam_child; +------------+-----------+ | mparent_id | mchild_id | +------------+-----------+ | 1 | 1 | | 1 | 2 | | 2 | 1 | | 2 | 2 | | 2 | 3 | | 4 | 1 | +------------+-----------+ 6 rows in set (0.01 sec)
Next let’s look at how cascading deletes are handled using the InnoDB tables which natively support this functionality.
DELETE FROM innodb_parent WHERE iparent_id=4; Query OK, 1 row affected (0.05 sec)
Let’s verify the results.
SELECT * FROM innodb_child; +------------+-----------+ | iparent_id | ichild_id | +------------+-----------+ | 1 | 1 | | 1 | 2 | | 2 | 1 | | 2 | 2 | | 2 | 3 | +------------+-----------+ 5 rows in set (0.00 sec)
Now let’s do the same test on the NDB and MyISAM tables using triggers to enforce the constraints.
DELETE FROM ndb_parent WHERE nparent_id=4; Query OK, 1 row affected (0.00 sec) SELECT * FROM ndb_child; +------------+-----------+ | nparent_id | nchild_id | +------------+-----------+ | 1 | 1 | | 1 | 2 | | 2 | 1 | | 2 | 2 | | 2 | 3 | +------------+-----------+ 5 rows in set (0.00 sec) DELETE FROM myisam_parent WHERE mparent_id=4; Query OK, 1 row affected (0.00 sec) SELECT * FROM myisam_child; +------------+-----------+ | mparent_id | mchild_id | +------------+-----------+ | 1 | 1 | | 1 | 2 | | 2 | 1 | | 2 | 2 | | 2 | 3 | +------------+-----------+ 5 rows in set (0.00 sec)
In this example we look at how to programmatically restrict updates and deletes.
Drop all your previously created objects. Recreate and reseed your base error, parent and child tables. We’ll need to redefine our InnoDB child table as shown.
CREATE TABLE innodb_child ( iparent_id INT NOT NULL, ichild_id INT NOT NULL, PRIMARY KEY (iparent_id, ichild_id), FOREIGN KEY (iparent_id) REFERENCES innodb_parent (iparent_id) ON DELETE RESTRICT ON UPDATE RESTRICT ) ENGINE=INNODB;
Updates and deletes will now be forbidden if there is any cross reference.
In order to ensure the parent_id in the child table refers to a valid key when an UPDATE SET parent_id= is issued, we’ll go ahead and create the following triggers for the NDB and MyISAM tables.
CREATE TRIGGER update_ndb_child BEFORE UPDATE ON ndb_child FOR EACH ROW BEGIN IF (SELECT COUNT(*) FROM ndb_parent WHERE nparent_id=new.nparent_id)=0 THEN INSERT error_msg VALUES ('Foreign Key Constraint Violated!'); END IF; END; CREATE TRIGGER update_myisam_child BEFORE UPDATE ON myisam_child FOR EACH ROW BEGIN IF (SELECT COUNT(*) FROM m_parent WHERE mparent_id=new.mparent_id)=0 THEN INSERT error_msg VALUES ('Foreign Key Constraint Violated!'); END IF; END;
Next we’ll forbid the update of parent_id from the parent table if there are any referenced parent_id rows in the child table by creating two additional triggers.
CREATE TRIGGER update_ndb_parent BEFORE UPDATE ON ndb_parent FOR EACH ROW BEGIN IF (SELECT COUNT(*) FROM ndb_child WHERE nparent_id=old.nparent_id) !=0 THEN INSERT error_msg VALUES ('Foreign Key Constraint Violated!'); END IF; END; CREATE TRIGGER update_myisam_parent BEFORE UPDATE ON myisam_parent FOR EACH ROW BEGIN IF (SELECT COUNT(*) FROM myisam_child WHERE mparent_id=old.mparent_id) !=0 THEN INSERT error_msg VALUES ('Foreign Key Constraint Violated!'); END IF; END;
Now we’ll prevent deletions from the parent table if there are any referenced rows in the child table.
CREATE TRIGGER delete_ndb_parent BEFORE DELETE ON ndb_parent FOR EACH ROW BEGIN IF (SELECT COUNT(*) FROM ndb_child WHERE nparent_id=old.nparent_id)!=0 THEN INSERT error_msg VALUES ('Foreign Key Constraint Violated!'); END IF; END; CREATE TRIGGER delete_myisam_parent BEFORE DELETE ON myisam_parent FOR EACH ROW BEGIN IF (SELECT COUNT(*) FROM myisam_child WHERE mparent_id=old.mparent_id) !=0 THEN INSERT error_msg VALUES ('Foreign Key Constraint Violated!'); END IF; END;
Now let’s verify the constraints. First by demonstrating it natively using InnoDB, and then with the use of triggers on the NDB and MyISAM.
UPDATE restriction on Innodb.
UPDATE innodb_parent SET iparent_id=4 WHERE iparent_id=3; ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails (`fk/innodb_child`, CONSTRAINT `innodb_child_ibfk_1` FOREIGN KEY (`iparent_id`) REFERENCES `innodb_parent` (`iparent_id`))
UPDATE restriction using triggers on NDB and MyISAM.
UPDATE ndb_parent SET nparent_id=4 WHERE nparent_id=3; ERROR 1062 (23000): Duplicate entry 'Foreign Key Constraint Violated!' for key 'PRIMARY' UPDATE myisam_parent SET mparent_id=4 WHERE mparent_id=3; ERROR 1062 (23000): Duplicate entry 'Foreign Key Constraint Violated!' for key 'PRIMARY'
DELETE restriction on InnoDB.
DELETE FROM innodb_parent WHERE iparent_id=3; ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails (`fk/innodb_child`, CONSTRAINT `innodb_child_ibfk_1` FOREIGN KEY (`iparent_id`) REFERENCES `innodb_parent` (`iparent_id`))
DELETE restriction using triggers on NDB and MyISAM.
DELETE FROM ndb_parent WHERE nparent_id=3; ERROR 1062 (23000): Duplicate entry 'Foreign Key Constraint Violated!' for key 'PRIMARY' DELETE FROM myisam_parent WHERE mparent_id=3; ERROR 1062 (23000): Duplicate entry 'Foreign Key Constraint Violated!' for key 'PRIMARY'
In this article we examined how we could programmatically enforce foreign keys on storage engines which do not natively support them. This was done by the use of triggers. The key advantage to leveraging these types of constraints is to increase the integrity of the data, while simplifying the work programmers need to do to application code in order to achieve this.