Thread: Referential integrity implementation - bug or user error?
Hi, Postgres fails to set null values when referenced key is deleted. I think I will try to explain with this simple example which I have tested on my linux box (rhat7.2) running postgres-v7.2. I have two tables as follows create table t1 ( id integer not null primary key ); create table t2 ( id integer not null primary key, t1_aid integer, t1_bid integer, foreign key (t1_aid) references t1 (id) on delete set null on update cascade, foreignkey (t1_bid) references t1 (id) on delete set null on update cascade ); ... and then I add some values as in msn=# insert into t1 values (1); INSERT 16904 1 msn=# insert into t1 values (2); INSERT 16905 1 msn=# insert into t2 values (1, 1, 1); INSERT 16906 1 msn=# insert into t2 values (2, 2, 2); INSERT 16907 1 msn=# insert into t2 values (3, 1, 2); INSERT 16908 1 But then when I try to delete one id from t1 I get this error message. msn=# delete from t1 where id=1; ERROR: <unnamed> referential integrity violation - key referenced from t2 not found in t1 Why this fails to set columns t1_aid and t1_bid in table t2 to null? Any help is greatly appreciated. Thanks. vujadin
Re: Referential integrity implementation - bug or user error?
From
missive@frontiernet.net (Lee Harr)
Date:
On Sun, 10 Mar 2002 23:19:34 +0100, msn <vujadin@post.tele.dk> wrote: > Hi, > > Postgres fails to set null values when referenced key is deleted. > > I think I will try to explain with this simple example which > I have tested on my linux box (rhat7.2) running postgres-v7.2. > > I have two tables as follows > > create table t1 ( > id integer not null primary key > ); > > create table t2 ( > id integer not null primary key, > t1_aid integer, > t1_bid integer, > foreign key (t1_aid) > references t1 (id) > on delete set null > on update cascade, > foreign key (t1_bid) > references t1 (id) > on delete set null > on update cascade > ); > > ... and then I add some values as in > > msn=# insert into t1 values (1); > INSERT 16904 1 > msn=# insert into t1 values (2); > INSERT 16905 1 > msn=# insert into t2 values (1, 1, 1); > INSERT 16906 1 > msn=# insert into t2 values (2, 2, 2); > INSERT 16907 1 > msn=# insert into t2 values (3, 1, 2); > INSERT 16908 1 > > But then when I try to delete one id from t1 I get this error message. > > msn=# delete from t1 where id=1; > ERROR: <unnamed> referential integrity violation - key referenced from t2 > not found in t1 > > Why this fails to set columns t1_aid and t1_bid in table t2 to null? > I guess it fails because the key it tries to use in t2 (NULL) is not in t1 (the only keys there are 1 and 2). You could insert a NULL key in to t1, then it might work... Though I am not so sure that makes sense.
On Sun, 10 Mar 2002, msn wrote: > But then when I try to delete one id from t1 I get this error message. > > msn=# delete from t1 where id=1; > ERROR: <unnamed> referential integrity violation - key referenced from t2 > not found in t1 > > Why this fails to set columns t1_aid and t1_bid in table t2 to null? Known problem with checking intermediate states of the table. It happens here because there are two references to the same table. I sent a message in response to a similar problem on -bugs that contained part of a patch that may fix this problem for you.