Thread: postgresql locks the whole table!

postgresql locks the whole table!

From
Dr NoName
Date:
Help!

I have a table that multiple processes must be able to
write to concurrently. However, it for some reason
gets locked in exclusive mode. I narrowed it down to
one SQL statement + some weirdness with foreign keys.
To debug this, I opened two psql sessions and typed in
the sql statements manually. Here is the situation:

CREATE TABLE take2
(
  id serial not null,
  timestamp timestamp NOT NULL DEFAULT now(),
  description text,
  iteration smallint,
  asset_id integer,
--  FOREIGN KEY (asset_id) REFERENCES public.asset
(id),  -- ON UPDATE CASCADE ON DELETE CASCADE,

  primary key(id)
);

(notice that the foreign key statement is commented
out). Just to make sure I am not causing excessive
locking unintentionally, I did "set transaction
isolation level read committed" in both psql shells
(default was serializable).

Now I type the following commands:

shell 1:

1. BEGIN
2. insert into take2 values(default, 'now()', 't1', 1,
1);


shell 2:

1. BEGIN
2. insert into take2 values(default, 'now()', 't2', 1,
1);

this works.

However, if I uncomment the foreign key statement and
recreate the table, then the second shell blocks on
the insert statement. As soon as the first transaction
is either committed or rolled back, the insert
statement goes through.

My question is why??? The two insert operations do not
conflict with each other (at least not in the
real-world situation). Also, why does the foreign key
make a difference?

looking at pg_locks, I see the following:

 relation | database | transaction |  pid  |
mode       | granted
----------+----------+-------------+-------+------------------+---------
    39356 |    34862 |        NULL | 18671 |
AccessShareLock  | t
    39356 |    34862 |        NULL | 18671 |
RowExclusiveLock | t
     NULL |     NULL |        9914 | 18671 |
ExclusiveLock    | t
    39354 |    34862 |        NULL | 18671 |
AccessShareLock  | t
    34886 |    34862 |        NULL | 18671 |
AccessShareLock  | t
    34886 |    34862 |        NULL | 18671 |
RowShareLock     | t
    16759 |    34862 |        NULL | 18671 |
AccessShareLock  | t
(7 rows)

Where does the ExclusiveLock come from? What is being
locked?

It is critical for us to run multiple transactions
concurrently -- in fact that was one of the reasons
for choosing PostgreSQL over MySQL. There are a lot of
file system operations and other processing that need
to happen along side the DB transaction. Those things
take a long time, so there is typically up to a
5-minute span between BEGIN and COMMIT. We cannot
block the production floor for 5 minutes when a user
tries to run a transaction, so as a temporary fix, we
got rid of the begin/commit. But obviously we would
rather not lose the atomicity.

So, in summary:
why does PostgreSQL lock the entire table?
what can we do about it?

This was tested on PostgreSQL 7.4.0 and 7.3.2.

thanks in advance,

Eugene

__________________________________
Do you Yahoo!?
Free Pop-Up Blocker - Get it now
http://companion.yahoo.com/

Re: postgresql locks the whole table!

From
Mike Mascari
Date:
Dr NoName wrote:

> Help!
>
> I have a table that multiple processes must be able to
> write to concurrently. However, it for some reason
> gets locked in exclusive mode. I narrowed it down to
> one SQL statement + some weirdness with foreign keys.
> To debug this, I opened two psql sessions and typed in
> the sql statements manually. Here is the situation:
>
> CREATE TABLE take2
> (
>   id serial not null,
>   timestamp timestamp NOT NULL DEFAULT now(),
>   description text,
>   iteration smallint,
>   asset_id integer,
> --  FOREIGN KEY (asset_id) REFERENCES public.asset
> (id),  -- ON UPDATE CASCADE ON DELETE CASCADE,
>
>   primary key(id)
> );

...

> 1. BEGIN
> 2. insert into take2 values(default, 'now()', 't1', 1,
> 1);

...

> So, in summary:
> why does PostgreSQL lock the entire table?

It isn't locking the entire table, it is locking the row of asset
where asset_id is 1 FOR UPDATE. When two simultaneous inserts occur in
the same child table for the same parent row, it is the equivalent of
two concurrent SELECT ... FOR UPDATE queries being executed against
the parent row.

> what can we do about it?

Not much, I'm afraid.  PostgreSQL badly needs a lock level whereby a
row is only locked for UPDATEs and DELETEs and not a pseudo SELECT ...
FOR RI_CHECK....

Mike Mascari
mascarm@mascari.com


Re: postgresql locks the whole table!

From
Jan Wieck
Date:
Dr NoName wrote:

> Help!
>
> I have a table that multiple processes must be able to
> write to concurrently. However, it for some reason
> gets locked in exclusive mode. I narrowed it down to
> one SQL statement + some weirdness with foreign keys.
> To debug this, I opened two psql sessions and typed in
> the sql statements manually. Here is the situation:
>
> CREATE TABLE take2
> (
>   id serial not null,
>   timestamp timestamp NOT NULL DEFAULT now(),
>   description text,
>   iteration smallint,
>   asset_id integer,
> --  FOREIGN KEY (asset_id) REFERENCES public.asset
> (id),  -- ON UPDATE CASCADE ON DELETE CASCADE,
>
>   primary key(id)
> );
>
> (notice that the foreign key statement is commented
> out). Just to make sure I am not causing excessive
> locking unintentionally, I did "set transaction
> isolation level read committed" in both psql shells
> (default was serializable).
>
> Now I type the following commands:
>
> shell 1:
>
> 1. BEGIN
> 2. insert into take2 values(default, 'now()', 't1', 1,
> 1);
>
>
> shell 2:
>
> 1. BEGIN
> 2. insert into take2 values(default, 'now()', 't2', 1,
> 1);
>
> this works.
>
> However, if I uncomment the foreign key statement and
> recreate the table, then the second shell blocks on
> the insert statement. As soon as the first transaction
> is either committed or rolled back, the insert
> statement goes through.
>
> My question is why??? The two insert operations do not
> conflict with each other (at least not in the
> real-world situation). Also, why does the foreign key
> make a difference?

Because PostgreSQL does not implement shared read locks on the row level
and therefore the "lightest" lock the foreign key constraint can take is
a write lock.

If you cannot make your transactons shorter (and please don't tell me
that you have user interaction going on while holding any open
transactions), then you might be able to increase your concurrency by
deferring the foreign key check until commit.


Jan

>
> looking at pg_locks, I see the following:
>
>  relation | database | transaction |  pid  |
> mode       | granted
> ----------+----------+-------------+-------+------------------+---------
>     39356 |    34862 |        NULL | 18671 |
> AccessShareLock  | t
>     39356 |    34862 |        NULL | 18671 |
> RowExclusiveLock | t
>      NULL |     NULL |        9914 | 18671 |
> ExclusiveLock    | t
>     39354 |    34862 |        NULL | 18671 |
> AccessShareLock  | t
>     34886 |    34862 |        NULL | 18671 |
> AccessShareLock  | t
>     34886 |    34862 |        NULL | 18671 |
> RowShareLock     | t
>     16759 |    34862 |        NULL | 18671 |
> AccessShareLock  | t
> (7 rows)
>
> Where does the ExclusiveLock come from? What is being
> locked?
>
> It is critical for us to run multiple transactions
> concurrently -- in fact that was one of the reasons
> for choosing PostgreSQL over MySQL. There are a lot of
> file system operations and other processing that need
> to happen along side the DB transaction. Those things
> take a long time, so there is typically up to a
> 5-minute span between BEGIN and COMMIT. We cannot
> block the production floor for 5 minutes when a user
> tries to run a transaction, so as a temporary fix, we
> got rid of the begin/commit. But obviously we would
> rather not lose the atomicity.
>
> So, in summary:
> why does PostgreSQL lock the entire table?
> what can we do about it?
>
> This was tested on PostgreSQL 7.4.0 and 7.3.2.
>
> thanks in advance,
>
> Eugene
>
> __________________________________
> Do you Yahoo!?
> Free Pop-Up Blocker - Get it now
> http://companion.yahoo.com/
>
> ---------------------------(end of broadcast)---------------------------
> TIP 9: the planner will ignore your desire to choose an index scan if your
>       joining column's datatypes do not match


--
#======================================================================#
# It's easier to get forgiveness for being wrong than for being right. #
# Let's break this rule - forgive me.                                  #
#================================================== JanWieck@Yahoo.com #


Re: postgresql locks the whole table!

From
Greg Stark
Date:
Dr NoName <spamacct11@yahoo.com> writes:

> My question is why??? The two insert operations do not
> conflict with each other (at least not in the
> real-world situation). Also, why does the foreign key
> make a difference?

It's not locking the whole table, it's locking the record that the foreign key
references. Note that they're both referencing the same foreign key.

It does this because it's afraid someone will go and delete that key before
the transaction commits. It has to take a lock that will prevent someone from
deleting the record (or updating the referenced column).

Unfortunately the only lock to choose from is an exclusive write lock. That's
overkill as you've noticed. I think this is something multiple people would
like to fix by introducing shared locks, but I wouldn't expect a solution
soon.

I don't know if there's any work-around better than just dropping the foreign
key reference.

--
greg

Re: postgresql locks the whole table!

From
Scott Ribe
Date:
> My question is why??? The two insert operations do not
> conflict with each other (at least not in the
> real-world situation). Also, why does the foreign key
> make a difference?

I don't know if this would help, but given the other explanations you've
gotten I would try setting the foreign key constraint to deferrable, then at
the beginning of the transaction defer constraints. The reasoning being that
if the check is deferred until commit, maybe the lock won't be taken until
commit, thus the window of time during which your 2 example inserts could
conflict would be more like what you expect, a brief instant.


--
Scott Ribe
scott_ribe@killerbytes.com
http://www.killerbytes.com/
(303) 665-7007 voice


Re: postgresql locks the whole table!

From
Dr NoName
Date:
> If you cannot make your transactons shorter (and
> please don't tell me
> that you have user interaction going on while
> holding any open
> transactions), then you might be able to increase
> your concurrency by
> deferring the foreign key check until commit.

oh! my! gawd!!!
THANK YOU!

__________________________________
Do you Yahoo!?
Free Pop-Up Blocker - Get it now
http://companion.yahoo.com/

Re: postgresql locks the whole table!

From
Dr NoName
Date:
> If you cannot make your transactons shorter (and
> please don't tell me
> that you have user interaction going on while
> holding any open
> transactions), then you might be able to increase
> your concurrency by
> deferring the foreign key check until commit.

oh! my! gawd!!!
THANK YOU! The deferred foreign key checks are exactly
what I needed. They are quite useful for other reasons
too. I think that should be the default for foreign
keys. Interestingly, the severe concurrency
degradation caused by immediate foreign key checks is
not explained in any of the documentation I looked at.

btw, there is no user interaction during the
transaction, just a lot of CPU- and IO-intensive
processing.

thanks,

Eugene

__________________________________
Do you Yahoo!?
Protect your identity with Yahoo! Mail AddressGuard
http://antispam.yahoo.com/whatsnewfree

Re: postgresql locks the whole table!

From
Jan Wieck
Date:
Dr NoName wrote:

>> If you cannot make your transactons shorter (and
>> please don't tell me
>> that you have user interaction going on while
>> holding any open
>> transactions), then you might be able to increase
>> your concurrency by
>> deferring the foreign key check until commit.
>
> oh! my! gawd!!!
> THANK YOU! The deferred foreign key checks are exactly
> what I needed. They are quite useful for other reasons
> too. I think that should be the default for foreign

The way it is is the way it is defined by the standard.


Jan

--
#======================================================================#
# It's easier to get forgiveness for being wrong than for being right. #
# Let's break this rule - forgive me.                                  #
#================================================== JanWieck@Yahoo.com #


Re: postgresql locks the whole table!

From
Scott Ribe
Date:
> The deferred foreign key checks are exactly
> what I needed. They are quite useful for other reasons
> too.

I believe Postgres is just following standards.

Yes, deferred is very useful for other things, like a real data model layer
mediating between UI and database--without it you have to worry about
performing inserts (and updates) in a particular order. That can be really
painful to code, and in some cases (cyclic relationships) impossible to do
except by leaving some constraints out.


--
Scott Ribe
scott_ribe@killerbytes.com
http://www.killerbytes.com/
(303) 665-7007 voice


Re: postgresql locks the whole table!

From
"Alistair Hopkins"
Date:
Just a thought...
What if you defer the foregn key constraint?
Won't this prevent the select for update until the end of the transaction,
so the lock will be as short as possible?

CONSTRAINTS

    SET CONSTRAINTS affects the behavior of constraint evaluation in the
current transaction. SET CONSTRAINTS, specified in SQL3, has these allowed
parameters:

    constraintlist

        Comma separated list of deferrable constraint names.
    mode

        The constraint mode. Allowed values are DEFERRED and IMMEDIATE.

    In IMMEDIATE mode, foreign key constraints are checked at the end of
each query.

    In DEFERRED mode, foreign key constraints marked as DEFERRABLE are
checked only at transaction commit or until its mode is explicitly set to
IMMEDIATE. This is actually only done for foreign key constraints, so it
does not apply to UNIQUE or other constraints.



Not tried this, but...

-----Original Message-----
From: pgsql-general-owner@postgresql.org
[mailto:pgsql-general-owner@postgresql.org]On Behalf Of Mike Mascari
Sent: 03 December 2003 17:00
To: Dr NoName
Cc: pgsql-general@postgresql.org
Subject: Re: [GENERAL] postgresql locks the whole table!


Dr NoName wrote:

> Help!
>
> I have a table that multiple processes must be able to
> write to concurrently. However, it for some reason
> gets locked in exclusive mode. I narrowed it down to
> one SQL statement + some weirdness with foreign keys.
> To debug this, I opened two psql sessions and typed in
> the sql statements manually. Here is the situation:
>
> CREATE TABLE take2
> (
>   id serial not null,
>   timestamp timestamp NOT NULL DEFAULT now(),
>   description text,
>   iteration smallint,
>   asset_id integer,
> --  FOREIGN KEY (asset_id) REFERENCES public.asset
> (id),  -- ON UPDATE CASCADE ON DELETE CASCADE,
>
>   primary key(id)
> );

...

> 1. BEGIN
> 2. insert into take2 values(default, 'now()', 't1', 1,
> 1);

...

> So, in summary:
> why does PostgreSQL lock the entire table?

It isn't locking the entire table, it is locking the row of asset
where asset_id is 1 FOR UPDATE. When two simultaneous inserts occur in
the same child table for the same parent row, it is the equivalent of
two concurrent SELECT ... FOR UPDATE queries being executed against
the parent row.

> what can we do about it?

Not much, I'm afraid.  PostgreSQL badly needs a lock level whereby a
row is only locked for UPDATEs and DELETEs and not a pseudo SELECT ...
FOR RI_CHECK....

Mike Mascari
mascarm@mascari.com


---------------------------(end of broadcast)---------------------------
TIP 9: the planner will ignore your desire to choose an index scan if your
      joining column's datatypes do not match



Re: postgresql locks the whole table!

From
Bruce Momjian
Date:
Greg Stark wrote:
>
> Dr NoName <spamacct11@yahoo.com> writes:
>
> > My question is why??? The two insert operations do not
> > conflict with each other (at least not in the
> > real-world situation). Also, why does the foreign key
> > make a difference?
>
> It's not locking the whole table, it's locking the record that the foreign key
> references. Note that they're both referencing the same foreign key.
>
> It does this because it's afraid someone will go and delete that key before
> the transaction commits. It has to take a lock that will prevent someone from
> deleting the record (or updating the referenced column).
>
> Unfortunately the only lock to choose from is an exclusive write lock. That's
> overkill as you've noticed. I think this is something multiple people would
> like to fix by introducing shared locks, but I wouldn't expect a solution
> soon.

As I remember the implementation problem is that we do an exclusive row
lock right now by putting the transaction id on the row and set a
special row-lock bit in the tuple.  Shared locks need to store multiple
transaction ids, and that is where we are stuck.  Shared memory is of
finite size, and the number of proc/row combinations is infinite, so it
seems we will need some shared stucture with backing store to disk, and
that will be slow.

You know the maximum number of backends on startup, but I don't see how
that helps us.  If we could somehow know the unique combinations of
those backend ids that would be used for any row, we could reserve a
range of transactions ids to map them, but the number of combinations is
too large.

Our xid/command-counter is currently 64 bits, so if we only had a
maximum of 64 backends, we could use those bits to mark the backends
holding the locks rather than put the xid in there.  Of course, the
maximum number backends can change over time, so that isn't really a
solution but more a brainstorm, but I do think shared memory bitmaps
might be in the final solution.

One idea would be to allocate 10k of shared memory for a shared lock
bitmap.  Assuming a max 100 backend, that is 2500 lock combinations,
numbered 0-2499.  We would put the bitmap number on the rows rather than
the xid.  Of course, problems are that there are only 2500 combinations
supported, and transactions have to get an exclusive lock on transaction
commit to clear their backend bits from the bitmap table so the rows can
be reused. Another refinement would be to use the row xid to store
either the xid for single backend locks, and use the bitmap table number
only when there is sharing of row locks by multiple backends.  That
might reduce the contention on the bitmap table.  If a backend wasn't
involved in shared locks, its bit wouldn't be set in the bitmap table
and it has nothing to do, and it can read the table without a lock.

--
  Bruce Momjian                        |  http://candle.pha.pa.us
  pgman@candle.pha.pa.us               |  (610) 359-1001
  +  If your life is a hard drive,     |  13 Roberts Road
  +  Christ can be your backup.        |  Newtown Square, Pennsylvania 19073

Re: postgresql locks the whole table!

From
Jeff Davis
Date:
> As I remember the implementation problem is that we do an exclusive row
> lock right now by putting the transaction id on the row and set a
> special row-lock bit in the tuple.  Shared locks need to store multiple
> transaction ids, and that is where we are stuck.  Shared memory is of
> finite size, and the number of proc/row combinations is infinite, so it
> seems we will need some shared stucture with backing store to disk, and
> that will be slow.
>
> You know the maximum number of backends on startup, but I don't see how
> that helps us.  If we could somehow know the unique combinations of
> those backend ids that would be used for any row, we could reserve a
> range of transactions ids to map them, but the number of combinations is
> too large.
>
> Our xid/command-counter is currently 64 bits, so if we only had a
> maximum of 64 backends, we could use those bits to mark the backends
> holding the locks rather than put the xid in there.  Of course, the
> maximum number backends can change over time, so that isn't really a
> solution but more a brainstorm, but I do think shared memory bitmaps
> might be in the final solution.
>
> One idea would be to allocate 10k of shared memory for a shared lock
> bitmap.  Assuming a max 100 backend, that is 2500 lock combinations,
> numbered 0-2499.  We would put the bitmap number on the rows rather than
> the xid.  Of course, problems are that there are only 2500 combinations
> supported, and transactions have to get an exclusive lock on transaction
> commit to clear their backend bits from the bitmap table so the rows can
> be reused. Another refinement would be to use the row xid to store
> either the xid for single backend locks, and use the bitmap table number
> only when there is sharing of row locks by multiple backends.  That
> might reduce the contention on the bitmap table.  If a backend wasn't
> involved in shared locks, its bit wouldn't be set in the bitmap table
> and it has nothing to do, and it can read the table without a lock.

The way I understand it, is that you're having trouble storing all of
the xids in the row; right now you just store one and mark it "locked".
If you were able to store several, but not necessarily all xids in all
cases, wouldn't that be a big improvement? The xids not in the list
would lock, as they do now, and the ones in the list would show an
improvement by sharing the lock, right?

Otherwise I don't entirely understand what you're saying.

Regards,
    Jeff Davis





Re: postgresql locks the whole table!

From
Bruce Momjian
Date:
Jeff Davis wrote:
> The way I understand it, is that you're having trouble storing all of
> the xids in the row; right now you just store one and mark it "locked".
> If you were able to store several, but not necessarily all xids in all
> cases, wouldn't that be a big improvement? The xids not in the list
> would lock, as they do now, and the ones in the list would show an
> improvement by sharing the lock, right?
>
> Otherwise I don't entirely understand what you're saying.

Yes, we could do that but we really want something that isn't going to
work only some of the time.  Ideally we want something that can share no
matter how many backends try.

--
  Bruce Momjian                        |  http://candle.pha.pa.us
  pgman@candle.pha.pa.us               |  (610) 359-1001
  +  If your life is a hard drive,     |  13 Roberts Road
  +  Christ can be your backup.        |  Newtown Square, Pennsylvania 19073

Re: postgresql locks the whole table!

From
Greg Stark
Date:
It's not strictly necessary to have a list of all xids at all. The normal
"shared read lock" is just "take the write lock, increment the readers
counter, unlock" Anyone who wants to write has to wait (using, eg, a condition
variable) until the readers count goes to 0.

This gets the right semantics but without the debugging info of a list of
lockers. Other than debugging the only advantage I see to having the list of
lockers is for deadlock detection. Is that absolutely mandatory?

--
greg

Re: postgresql locks the whole table!

From
Mike Mascari
Date:
Greg Stark wrote:
> It's not strictly necessary to have a list of all xids at all. The normal
> "shared read lock" is just "take the write lock, increment the readers
> counter, unlock" Anyone who wants to write has to wait (using, eg, a condition
> variable) until the readers count goes to 0.
>
> This gets the right semantics but without the debugging info of a list of
> lockers. Other than debugging the only advantage I see to having the list of
> lockers is for deadlock detection. Is that absolutely mandatory?

What happens if a backend is killed and never decrements its reference
count?

Mike Mascari
mascarm@mascari.com


Re: postgresql locks the whole table!

From
Stephan Szabo
Date:
On Sun, 7 Dec 2003, Greg Stark wrote:

> It's not strictly necessary to have a list of all xids at all. The normal
> "shared read lock" is just "take the write lock, increment the readers
> counter, unlock" Anyone who wants to write has to wait (using, eg, a condition
> variable) until the readers count goes to 0.

There are some storage/cleanup questions though. If that's stored in the
tuple header, what happens after a crash?

In addition, how should the locks be granted for a sequence like:
 T1: get shared lock on row A
 T2: get exclusive lock on row A
 T3: get shared lock on row A
Does T3 get the lock or not? If it does, then you have the possibility of
freezing out T2 for a very long time and badly hurting update/delete
performance. If it doesn't, then how are you keeping track of the fact
that there are one or more people who want exclusive locks on the same
row that are "in front" of you?

> This gets the right semantics but without the debugging info of a list of
> lockers. Other than debugging the only advantage I see to having the list of
> lockers is for deadlock detection. Is that absolutely mandatory?

I think so, yes, especially if we're going to use it for things like
foreign keys.  It's too easy to get into a deadlock with foreign keys
(even when implemented through shared locks) and I think having undetected
deadlocks would be even worse than our current behavior.  At least with
the current behavior you get an indication that something is wrong.

Re: postgresql locks the whole table!

From
Tom Lane
Date:
> Greg Stark wrote:
>> This gets the right semantics but without the debugging info of a list of
>> lockers. Other than debugging the only advantage I see to having the list of
>> lockers is for deadlock detection. Is that absolutely mandatory?

No, deadlock detection is not optional.

Mike Mascari <mascarm@mascari.com> writes:
> What happens if a backend is killed and never decrements its reference
> count?

Even if it's not killed, how does it know to decrement the reference
count?  You still need a list of all locked tuples *somewhere*.  Perhaps
a technique like this would allow the list to not be in shared memory,
which is helpful, but it's far from an ideal solution.

            regards, tom lane

Re: postgresql locks the whole table!

From
Greg Stark
Date:
Stephan Szabo <sszabo@megazone.bigpanda.com> writes:

> In addition, how should the locks be granted for a sequence like:
>  T1: get shared lock on row A
>  T2: get exclusive lock on row A
>  T3: get shared lock on row A
> Does T3 get the lock or not? If it does, then you have the possibility of
> freezing out T2 for a very long time and badly hurting update/delete
> performance.

Well this is a fundamental question that applies to any scheme to handle
shared locks. You get into all sorts of fun stuff like livelock and priority
inversion that real time systems folk invent just to torture programmers.

--
greg