Full table lock dropping a foreign key

From: Paul Jungwirth <pj(at)illuminatedcomputing(dot)com>
To: "pgsql-general(at)postgresql(dot)org" <pgsql-general(at)postgresql(dot)org>
Subject: Full table lock dropping a foreign key
Date: 2018-09-05 16:35:27
Message-ID: 5cfcdc5c-79db-98ed-6596-bc1fbae3ac10@illuminatedcomputing.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

Hello,

I noticed that Postgres takes an AccessExclusiveLock (a lock on the
whole table) against the *referenced* table when dropping a foreign key.
I wasn't expecting that, and some experimentation showed it does *not*
take one when creating the FK. For example:

pjtest=# create table parent (id integer primary key);
CREATE TABLE
pjtest=# create table child (id integer primary key, parent_id integer);
CREATE TABLE
pjtest=# begin;
BEGIN
pjtest=# alter table child add constraint pfk foreign key (parent_id)
references parent (id);
ALTER TABLE

And now pg_locks has this:

pjtest=# select locktype, relation::regclass, mode from pg_locks;
locktype | relation | mode
---------------+-------------+-----------------------
relation | parent_pkey | AccessShareLock
relation | child_pkey | AccessShareLock
virtualxid | | ExclusiveLock
relation | pg_locks | AccessShareLock
virtualxid | | ExclusiveLock
relation | parent | AccessShareLock
relation | parent | RowShareLock
relation | parent | ShareRowExclusiveLock
transactionid | | ExclusiveLock
relation | child | AccessShareLock
relation | child | ShareRowExclusiveLock
(11 rows)

But after dropping it:

pjtest=# commit;
COMMIT
pjtest=# begin;
BEGIN
pjtest=# alter table child drop constraint pfk;
ALTER TABLE

Now my locks are:

pjtest=# select locktype, relation::regclass, mode from pg_locks;
locktype | relation | mode
---------------+----------+---------------------
virtualxid | | ExclusiveLock
relation | pg_locks | AccessShareLock
virtualxid | | ExclusiveLock
relation | parent | AccessExclusiveLock
relation | child | AccessExclusiveLock
transactionid | | ExclusiveLock
object | | AccessExclusiveLock
object | | AccessExclusiveLock
object | | AccessExclusiveLock
object | | AccessExclusiveLock
object | | AccessExclusiveLock
(11 rows)

I noticed this on 9.5 but confirmed it on 10.5.

I was surprised because the docs give a pretty short list of things that
take AccessExclusiveLocks
(https://www.postgresql.org/docs/current/static/explicit-locking.html)
It mentions ALTER TABLE, and it makes sense when I recall that foreign
keys are implemented by putting triggers on *both* referencing &
referenced tables, but still it caught me off guard. Also I don't
understand why the lock is not necessary when adding a foreign key?

Anyway I don't have much of a question, although I wouldn't mind adding
a note to the docs that dropping an FK takes this lock on both tables,
if others agree that is a good idea.

Yours,

--
Paul ~{:-)
pj(at)illuminatedcomputing(dot)com

Responses

Browse pgsql-general by date

  From Date Subject
Next Message Dmitri Maziuk 2018-09-05 16:39:04 Re: increasing HA
Previous Message Thomas Poty 2018-09-05 15:45:05 Re: increasing HA