diff --git a/doc/src/sgml/func.sgml b/doc/src/sgml/func.sgml index 6366b17a648..67c473a8248 100644 --- a/doc/src/sgml/func.sgml +++ b/doc/src/sgml/func.sgml @@ -9983,11 +9983,13 @@ SELECT ... WHERE CASE WHEN x <> 0 THEN y/x > 1.5 ELSE false END; - As described in , functions and - operators marked IMMUTABLE can be evaluated when - the query is planned rather than when it is executed. This means - that constant parts of a subexpression that is not evaluated during - query execution might still be evaluated during query planning. + As described in , 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. diff --git a/doc/src/sgml/syntax.sgml b/doc/src/sgml/syntax.sgml index 863de8852b0..a328585b5b3 100644 --- a/doc/src/sgml/syntax.sgml +++ b/doc/src/sgml/syntax.sgml @@ -2299,6 +2299,55 @@ SELECT ... WHERE CASE WHEN x > 0 THEN y/x > 1.5 ELSE false END; example, it would be better to sidestep the problem by writing y > 1.5*x instead.) + + + CASE is not a cure-all for such issues, however. + One limitation of the technique illustrated above is that it does not + prevent early evaluation of constant subexpressions. + As described in , functions and + operators marked IMMUTABLE can be evaluated when + the query is planned rather than when it is executed. Thus for example + +SELECT CASE WHEN x > 0 THEN x ELSE 1/0 END FROM tab; + + is likely to result in a division-by-zero failure due to the planner + trying to simplify the constant subexpression, + even if every row in the table has x > 0 so that the + ELSE arm would never be entered at run time. + + + + While that particular example might seem silly, related cases that don't + obviously involve constants can occur in queries executed within + functions, since the values of function arguments and local variables + can be inserted into queries as constants for planning purposes. + Within PL/pgSQL functions, for example, using an + IF-THEN-ELSE statement to protect + a risky computation is much safer than just nesting it in a + CASE expression. + + + + Another limitation of the same kind is that a CASE cannot + prevent evaluation of an aggregate expression contained within it, + because aggregate expressions are computed before other + expressions in a SELECT list or HAVING clause + are considered. For example, the following query can cause a + division-by-zero error despite seemingly having protected against it: + +SELECT CASE WHEN min(employees) > 0 + THEN avg(expenses / employees) + END + FROM departments; + + The min() and avg() aggregates are computed + concurrently over all the input rows, so if any row + has employees equal to zero, the division-by-zero error + will occur before there is any opportunity to test the result of + min(). Instead, use a WHERE + clause to prevent problematic input rows from + reaching an aggregate function in the first place. +