Re: Views and triggers more then one row returned by subquery. - Mailing list pgsql-general
From | Day, David |
---|---|
Subject | Re: Views and triggers more then one row returned by subquery. |
Date | |
Msg-id | DM6PR09MB482392D54140EC7BBB315B638BA90@DM6PR09MB4823.namprd09.prod.outlook.com Whole thread Raw |
In response to | Re: Views and triggers more then one row returned by subquery. (Tom Lane <tgl@sss.pgh.pa.us>) |
List | pgsql-general |
Tom,
You are exactly right about STABLE needed on the get_rule_seq function.
That resolved my issues.
I've been burned before by using a function within a view/WHERE situation and the function was not marked STABLE.
I need to start taking PREMAGEN.
I Kind of came to the same conclusion in parrallel after I ran the explain analyze on the select and wondered why the hell it was going about it like that.
Yes keeping the steps of a rule properly associated and ordered with a folder is mind bending. Sorry you had to see it.
Thanks so much for analysis and comments..
Regards
Dave
From: Tom Lane <tgl@sss.pgh.pa.us>
Sent: Tuesday, January 12, 2021 6:24 PM
To: Day, David <david.day@redcom.com>
Cc: pgsql-general@lists.postgresql.org <pgsql-general@lists.postgresql.org>
Subject: Re: Views and triggers more then one row returned by subquery.
Sent: Tuesday, January 12, 2021 6:24 PM
To: Day, David <david.day@redcom.com>
Cc: pgsql-general@lists.postgresql.org <pgsql-general@lists.postgresql.org>
Subject: Re: Views and triggers more then one row returned by subquery.
"Day, David" <david.day@redcom.com> writes:
> My presumption of views and instead of trigger behavior is that the VIEW first gets populated with the WHERE filter and then the "DELETE or UPDATE" operation will fire against each of the rendered view rows. ( ? )
> If this is true then I can't explain the more then one row returned error.
This code makes my head hurt :-(
However, it's fairly easy to tell that the trigger successfully completes
on the first view row (you can check that by sticking some RAISE NOTICE
commands in it) and then the error is thrown while evaluating the next
view row. The error has to be complaining about the "WITH rule_heads ..."
subquery in the view's targetlist; the only other subquery is the MAX()
subquery, which most certainly isn't going to return more than one row.
The trigger is evidently running rule_delete_and_decrement(), which
I am not interested in deconstructing in full, but I can see that
it modifies the contents of the my_translator table. So what must
be happening is that the "WITH rule_heads ..." subquery is returning
more than one row after that modification occurs.
I have a rough theory as to why, though I'm not planning on tracing it
down in detail. The result of the WITH clause itself *does not see the
deletion*, as specified somewhere in our fine manual. (That part is
consistent with your expectation that the view output doesn't change
while this is all going on: my_translator is being scanned using the
original query snapshot, so the subquery doesn't see the already-applied
changes.) So when we re-execute the subquery at the second view row,
the "WITH rule_heads" output is the same as before. On the other hand,
the get_rule_seq() function is going to see the updated contents of
my_translator, since it's declared VOLATILE. I think that this
inconsistency results in more than one row getting let through the
WHERE filter, and voila we get the error.
You might be able to fix this by marking get_rule_seq() as STABLE
so that it sees the same snapshot as the calling query. At least,
when I change it to stable I don't see the error anymore. Whether
things are then consistent with your intent, I can't say. But
I will say that this code is an unmaintainable pile of spaghetti,
because when the side-effects occur and where they're visible
is going to be almost impossible to keep track of.
regards, tom lane
> My presumption of views and instead of trigger behavior is that the VIEW first gets populated with the WHERE filter and then the "DELETE or UPDATE" operation will fire against each of the rendered view rows. ( ? )
> If this is true then I can't explain the more then one row returned error.
This code makes my head hurt :-(
However, it's fairly easy to tell that the trigger successfully completes
on the first view row (you can check that by sticking some RAISE NOTICE
commands in it) and then the error is thrown while evaluating the next
view row. The error has to be complaining about the "WITH rule_heads ..."
subquery in the view's targetlist; the only other subquery is the MAX()
subquery, which most certainly isn't going to return more than one row.
The trigger is evidently running rule_delete_and_decrement(), which
I am not interested in deconstructing in full, but I can see that
it modifies the contents of the my_translator table. So what must
be happening is that the "WITH rule_heads ..." subquery is returning
more than one row after that modification occurs.
I have a rough theory as to why, though I'm not planning on tracing it
down in detail. The result of the WITH clause itself *does not see the
deletion*, as specified somewhere in our fine manual. (That part is
consistent with your expectation that the view output doesn't change
while this is all going on: my_translator is being scanned using the
original query snapshot, so the subquery doesn't see the already-applied
changes.) So when we re-execute the subquery at the second view row,
the "WITH rule_heads" output is the same as before. On the other hand,
the get_rule_seq() function is going to see the updated contents of
my_translator, since it's declared VOLATILE. I think that this
inconsistency results in more than one row getting let through the
WHERE filter, and voila we get the error.
You might be able to fix this by marking get_rule_seq() as STABLE
so that it sees the same snapshot as the calling query. At least,
when I change it to stable I don't see the error anymore. Whether
things are then consistent with your intent, I can't say. But
I will say that this code is an unmaintainable pile of spaghetti,
because when the side-effects occur and where they're visible
is going to be almost impossible to keep track of.
regards, tom lane
pgsql-general by date: