foreign key introduces unnecessary locking ?
Hi,
When two tables (table2 and table3) have foreign keys
referring to a common table(table1), I am unable to
have 2 concurrent transactions - one performing insert
on table1 and the other on table2, when the records
being inserted have the same foreign key.
If I use JDBC, one of the transactions aborts.
If I open 2 psql sessions and try the same, one just
waits and does not show the prompt until the other
transaction has been committed or aborted.
For example,
create table tmp1(idx int4, data int4);
create table tmp2(idx2 int4, col2 int4, constraint
tmpcon2 foreign key(col2) references tmp1(idx));
create table tmp3(idx3 int4, col3 int4, constraint
tmpcon3 foreign key(col3) references tmp1(idx));
insert into tmp1 values(1, 1);
Transaction 1 :
begin work;
insert into tmp2 values(2, 1);
Transaction2 :
begin work;
insert into tmp3 values(3,1);
Since such transactions are common for me, for the
time-being I have dropped the foreign key constraint.
Any ideas ?
Rini
__________________________________________________
Do You Yahoo!?
Yahoo! Photos - 35mm Quality Prints, Now Get 15 Free!
http://photos.yahoo.com/
Try this for both FK tables:
create table tmp2(idx2 int4, col2 int4, constraint
tmpcon2 foreign key(col2) references tmp1(idx) INITIALLY DEFERRED);
This will defer constraint checks till transaction commit...
though constraint triggers should use SnapshotDirty instead of
SELECT FOR UPDATE anyway.
Did you consider this, Jan?
Vadim
Show quoted text
When two tables (table2 and table3) have foreign keys
referring to a common table(table1), I am unable to
have 2 concurrent transactions - one performing insert
on table1 and the other on table2, when the records
being inserted have the same foreign key.If I use JDBC, one of the transactions aborts.
If I open 2 psql sessions and try the same, one just
waits and does not show the prompt until the other
transaction has been committed or aborted.For example,
create table tmp1(idx int4, data int4);
create table tmp2(idx2 int4, col2 int4, constraint
tmpcon2 foreign key(col2) references tmp1(idx));
create table tmp3(idx3 int4, col3 int4, constraint
tmpcon3 foreign key(col3) references tmp1(idx));
insert into tmp1 values(1, 1);Transaction 1 :
begin work;
insert into tmp2 values(2, 1);Transaction2 :
begin work;
insert into tmp3 values(3,1);Since such transactions are common for me, for the
time-being I have dropped the foreign key constraint.
Any ideas ?Rini
__________________________________________________
Do You Yahoo!?
Yahoo! Photos - 35mm Quality Prints, Now Get 15 Free!
http://photos.yahoo.com/
Import Notes
Resolved by subject fallback
On Mon, 2 Oct 2000, Rini Dutta wrote:
When two tables (table2 and table3) have foreign keys
referring to a common table(table1), I am unable to
have 2 concurrent transactions - one performing insert
on table1 and the other on table2, when the records
being inserted have the same foreign key.If I use JDBC, one of the transactions aborts.
If I open 2 psql sessions and try the same, one just
waits and does not show the prompt until the other
transaction has been committed or aborted.For example,
create table tmp1(idx int4, data int4);
create table tmp2(idx2 int4, col2 int4, constraint
tmpcon2 foreign key(col2) references tmp1(idx));
create table tmp3(idx3 int4, col3 int4, constraint
tmpcon3 foreign key(col3) references tmp1(idx));
insert into tmp1 values(1, 1);Transaction 1 :
begin work;
insert into tmp2 values(2, 1);Transaction2 :
begin work;
insert into tmp3 values(3,1);Since such transactions are common for me, for the
time-being I have dropped the foreign key constraint.
Any ideas ?
Each is attempting to grab row locks on tmp1 to prevent
the rows from going away while we're testing the
references. The second transaction is waiting for the row
lock to go away so that it can do its row lock.
I'm not sure why its failing in JDBC though.
Mikheev, Vadim wrote:
Try this for both FK tables:
create table tmp2(idx2 int4, col2 int4, constraint
tmpcon2 foreign key(col2) references tmp1(idx) INITIALLY DEFERRED);This will defer constraint checks till transaction commit...
though constraint triggers should use SnapshotDirty instead of
SELECT FOR UPDATE anyway.Did you consider this, Jan?
Vadim
Whenever the checks are done, the transaction inserting a new
reference to the key must ensure that this key cannot get
deleted until it is done and it's newly inserted reference is
visible to others. Otherwise a referential action,
preventing referenced key deletion (or other action) wouldn't
see those and it would be possible to violate the constraint.
I don't see any other way doing it than obtaining a lock.
Using SnapshotDirty would mean, that one transaction could
DELETE a reference, then another transaction removes the
primary key (because using Dirty the DELETE is already
visible), but now the first transaction rolls back. Voila,
constraint violated.
Jan
--
#======================================================================#
# It's easier to get forgiveness for being wrong than for being right. #
# Let's break this rule - forgive me. #
#================================================== JanWieck@Yahoo.com #
though constraint triggers should use SnapshotDirty instead of
SELECT FOR UPDATE anyway.Did you consider this, Jan?
Whenever the checks are done, the transaction inserting a new
reference to the key must ensure that this key cannot get
deleted until it is done and it's newly inserted reference is
visible to others. Otherwise a referential action,
preventing referenced key deletion (or other action) wouldn't
see those and it would be possible to violate the constraint.I don't see any other way doing it than obtaining a lock.
Using SnapshotDirty would mean, that one transaction could
DELETE a reference, then another transaction removes the
primary key (because using Dirty the DELETE is already
visible), but now the first transaction rolls back. Voila,
constraint violated.
Using Dirty transaction removing/updating PK could see that concurrent
xaction attempts to update/insert FK and so would wait for its commit/abort.
Just like now same row writers wait for each other.
Having this, we could insert FK without holding locks over PK. At the moment
of constarint check we would see and wait concurrent PK deletion.
If two xactons will wait for each other then one of them will be aborted.
This behaviour is more natural for MVCC system postulated that
only same-row-writers wait for each other. Why two same FK inserters
should wait for each other if we can avoid this?
Also, is there any way to get deferrable PK/UK constraints? I wonder
why unique index is used for them.
Vadim
Using Dirty transaction removing/updating PK could see that concurrent
xaction attempts to update/insert FK and so would wait for its
commit/abort.
^^^^^^^^
Of course this will require some function that would take tid as one of
arguments, fetch row and check if someone is updating it.
Just like now same row writers wait for each other.
Vadim