Good explanation of cascade (ON DELETE/UPDATE) behavior
If you like the Parent
and Child
terms and you feel they are easy to be remembered, you may like the translation of ON DELETE CASCADE
to Leave No Orphans!
Which means that when a Parent
row is deleted (killed), no orphan row should stay alive in the Child
table. All children of the parent row are killed (deleted), too. If any of these children has grandchildren (in another table through another foreign key) and there is ON DELETE CASCADE
defined, these should be killed, too (and all descendants, as long as there is a cascade effect defined.)
The FOREIGN KEY
constraint itself could also be described as Allow No Orphans!
(in the first place). No Child
should ever be allowed (written) in the child table if it hasn't a Parent
(a row in the parent table).
For consistency, the ON DELETE RESTRICT
can be translated to the (less aggresive) You Can't Kill Parents!
Only childless rows can be killed (deleted.)
For example, if I have two tables - Parent and Child - where Child records are owned by Parent records, which table needs the ON DELETE CASCADE?
ON DELETE CASCADE is an optional clause in a foreign key declaration. So it goes with the foreign key declaration. (Meaning, in the "child" table.)
...it could mean delete the Parent record when the Child record is deleted, or it could mean delete the Child record when the Parent is deleted. So which is it?
One way to interpret a foreign key declaration is, "All valid values for this column come from 'that_column' in 'that_table'." When you delete a row in the "child" table, nobody cares. It doesn't affect data integrity.
When you delete a row from the "parent" table--from "that_table"--you remove a valid value from the possible values for the "child" table. To maintain data integrity, you have to do something to the "child" table. Cascading deletes is one thing you can do.
Chapter and verse, from PostgreSQL docs.
Restricting and cascading deletes are the two most common options. RESTRICT prevents deletion of a referenced row. NO ACTION means that if any referencing rows still exist when the constraint is checked, an error is raised; this is the default behavior if you do not specify anything. (The essential difference between these two choices is that NO ACTION allows the check to be deferred until later in the transaction, whereas RESTRICT does not.) CASCADE specifies that when a referenced row is deleted, row(s) referencing it should be automatically deleted as well. There are two other options: SET NULL and SET DEFAULT. These cause the referencing column(s) in the referencing row(s) to be set to nulls or their default values, respectively, when the referenced row is deleted. Note that these do not excuse you from observing any constraints. For example, if an action specifies SET DEFAULT but the default value would not satisfy the foreign key constraint, the operation will fail.
SQL:2011 Spec
There are five options for ON DELETE
and ON UPDATE
that can apply to the FOREIGN KEY
. These are called <referential actions>
, directly from the SQL:2011 spec
ON DELETE CASCADE
: if a row of the referenced table is deleted, then all matching rows in the referencing table are deleted.ON DELETE SET NULL
: if a row of the referenced table is deleted, then all referencing columns in all matching rows of the referencing table to be set to null.ON DELETE SET DEFAULT
: if a row of the referenced table is deleted, then all referencing columns in all matching rows of the referencing table to be set to the column’s default value.ON DELETE RESTRICT
: it is prohibited to delete a row of the referenced table if that row has any matching rows in the referencing table.ON DELETE NO ACTION
(the default): there is no referential delete action; the referential constraint only specifies a constraint check.
The foreign key establishes the dependent relationship. The <referential action>
determines what happens when the relationship is dissolved.
Example / Metaphor / Explanation
For this example, we will accept the common model of society and economy: where every business
is a company that maintains a relationship to the bourgeoisie
through a fatcat_owner
.
CREATE TABLE bourgeoisie(
fatcat_owner varchar(100) PRIMARY KEY
);
INSERT INTO bourgeoisie(fatcat_owner) VALUES
( 'Koch Brothers' );
CREATE TABLE business (
name varchar(100),
fatcat_owner varchar(100) REFERENCES bourgeoisie
);
INSERT INTO business(name, fatcat_owner)
VALUES ('Georgia-Pacific', 'Koch Brothers');
If all business
es are directly affected by bourgeoisie
by way of their fatcat_owner
then what do you do after the workers' revolution when that you purge the fatcat_owner
s and have a classless society?
-- Viva la revolución
BEGIN;
DELETE FROM bourgeoisie;
END;
You have a few options here,
Stop the revolution. In SQL parlance,
RESTRICT
. Some people believe this is the lesser evil, but they're usually wrong.Allow it to go on. If so when the revolution happens SQL gives you four options,
SET NULL
-- leave it blank. Who knows, maybe capitalism is restored thebourgeoisie
comes up and oligarchs fill the roll of thefatcat_owners
. Important note, the column must beNULLABLE
(notNOT NULL
) or this can never happen.SET DEFAULT
-- perhaps you had aDEFAULT
that handled this? ADEFAULT
can call a function. Maybe your schema is revolution-ready, already.CASCADE
-- there is no damage control. If thebourgeoisie
goes, so does thebusiness
. If a business must have afatcat_owner
, then sometimes it makes more sense to lose the data rather than have a non-business in abusiness
table.NO ACTION
-- this is essentially a method of delaying the check, in MySQL it's no different thanRESTRICT
, but in PostgreSQL, you'd be able to do-- Not a real revolution. -- requires constraint be DEFERRABLE INITIALLY DEFERRED BEGIN; SET CONSTRAINTS ALL DEFERRED; DELETE FROM bourgeoisie; INSERT INTO bourgeoisie VALUES ( 'Putin' ); UPDATE business SET fatcat_owner = 'Putin'; END;
In such a system, the constraint is validated only before the transaction commits. This may result in stopping the revolution, but you can recover in the transaction -- for some degree of "recover."