Thread: apparent RI bug

apparent RI bug

From
chester c young
Date:
it appears I have a broken RI in my db.

call_individual.clh_id references call_household.clh_id

\d call_individual
...
Foreign-key constraints:   "call_individual_clh_id_fkey" FOREIGN KEY (clh_id) REFERENCES
call_household(clh_id) ON DELETE CASCADE

however:
development=# select clh_id from call_individual cli where not exists(
select 1 from call_household clh where clh.clh_id=cli.clh_id );clh_id 
-------- 14691

should not matter, but call_individual has a pre-delete trigger that
simply raises an exception to prevent deletions:       raise exception 'calls may not be deleted';


     ____________________________________________________________________________________
You rock. That's why Blockbuster's offering you one month of Blockbuster Total Access, No Cost.  
http://tc.deals.yahoo.com/tc/blockbuster/text5.com


Re: apparent RI bug

From
Stephan Szabo
Date:
On Wed, 2 Apr 2008, chester c young wrote:

> it appears I have a broken RI in my db.
>
> call_individual.clh_id references call_household.clh_id
>
> \d call_individual
> ...
> Foreign-key constraints:
>     "call_individual_clh_id_fkey" FOREIGN KEY (clh_id) REFERENCES
> call_household(clh_id) ON DELETE CASCADE
>
> however:
> development=# select clh_id from call_individual cli where not exists(
> select 1 from call_household clh where clh.clh_id=cli.clh_id );
>  clh_id
> --------
>   14691
>
> should not matter, but call_individual has a pre-delete trigger that
> simply raises an exception to prevent deletions:
>         raise exception 'calls may not be deleted';

Yeah, that looks pretty broken. Can you reproduce this from a clean start
repeatedly or is this a one off? Do you ever turn off triggers, perhaps by
modifying the pg_class row's reltriggers (I'd guess the answer is no, but
it'd be good to make sure)?



Re: apparent RI bug

From
chester c young
Date:
Stephan Szabo <sszabo@megazone.bigpanda.com> wrote:

> On Wed, 2 Apr 2008, chester c young wrote:
> 
> > it appears I have a broken RI in my db.

> Yeah, that looks pretty broken. Can you reproduce this from a clean
> start repeatedly or is this a one off? Do you ever turn off triggers,
> perhaps by modifying the pg_class row's reltriggers (I'd guess the
> answer is no, but it'd be good to make sure)?

only one error.  unable to duplicate so far.

this is a development db - triggers are frequently dropped and created,
but I don't think ever concurrently with db activity.


     ____________________________________________________________________________________
You rock. That's why Blockbuster's offering you one month of Blockbuster Total Access, No Cost.  
http://tc.deals.yahoo.com/tc/blockbuster/text5.com


Re: apparent RI bug

From
Stephan Szabo
Date:
On Thu, 3 Apr 2008, chester c young wrote:

>
> Stephan Szabo <sszabo@megazone.bigpanda.com> wrote:
>
> > On Wed, 2 Apr 2008, chester c young wrote:
> >
> > > it appears I have a broken RI in my db.
>
> > Yeah, that looks pretty broken. Can you reproduce this from a clean
> > start repeatedly or is this a one off? Do you ever turn off triggers,
> > perhaps by modifying the pg_class row's reltriggers (I'd guess the
> > answer is no, but it'd be good to make sure)?
>
> only one error.  unable to duplicate so far.
>
> this is a development db - triggers are frequently dropped and created,
> but I don't think ever concurrently with db activity.

Is it possible you ever had a before delete trigger that just did a return
NULL rather than raising an exception? IIRC, explicitly telling the
system to ignore the delete will work on the referential actions.


Re: apparent RI bug

From
chester c young
Date:
--- Stephan Szabo <sszabo@megazone.bigpanda.com> wrote:

> Is it possible you ever had a before delete trigger that just did a
> return
> NULL rather than raising an exception? IIRC, explicitly telling the
> system to ignore the delete will work on the referential actions.

yes, it is possible, for example, a function without a body or without
a "return old".

are you saying this would override the RI constraint?  if so, is this
by design?

     ____________________________________________________________________________________
You rock. That's why Blockbuster's offering you one month of Blockbuster Total Access, No Cost.  
http://tc.deals.yahoo.com/tc/blockbuster/text5.com


Re: apparent RI bug

From
Stephan Szabo
Date:
On Thu, 3 Apr 2008, chester c young wrote:

> --- Stephan Szabo <sszabo@megazone.bigpanda.com> wrote:
>
> > Is it possible you ever had a before delete trigger that just did a
> > return
> > NULL rather than raising an exception? IIRC, explicitly telling the
> > system to ignore the delete will work on the referential actions.
>
> yes, it is possible, for example, a function without a body or without
> a "return old".
>
> are you saying this would override the RI constraint?

If it returned something that would have prevented the delete without an
error, yes.

> if so, is this by design?

It's basically an ongoing question (without concensus AFAIK) about whether
a rule or trigger should be allowed to stop the referential action and
what should happen if it does.


Re: apparent RI bug

From
chester c young
Date:
--- Stephan Szabo <sszabo@megazone.bigpanda.com> wrote:

> > is it is possible, for example, a function without a body or
> without a "return old".
> >
> > are you saying this would override the RI constraint?
> 
> If it returned something that would have prevented the delete without
> an error, yes.

this is very good news that there is a reason why the RI did not work,
which is to say, RI not working randomly is very frightening


> > if so, is this by design?
> 
> It's basically an ongoing question (without concensus AFAIK) about
> whether
> a rule or trigger should be allowed to stop the referential action
> and
> what should happen if it does.

in my opinion the most important thing is that it's documented.

btw, cheers! you're my hero of the week!!


     ____________________________________________________________________________________
You rock. That's why Blockbuster's offering you one month of Blockbuster Total Access, No Cost.  
http://tc.deals.yahoo.com/tc/blockbuster/text5.com