Re: Locking: PostgreSQL Vs. Oracle - Mailing list pgsql-admin

From Scott Mead
Subject Re: Locking: PostgreSQL Vs. Oracle
Date
Msg-id DD40A369-67DF-47F0-976B-D113AE59920E@openscg.com
Whole thread Raw
In response to Locking: PostgreSQL Vs. Oracle  (HEMPLEMAN Matthew <matthew.hempleman@alstom.com>)
List pgsql-admin

On Oct 19, 2015, at 19:55, HEMPLEMAN Matthew <matthew.hempleman@alstom.com> wrote:

Hi all,

 

I’m in the process of migrating a web application from Oracle to PostgreSQL and, after quite a few headaches, it’s almost there.  The last step (I hope) is getting to the bottom of an intermittent locking issue I see when I run integration tests.  Most of the time, all tests are passing, but occasionally a test will fail with a stale state exception.  Another developer ran a few IT tests and said one run stalled and never finished.  Based on a cursory look at the internal PG tables, he said it looked like too many tables were locked due locks propagating out via foreign keys.  I’m not sure how this could be possible.

 

I’ve been looking into the differences between PostgreSQL and Oracle locking behavior, but nothing has jumped out at me so far.  I’m not a dba so hopefully I’m missing something obvious.  Any advice would be greatly appreciated!  Thanks.

 

 

Additional information;

 

Isolation Level:  read committed for both dbs

JBoss 6.1 eap

PostgreSQL 9.4

Hibernate 3.64

Very commonly, you'll run in to a state know as 'idle in transaction'. (Select pid,datname,waiting,state,query from pg_stat_activity;)
  
   I've seen this on many apps migrated to Postgres from Oracle / SQLServer. Essentially, this means that you are:
1. Not in auto-commit
2. You have started a transaction (BEGIN;)
3. You may have done some amount of work
4. You never ended the transaction ( COMMIT, ROLLBACK, etc...)

When this happens any locks (from row-updates / deletes, etc...) could possibly cause lock contention.  You if you look at pg_stat_activity where waiting ='t' you can correlate this (via pid) to pg_locks. 

   You can also look at pg_locks where granted='f', look at the type of lock (say accessexclusive on a relation) then select * from pg_locks where relation='xyz' and see who has been granted the lock, then, go back to pg_stat_activity to find the offender. 

  Just a note: if you see 'idle in transaction in 'pg_stat_activity', the query column contains the query that was previously executed before the application stopped issuing commands. 

  Good luck!

--
Scott Mead
OpenSCG
PostgreSQL, Linux and Java experts

scottm@openscg.com ( via mobile )





CONFIDENTIALITY : This e-mail and any attachments are confidential and may be privileged. If you are not a named recipient, please notify the sender immediately and do not disclose the contents to another person, use it for any purpose or store or copy the information in any medium.

pgsql-admin by date:

Previous
From: HEMPLEMAN Matthew
Date:
Subject: Locking: PostgreSQL Vs. Oracle
Next
From: Albe Laurenz
Date:
Subject: Re: Locking: PostgreSQL Vs. Oracle