Introduction
DEFERRED CONSTRAINTS are useful when you know that in a transaction you'll have inconsistent data for a while, like foreign keys that don't match, but you know that at the end of a transaction it will be consistent.
It was a nice PostgreSQL surprise to discover DEFERRED CONSTRAINTS
, because it's not present in many other relational databases. PostgreSQL's documentation is always amazing, worth having a look at it. I would highlight the first two paragraphs:
SET CONSTRAINTS sets the behavior of constraint checking within the current transaction. IMMEDIATE constraints are checked at the end of each statement. DEFERRED constraints are not checked until transaction commit. Each constraint has its own IMMEDIATE or DEFERRED mode.
Upon creation, a constraint is given one of three characteristics: DEFERRABLE INITIALLY DEFERRED, DEFERRABLE INITIALLY IMMEDIATE, or NOT DEFERRABLE. The third class is always IMMEDIATE and is not affected by the SET CONSTRAINTS command. The first two classes start every transaction in the indicated mode, but their behavior can be changed within a transaction by SET CONSTRAINTS.
And it's also important to note that not all the constraints can be deferred:
Currently, only UNIQUE, PRIMARY KEY, REFERENCES (foreign key), and EXCLUDE constraints are affected by this setting. NOT NULL and CHECK constraints are always checked immediately when a row is inserted or modified (not at the end of the statement). Uniqueness and exclusion constraints that have not been declared DEFERRABLE are also checked immediately.
The firing of triggers that are declared as “constraint triggers” is also controlled by this setting — they fire at the same time that the associated constraint should be checked.
When to use them
Before showing some SQL code, two examples where I find DEFERRED CONSTRAINTS
useful. When you need to:
- Update primary keys that are part of primary or foreign keys in related tables.
- Insert in multiple tables when you don't know the relationship between them. For example, a generic service to update master table's data in multiple services.
Example
We create two related tables with the usual syntax:
CREATE TABLE public.Countries
(
code CHAR(2),
description VARCHAR(100),
CONSTRAINT coutry_pkey PRIMARY KEY (code)
);
CREATE TABLE public.Cities
(
country_code CHAR(2),
city_code CHAR(3),
description VARCHAR(100),
CONSTRAINT cities_pkey PRIMARY KEY (country_code, city_code),
CONSTRAINT fk_cities_countries FOREIGN KEY (country_code) REFERENCES public.Countries (code)
);
We must insert first into public.Countries
and then public.Cities
, because of fk_cities_countries
foreign key constraint:
INSERT INTO public.Countries (code, description)
VALUES('as','Argentina');
INSERT INTO public.Countries (code, description)
VALUES('us','United States');
INSERT INTO public.Countries (code, description)
VALUES('es','Spain');
INSERT INTO public.Cities (country_code, city_code, description)
VALUES('us', 'stl', 'Seatle');
INSERT INTO public.Cities (country_code, city_code, description)
VALUES('as', 'ba', 'Buenos Aires');
INSERT INTO public.Cities (country_code, city_code, description)
VALUES('es', 'mad', 'Madrid');
INSERT INTO public.Cities (country_code, city_code, description)
VALUES('us', 'ny', 'New York');
But we could change the order if the foreign key is enabled to be deferred:
ALTER TABLE public.Cities
ALTER CONSTRAINT fk_cities_countries DEFERRABLE INITIALLY IMMEDIATE;
To avoid the error, inside the transaction must be set SET CONSTRAINTS ALL DEFERRED;
(or specifying the constraint's name we're interested in instead of ALL):
START TRANSACTION;
SET CONSTRAINTS ALL DEFERRED;
INSERT INTO public.Cities (country_code, city_code, description)
VALUES('us', 'stl', 'Seatle');
INSERT INTO public.Cities (country_code, city_code, description)
VALUES('as', 'ba', 'Buenos Aires');
INSERT INTO public.Cities (country_code, city_code, description)
VALUES('es', 'mad', 'Madrid');
INSERT INTO public.Cities (country_code, city_code, description)
VALUES('us', 'ny', 'New York');
INSERT INTO public.Countries (code, description)
VALUES('as','Argentina');
INSERT INTO public.Countries (code, description)
VALUES('us','United States');
INSERT INTO public.Countries (code, description)
VALUES('es','Spain');
COMMIT TRANSACTION;
To change the correct code of Argentina, ar
instead of as
, we can do it easily:
START TRANSACTION;
SET CONSTRAINTS ALL DEFERRED;
UPDATE public.Countries SET code = 'ar' WHERE code = 'as';
UPDATE public.Cities SET country_code = 'ar' WHERE country_code = 'as';
COMMIT TRANSACTION;
Once done, it might be interesting to configure the CONSTRAINT
back with the default behavior:
ALTER TABLE public.Cities
ALTER CONSTRAINT fk_cities_countries DEFERRABLE INITIALLY IMMEDIATE;
This example could be achieved adding ON UPDATE CASCADE clause when creating the foreign key constraint. But it's an easy example that shows how it works.