Thread: Exclusive lock question
I have been trying to diagnose a performance problem we have been seeing with a postgres application. The performance of the database server is usually quite good but every now and then it slows to a crawl. The output of vmstat does not show excessive CPU usage or disk IO. The output of ps does show that the number of postgres process's that appear to be stuck in some query spikes and in some cases restarting the postgres server is the only way to clear them. While trying to diagnose this problem I ran select * from pg_locks I could understand most of the output but I was wondering what a result like the following indicates relation | database | transaction | pid | mode | granted ----------+----------+-------------+-------+---------------+--------- | | 26052434 | 29411 | ExclusiveLock | t | | 26051641 | 29345 | ExclusiveLock | t | | 26052415 | 29519 | ExclusiveLock | t | | 26052407 | 29381 | ExclusiveLock | t | | 26052432 | 29658 | ExclusiveLock | t When I see the slowdowns there are hundreds of these with no entry for relation or database. Any ideas what is being locked in this case? Emil
Emil Briggs <emil@baymountain.com> writes: > When I see the slowdowns there are hundreds of these with no entry for > relation or database. Any ideas what is being locked in this case? Per the pg_locks documentation: Every transaction holds an exclusive lock on its transaction ID for its entire duration. If one transaction finds it necessary to wait specifically for another transaction, it does so by attempting to acquire share lock on the other transaction ID. That will succeed only when the other transaction terminates and releases its locks. regards, tom lane