1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>9.18. Conditional Expressions</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="functions-sequence.html" title="9.17. Sequence Manipulation Functions" /><link rel="next" href="functions-array.html" title="9.19. Array Functions and Operators" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">9.18. Conditional Expressions</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="functions-sequence.html" title="9.17. Sequence Manipulation Functions">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="functions.html" title="Chapter 9. Functions and Operators">Up</a></td><th width="60%" align="center">Chapter 9. Functions and Operators</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="functions-array.html" title="9.19. Array Functions and Operators">Next</a></td></tr></table><hr /></div><div class="sect1" id="FUNCTIONS-CONDITIONAL"><div class="titlepage"><div><div><h2 class="title" style="clear: both">9.18. Conditional Expressions <a href="#FUNCTIONS-CONDITIONAL" class="id_link">#</a></h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="functions-conditional.html#FUNCTIONS-CASE">9.18.1. <code class="literal">CASE</code></a></span></dt><dt><span class="sect2"><a href="functions-conditional.html#FUNCTIONS-COALESCE-NVL-IFNULL">9.18.2. <code class="literal">COALESCE</code></a></span></dt><dt><span class="sect2"><a href="functions-conditional.html#FUNCTIONS-NULLIF">9.18.3. <code class="literal">NULLIF</code></a></span></dt><dt><span class="sect2"><a href="functions-conditional.html#FUNCTIONS-GREATEST-LEAST">9.18.4. <code class="literal">GREATEST</code> and <code class="literal">LEAST</code></a></span></dt></dl></div><a id="id-1.5.8.24.2" class="indexterm"></a><a id="id-1.5.8.24.3" class="indexterm"></a><p>
3 This section describes the <acronym class="acronym">SQL</acronym>-compliant conditional expressions
4 available in <span class="productname">PostgreSQL</span>.
5 </p><div class="tip"><h3 class="title">Tip</h3><p>
6 If your needs go beyond the capabilities of these conditional
7 expressions, you might want to consider writing a server-side function
8 in a more expressive programming language.
9 </p></div><div class="note"><h3 class="title">Note</h3><p>
10 Although <code class="token">COALESCE</code>, <code class="token">GREATEST</code>, and
11 <code class="token">LEAST</code> are syntactically similar to functions, they are
12 not ordinary functions, and thus cannot be used with explicit
13 <code class="token">VARIADIC</code> array arguments.
14 </p></div><div class="sect2" id="FUNCTIONS-CASE"><div class="titlepage"><div><div><h3 class="title">9.18.1. <code class="literal">CASE</code> <a href="#FUNCTIONS-CASE" class="id_link">#</a></h3></div></div></div><p>
15 The <acronym class="acronym">SQL</acronym> <code class="token">CASE</code> expression is a
16 generic conditional expression, similar to if/else statements in
17 other programming languages:
19 </p><pre class="synopsis">
20 CASE WHEN <em class="replaceable"><code>condition</code></em> THEN <em class="replaceable"><code>result</code></em>
21 [<span class="optional">WHEN ...</span>]
22 [<span class="optional">ELSE <em class="replaceable"><code>result</code></em></span>]
26 <code class="token">CASE</code> clauses can be used wherever
27 an expression is valid. Each <em class="replaceable"><code>condition</code></em> is an
28 expression that returns a <code class="type">boolean</code> result. If the condition's
29 result is true, the value of the <code class="token">CASE</code> expression is the
30 <em class="replaceable"><code>result</code></em> that follows the condition, and the
31 remainder of the <code class="token">CASE</code> expression is not processed. If the
32 condition's result is not true, any subsequent <code class="token">WHEN</code> clauses
33 are examined in the same manner. If no <code class="token">WHEN</code>
34 <em class="replaceable"><code>condition</code></em> yields true, the value of the
35 <code class="token">CASE</code> expression is the <em class="replaceable"><code>result</code></em> of the
36 <code class="token">ELSE</code> clause. If the <code class="token">ELSE</code> clause is
37 omitted and no condition is true, the result is null.
40 </p><pre class="screen">
51 CASE WHEN a=1 THEN 'one'
64 The data types of all the <em class="replaceable"><code>result</code></em>
65 expressions must be convertible to a single output type.
66 See <a class="xref" href="typeconv-union-case.html" title="10.5. UNION, CASE, and Related Constructs">Section 10.5</a> for more details.
68 There is a <span class="quote">“<span class="quote">simple</span>”</span> form of <code class="token">CASE</code> expression
69 that is a variant of the general form above:
71 </p><pre class="synopsis">
72 CASE <em class="replaceable"><code>expression</code></em>
73 WHEN <em class="replaceable"><code>value</code></em> THEN <em class="replaceable"><code>result</code></em>
74 [<span class="optional">WHEN ...</span>]
75 [<span class="optional">ELSE <em class="replaceable"><code>result</code></em></span>]
80 <em class="replaceable"><code>expression</code></em> is computed, then compared to
81 each of the <em class="replaceable"><code>value</code></em> expressions in the
82 <code class="token">WHEN</code> clauses until one is found that is equal to it. If
83 no match is found, the <em class="replaceable"><code>result</code></em> of the
84 <code class="token">ELSE</code> clause (or a null value) is returned. This is similar
85 to the <code class="function">switch</code> statement in C.
87 The example above can be written using the simple
88 <code class="token">CASE</code> syntax:
89 </p><pre class="screen">
91 CASE a WHEN 1 THEN 'one'
104 A <code class="token">CASE</code> expression does not evaluate any subexpressions
105 that are not needed to determine the result. For example, this is a
106 possible way of avoiding a division-by-zero failure:
107 </p><pre class="programlisting">
108 SELECT ... WHERE CASE WHEN x <> 0 THEN y/x > 1.5 ELSE false END;
110 </p><div class="note"><h3 class="title">Note</h3><p>
111 As described in <a class="xref" href="sql-expressions.html#SYNTAX-EXPRESS-EVAL" title="4.2.14. Expression Evaluation Rules">Section 4.2.14</a>, there are various
112 situations in which subexpressions of an expression are evaluated at
113 different times, so that the principle that <span class="quote">“<span class="quote"><code class="token">CASE</code>
114 evaluates only necessary subexpressions</span>”</span> is not ironclad. For
115 example a constant <code class="literal">1/0</code> subexpression will usually result in
116 a division-by-zero failure at planning time, even if it's within
117 a <code class="token">CASE</code> arm that would never be entered at run time.
118 </p></div></div><div class="sect2" id="FUNCTIONS-COALESCE-NVL-IFNULL"><div class="titlepage"><div><div><h3 class="title">9.18.2. <code class="literal">COALESCE</code> <a href="#FUNCTIONS-COALESCE-NVL-IFNULL" class="id_link">#</a></h3></div></div></div><a id="id-1.5.8.24.8.2" class="indexterm"></a><a id="id-1.5.8.24.8.3" class="indexterm"></a><a id="id-1.5.8.24.8.4" class="indexterm"></a><pre class="synopsis">
119 <code class="function">COALESCE</code>(<em class="replaceable"><code>value</code></em> [<span class="optional">, ...</span>])
121 The <code class="function">COALESCE</code> function returns the first of its
122 arguments that is not null. Null is returned only if all arguments
123 are null. It is often used to substitute a default value for
124 null values when data is retrieved for display, for example:
125 </p><pre class="programlisting">
126 SELECT COALESCE(description, short_description, '(none)') ...
128 This returns <code class="varname">description</code> if it is not null, otherwise
129 <code class="varname">short_description</code> if it is not null, otherwise <code class="literal">(none)</code>.
131 The arguments must all be convertible to a common data type, which
132 will be the type of the result (see
133 <a class="xref" href="typeconv-union-case.html" title="10.5. UNION, CASE, and Related Constructs">Section 10.5</a> for details).
135 Like a <code class="token">CASE</code> expression, <code class="function">COALESCE</code> only
136 evaluates the arguments that are needed to determine the result;
137 that is, arguments to the right of the first non-null argument are
138 not evaluated. This SQL-standard function provides capabilities similar
139 to <code class="function">NVL</code> and <code class="function">IFNULL</code>, which are used in some other
141 </p></div><div class="sect2" id="FUNCTIONS-NULLIF"><div class="titlepage"><div><div><h3 class="title">9.18.3. <code class="literal">NULLIF</code> <a href="#FUNCTIONS-NULLIF" class="id_link">#</a></h3></div></div></div><a id="id-1.5.8.24.9.2" class="indexterm"></a><pre class="synopsis">
142 <code class="function">NULLIF</code>(<em class="replaceable"><code>value1</code></em>, <em class="replaceable"><code>value2</code></em>)
144 The <code class="function">NULLIF</code> function returns a null value if
145 <em class="replaceable"><code>value1</code></em> equals <em class="replaceable"><code>value2</code></em>;
146 otherwise it returns <em class="replaceable"><code>value1</code></em>.
147 This can be used to perform the inverse operation of the
148 <code class="function">COALESCE</code> example given above:
149 </p><pre class="programlisting">
150 SELECT NULLIF(value, '(none)') ...
152 In this example, if <code class="literal">value</code> is <code class="literal">(none)</code>,
153 null is returned, otherwise the value of <code class="literal">value</code>
156 The two arguments must be of comparable types.
157 To be specific, they are compared exactly as if you had
158 written <code class="literal"><em class="replaceable"><code>value1</code></em>
159 = <em class="replaceable"><code>value2</code></em></code>, so there must be a
160 suitable <code class="literal">=</code> operator available.
162 The result has the same type as the first argument — but there is
163 a subtlety. What is actually returned is the first argument of the
164 implied <code class="literal">=</code> operator, and in some cases that will have
165 been promoted to match the second argument's type. For
166 example, <code class="literal">NULLIF(1, 2.2)</code> yields <code class="type">numeric</code>,
167 because there is no <code class="type">integer</code> <code class="literal">=</code>
168 <code class="type">numeric</code> operator,
169 only <code class="type">numeric</code> <code class="literal">=</code> <code class="type">numeric</code>.
170 </p></div><div class="sect2" id="FUNCTIONS-GREATEST-LEAST"><div class="titlepage"><div><div><h3 class="title">9.18.4. <code class="literal">GREATEST</code> and <code class="literal">LEAST</code> <a href="#FUNCTIONS-GREATEST-LEAST" class="id_link">#</a></h3></div></div></div><a id="id-1.5.8.24.10.2" class="indexterm"></a><a id="id-1.5.8.24.10.3" class="indexterm"></a><pre class="synopsis">
171 <code class="function">GREATEST</code>(<em class="replaceable"><code>value</code></em> [<span class="optional">, ...</span>])
172 </pre><pre class="synopsis">
173 <code class="function">LEAST</code>(<em class="replaceable"><code>value</code></em> [<span class="optional">, ...</span>])
175 The <code class="function">GREATEST</code> and <code class="function">LEAST</code> functions select the
176 largest or smallest value from a list of any number of expressions.
177 The expressions must all be convertible to a common data type, which
178 will be the type of the result
179 (see <a class="xref" href="typeconv-union-case.html" title="10.5. UNION, CASE, and Related Constructs">Section 10.5</a> for details).
181 NULL values in the argument list are ignored. The result will be NULL
182 only if all the expressions evaluate to NULL. (This is a deviation from
183 the SQL standard. According to the standard, the return value is NULL if
184 any argument is NULL. Some other databases behave this way.)
185 </p></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="functions-sequence.html" title="9.17. Sequence Manipulation Functions">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="functions.html" title="Chapter 9. Functions and Operators">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="functions-array.html" title="9.19. Array Functions and Operators">Next</a></td></tr><tr><td width="40%" align="left" valign="top">9.17. Sequence Manipulation Functions </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> 9.19. Array Functions and Operators</td></tr></table></div></body></html>