Thread: troubleshooting a database that keeps locking up

troubleshooting a database that keeps locking up

From
Jonathan Vanasco
Date:
I have a database that has started to constantly hang after a brief period of activity

looking at `select * from pg_stat_activity;` I roughly see the following each time:

    process 1 | <IDLE>
    process 2 | <IDLE> in transaction
    process 3 | <IDLE> in transaction
    process 4 | <IDLE>
    process 5 | <IDLE>
    process 6 | <IDLE>
    process 7 | INSERT INTO table_a ........  RETURNING id

occasionally I'll see

    process 8 | UPDATE table_b

Does anyone have tips on how I can troubleshoot this.

I was hoping there would be some way to show the history of the "<IDLE> in transaction" processes, but I couldn't find
them.

I was also wondering if the "RETURNING id" might have something to do with this.

I'd appreciate any pointers in trying to figure out what is causing this.




Re: troubleshooting a database that keeps locking up

From
Tom Lane
Date:
Jonathan Vanasco <postgres@2xlp.com> writes:
> I have a database that has started to constantly hang after a brief period of activity

> looking at `select * from pg_stat_activity;` I roughly see the following each time:

>     process 1 | <IDLE>
>     process 2 | <IDLE> in transaction
>     process 3 | <IDLE> in transaction
>     process 4 | <IDLE>
>     process 5 | <IDLE>
>     process 6 | <IDLE>
>     process 7 | INSERT INTO table_a ........  RETURNING id

> Does anyone have tips on how I can troubleshoot this.

It's a reasonable bet that process 7 is blocked waiting for a lock that's
held by one of the idle-in-transaction processes.  You could look into
pg_locks to confirm that.

> I was hoping there would be some way to show the history of the "<IDLE> in transaction" processes, but I couldn't
findthem. 

No, PG doesn't track that.  You could turn on log_statement = all and
then look to the postmaster log to see what those processes had been
doing.  (You'll probably want to set log_line_prefix to at least %p
if you haven't already.)

            regards, tom lane