Re: Broken type checking for empty subqueries

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: David Rowley <dgrowleyml(at)gmail(dot)com>
Cc: Vik Fearing <vik(at)postgresfriends(dot)org>, Marek Malevič <marek(at)malevicovi(dot)net>, pgsql-bugs(at)lists(dot)postgresql(dot)org
Subject: Re: Broken type checking for empty subqueries
Date: 2023-09-28 21:53:41
Message-ID: 1103246.1695938021@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-bugs

David Rowley <dgrowleyml(at)gmail(dot)com> writes:
> On Fri, 29 Sept 2023 at 03:57, Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> wrote:
>> Sadly, I doubt that would cover enough of the problem space to make
>> much difference to people who try to do this sort of thing.

> hmm, I guess it does nothing for stuff like overflow errors since we
> didn't adjust the ereports of those functions:

Yeah. I suppose we could start trying to expand the use of soft
error reporting, but it'd be a herculean, probably multi-year
task to get to where even "most cases" would be covered.

I was actually wondering after sending my previous message whether
CASE wouldn't do the job for the OP. We do have a rule that once
a CASE test expression has reduced to constant-true or constant-false,
we skip const-folding for CASE arms that are thereby proven unreachable.
Thus for instance

regression=# select case when 1 < 2 then 42 else 1/0 end;
case
------
42
(1 row)

The big trick in using this is to understand what is covered by
const-folding and what is not. Initial conversion of a literal string
isn't, because that's done at parse time. So this still fails:

regression=# select case when 1 < 2 then 42 else 'foo'::int end;
ERROR: invalid input syntax for type integer: "foo"
LINE 1: select case when 1 < 2 then 42 else 'foo'::int end;
^

but you can get around that like this:

regression=# select case when 1 < 2 then 42 else 'foo'::text::int end;
case
------
42
(1 row)

because the text-to-int conversion is considered a run-time not
parse-time operation.

So I wonder whether that weird-looking sub-select couldn't be converted to
a simple SELECT CASE with both more readability and better future-proofing
against optimizer improvements.

Another way is to push it all into procedural logic, ie a plpgsql function
that doesn't try to evaluate the problematic expression until it's
checked the test expression.

regards, tom lane

In response to

Responses

Browse pgsql-bugs by date

  From Date Subject
Next Message Tom Lane 2023-09-28 22:14:07 Re: md5 password valid and invalid after upgrading
Previous Message Kyle MacMillan 2023-09-28 21:49:39 Re: md5 password valid and invalid after upgrading