blob: b500091643bfa5fc6192e514996c5dbe5f276ad7 [file] [log] [blame]
<?xml version="1.0" encoding="UTF-8"?>
<!--
Licensed to the Apache Software Foundation (ASF) under one
or more contributor license agreements. See the NOTICE file
distributed with this work for additional information
regarding copyright ownership. The ASF licenses this file
to you under the Apache License, Version 2.0 (the
"License"); you may not use this file except in compliance
with the License. You may obtain a copy of the License at
http://www.apache.org/licenses/LICENSE-2.0
Unless required by applicable law or agreed to in writing,
software distributed under the License is distributed on an
"AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY
KIND, either express or implied. See the License for the
specific language governing permissions and limitations
under the License.
-->
<!DOCTYPE concept PUBLIC "-//OASIS//DTD DITA Concept//EN" "concept.dtd">
<concept id="conditional_functions">
<title>Impala Conditional Functions</title>
<titlealts audience="PDF">
<navtitle>Conditional Functions</navtitle>
</titlealts>
<prolog>
<metadata>
<data name="Category" value="Impala"/>
<data name="Category" value="Impala Functions"/>
<data name="Category" value="SQL"/>
<data name="Category" value="Data Analysts"/>
<data name="Category" value="Developers"/>
<data name="Category" value="Querying"/>
</metadata>
</prolog>
<conbody>
<p>
Impala supports the following conditional functions for testing equality, comparison
operators, and nullity:
</p>
<ul>
<li>
<xref href="#conditional_functions/case">CASE</xref>
</li>
<li>
<xref href="#conditional_functions/case2">CASE2</xref>
</li>
<li>
<xref href="#conditional_functions/coalesce">COALESCE</xref>
</li>
<li>
<xref href="#conditional_functions/decode">DECODE</xref>
</li>
<li>
<xref href="#conditional_functions/if">IF</xref>
</li>
<li>
<xref href="#conditional_functions/ifnull">IFNULL</xref>
</li>
<li>
<xref href="#conditional_functions/isfalse">ISFALSE</xref>
</li>
<li>
<xref href="#conditional_functions/isnotfalse">ISNOTFALSE</xref>
</li>
<li>
<xref href="#conditional_functions/isnottrue">ISNOTTRUE</xref>
</li>
<li>
<xref href="#conditional_functions/isnull">ISNULL</xref>
</li>
<li>
<xref href="#conditional_functions/istrue">ISTRUE</xref>
</li>
<li>
<xref href="#conditional_functions/nonnullvalue">NONNULLVALUE</xref>
</li>
<li>
<xref href="#conditional_functions/nullif">NULLIF</xref>
</li>
<li>
<xref href="#conditional_functions/nullifzero">NULLIFZERO</xref>
</li>
<li>
<xref href="#conditional_functions/nullvalue">NULLVALUE</xref>
</li>
<li>
<xref href="#conditional_functions/nvl">NVL</xref>
</li>
<li>
<xref href="#conditional_functions/nvl2">NVL2</xref>
</li>
<li>
<xref href="#conditional_functions/zeroifnull">ZEROIFNULL</xref>
</li>
</ul>
<dl>
<dlentry id="case">
<dt>
CASE a WHEN b THEN c [WHEN d THEN e]... [ELSE f] END
</dt>
<dd>
<b>Purpose:</b> Compares an expression to one or more possible values, and returns a
corresponding result when a match is found.
<p
conref="../shared/impala_common.xml#common/return_same_type"/>
<p conref="../shared/impala_common.xml#common/usage_notes_blurb"/>
<p>
In this form of the <codeph>CASE</codeph> expression, the initial value
<codeph>A</codeph> being evaluated for each row it typically a column reference, or
an expression involving a column. This form can only compare against a set of
specified values, not ranges, multi-value comparisons such as
<codeph>BETWEEN</codeph> or <codeph>IN</codeph>, regular expressions, or
<codeph>NULL</codeph>.
</p>
<p conref="../shared/impala_common.xml#common/example_blurb"/>
<p>
Although this example is split across multiple lines, you can put any or all parts
of a <codeph>CASE</codeph> expression on a single line, with no punctuation or other
separators between the <codeph>WHEN</codeph>, <codeph>ELSE</codeph>, and
<codeph>END</codeph> clauses.
</p>
<codeblock>select case x
when 1 then 'one'
when 2 then 'two'
when 0 then 'zero'
else 'out of range'
end
from t1;
</codeblock>
</dd>
</dlentry>
<dlentry id="case2">
<dt>
CASE WHEN a THEN b [WHEN c THEN d]... [ELSE e] END
</dt>
<dd>
<b>Purpose:</b> Tests whether any of a sequence of expressions is
<codeph>TRUE</codeph>, and returns a corresponding result for the first true
expression.
<p
conref="../shared/impala_common.xml#common/return_same_type"/>
<p conref="../shared/impala_common.xml#common/usage_notes_blurb"/>
<p>
<codeph>CASE</codeph> expressions without an initial test value have more
flexibility. For example, they can test different columns in different
<codeph>WHEN</codeph> clauses, or use comparison operators such as
<codeph>BETWEEN</codeph>, <codeph>IN</codeph> and <codeph>IS NULL</codeph> rather
than comparing against discrete values.
</p>
<p>
<codeph>CASE</codeph> expressions are often the foundation of long queries that
summarize and format results for easy-to-read reports. For example, you might use a
<codeph>CASE</codeph> function call to turn values from a numeric column into
category strings corresponding to integer values, or labels such as <q>Small</q>,
<q>Medium</q> and <q>Large</q> based on ranges. Then subsequent parts of the query
might aggregate based on the transformed values, such as how many values are
classified as small, medium, or large. You can also use <codeph>CASE</codeph> to
signal problems with out-of-bounds values, <codeph>NULL</codeph> values, and so on.
</p>
<p>
By using operators such as <codeph>OR</codeph>, <codeph>IN</codeph>,
<codeph>REGEXP</codeph>, and so on in <codeph>CASE</codeph> expressions, you can
build extensive tests and transformations into a single query. Therefore,
applications that construct SQL statements often rely heavily on
<codeph>CASE</codeph> calls in the generated SQL code.
</p>
<p>
Because this flexible form of the <codeph>CASE</codeph> expressions allows you to
perform many comparisons and call multiple functions when evaluating each row, be
careful applying elaborate <codeph>CASE</codeph> expressions to queries that process
large amounts of data. For example, when practical, evaluate and transform values
through <codeph>CASE</codeph> after applying operations such as aggregations that
reduce the size of the result set; transform numbers to strings after performing
joins with the original numeric values.
</p>
<p conref="../shared/impala_common.xml#common/example_blurb"/>
<p>
Although this example is split across multiple lines, you can put any or all parts
of a <codeph>CASE</codeph> expression on a single line, with no punctuation or other
separators between the <codeph>WHEN</codeph>, <codeph>ELSE</codeph>, and
<codeph>END</codeph> clauses.
</p>
<codeblock>select case
when dayname(now()) in ('Saturday','Sunday') then 'result undefined on weekends'
when x > y then 'x greater than y'
when x = y then 'x and y are equal'
when x is null or y is null then 'one of the columns is null'
else null
end
from t1;
</codeblock>
</dd>
</dlentry>
<dlentry id="coalesce">
<dt>
COALESCE(type v1, type v2, ...)
</dt>
<dd>
<b>Purpose:</b> Returns the first specified argument that is not
<codeph>NULL</codeph>, or <codeph>NULL</codeph> if all arguments are
<codeph>NULL</codeph>.
<p
conref="../shared/impala_common.xml#common/return_same_type"/>
</dd>
</dlentry>
<dlentry rev="2.0.0" id="decode">
<dt>
DECODE(type expression, type search1, type result1 [, type search2, type result2 ...]
[, type default] )
</dt>
<dd>
<b>Purpose:</b> Compares the first argument, <codeph>expression</codeph>, to the
<codeph>search</codeph> expressions using the <codeph>IS NOT DISTINCT</codeph>
operator, and returns:
<ul>
<li>
The corresponding <codeph>result</codeph> when a match is found.
</li>
<li>
The first corresponding <codeph>result</codeph> if there are more than one
matching <codeph>search</codeph> expressions.
</li>
<li>
The <codeph>default</codeph> expression if none of the search expressions matches
the first argument <codeph>expression</codeph>.
</li>
<li>
<codeph>NULL</codeph> if the final <codeph>default</codeph> expression is omitted
and none of the <codeph>search</codeph> expressions matches the first argument.
</li>
</ul>
<p>
<b>Return type:</b> Same as the first argument with the following exceptions:
<ul>
<li>
Integer values are promoted to <codeph>BIGINT</codeph>.
</li>
<li>
Floating-point values are promoted to <codeph>DOUBLE</codeph>.
</li>
<li>
Use <codeph>CAST()</codeph> when inserting into a smaller numeric column.
</li>
</ul>
</p>
<p conref="../shared/impala_common.xml#common/usage_notes_blurb"/>
<ul>
<li>
Can be used as shorthand for a <codeph>CASE</codeph> expression.
</li>
<li>
The first argument, <codeph>expression</codeph>, and the search expressions must
be of the same type or convertible types.
</li>
<li>
The result expression can be a different type, but all result expressions must be
of the same type.
</li>
<li>
Returns a successful match if the first argument is <codeph>NULL</codeph> and a
search expression is also <codeph>NULL</codeph>.
</li>
<li>
<codeph>NULL</codeph> can be used as a search expression.
</li>
</ul>
<p conref="../shared/impala_common.xml#common/example_blurb"/>
<p>
The following example translates numeric day values into weekday names, such as 1 to
Monday, 2 to Tuesday, etc.
</p>
<codeblock>SELECT event, DECODE(day_of_week, 1, "Monday", 2, "Tuesday", 3, "Wednesday",
4, "Thursday", 5, "Friday", 6, "Saturday", 7, "Sunday", "Unknown day")
FROM calendar;
</codeblock>
</dd>
</dlentry>
<dlentry id="if">
<dt>
IF(BOOLEAN condition, type ifTrue, type ifFalseOrNull)
</dt>
<dd>
<b>Purpose:</b> Tests an expression and returns a corresponding result depending on
whether the result is <codeph>TRUE</codeph>, <codeph>FALSE</codeph>, or
<codeph>NULL</codeph>.
<p>
<b>Return type:</b> Same as the <codeph>ifTrue</codeph> argument value
</p>
</dd>
</dlentry>
<dlentry rev="1.3.0" id="ifnull">
<dt>
IFNULL(type a, type ifNull)
</dt>
<dd>
<b>Purpose:</b> Alias for the <codeph>ISNULL()</codeph> function, with the same
behavior. To simplify porting SQL with vendor extensions to Impala.
<p conref="../shared/impala_common.xml#common/added_in_130"/>
</dd>
</dlentry>
<dlentry id="isfalse" rev="2.2.0">
<dt>
ISFALSE(BOOLEAN expression)
</dt>
<dd>
<b>Purpose:</b> Returns <codeph>TRUE</codeph> if the expression is
<codeph>FALSE</codeph>. Returns <codeph>FALSE</codeph> if the expression is
<codeph>TRUE</codeph> or <codeph>NULL</codeph>.
<p>
Same as the <codeph>IS FALSE</codeph> operator.
</p>
<p>
Similar to <codeph>ISNOTTRUE()</codeph>, except it returns the opposite value for a
<codeph>NULL</codeph> argument.
</p>
<p conref="../shared/impala_common.xml#common/return_type_boolean"/>
<p conref="../shared/impala_common.xml#common/added_in_220"/>
<p conref="../shared/impala_common.xml#common/usage_notes_blurb"/>
<p
conref="../shared/impala_common.xml#common/boolean_functions_vs_expressions"
/>
</dd>
</dlentry>
<dlentry id="isnotfalse" rev="2.2.0">
<dt>
ISNOTFALSE(BOOLEAN expression)
</dt>
<dd>
<b>Purpose:</b> Tests if a Boolean expression is not <codeph>FALSE</codeph> (that is,
either <codeph>TRUE</codeph> or <codeph>NULL</codeph>). Returns <codeph>TRUE</codeph>
if so. If the argument is <codeph>NULL</codeph>, returns <codeph>TRUE</codeph>.
<p>
Same as the <codeph>IS NOT FALSE</codeph> operator.
</p>
<p>
Similar to <codeph>ISTRUE()</codeph>, except it returns the opposite value for a
<codeph>NULL</codeph> argument.
</p>
<p
conref="../shared/impala_common.xml#common/return_type_boolean"/>
<p conref="../shared/impala_common.xml#common/for_compatibility_only"/>
<p conref="../shared/impala_common.xml#common/added_in_220"/>
<p conref="../shared/impala_common.xml#common/usage_notes_blurb"/>
<p
conref="../shared/impala_common.xml#common/boolean_functions_vs_expressions"
/>
</dd>
</dlentry>
<dlentry id="isnottrue" rev="2.2.0">
<dt>
ISNOTTRUE(BOOLEAN expression)
</dt>
<dd>
<b>Purpose:</b> Tests if a Boolean expression is not <codeph>TRUE</codeph> (that is,
either <codeph>FALSE</codeph> or <codeph>NULL</codeph>). Returns <codeph>TRUE</codeph>
if so. If the argument is <codeph>NULL</codeph>, returns <codeph>TRUE</codeph>.
<p>
Same as the <codeph>IS NOT TRUE</codeph> operator.
</p>
<p>
Similar to <codeph>ISFALSE()</codeph>, except it returns the opposite value for a
<codeph>NULL</codeph> argument.
</p>
<p
conref="../shared/impala_common.xml#common/return_type_boolean"/>
<p conref="../shared/impala_common.xml#common/added_in_220"/>
<p conref="../shared/impala_common.xml#common/usage_notes_blurb"/>
<p
conref="../shared/impala_common.xml#common/boolean_functions_vs_expressions"
/>
</dd>
</dlentry>
<dlentry id="isnull">
<dt>
ISNULL(type a, type ifNull)
</dt>
<dd>
<b>Purpose:</b> Tests if an expression is <codeph>NULL</codeph>, and returns the
expression result value if not. If the first argument is <codeph>NULL</codeph>,
returns the second argument.
<p>
<b>Compatibility notes:</b> Equivalent to the <codeph>NVL()</codeph> function from
Oracle Database or <codeph>IFNULL()</codeph> from MySQL. The <codeph>NVL()</codeph>
and <codeph>IFNULL()</codeph> functions are also available in Impala.
</p>
<p>
<b>Return type:</b> Same as the first argument value
</p>
</dd>
</dlentry>
<dlentry id="istrue" rev="2.2.0">
<dt>
ISTRUE(BOOLEAN expression)
</dt>
<dd>
<b>Purpose:</b> Returns <codeph>TRUE</codeph> if the expression is
<codeph>TRUE</codeph>. Returns <codeph>FALSE</codeph> if the expression is
<codeph>FALSE</codeph> or <codeph>NULL</codeph>.
<p>
Same as the <codeph>IS TRUE</codeph> operator.
</p>
<p>
Similar to <codeph>ISNOTFALSE()</codeph>, except it returns the opposite value for a
<codeph>NULL</codeph> argument.
</p>
<p conref="../shared/impala_common.xml#common/return_type_boolean"/>
<p conref="../shared/impala_common.xml#common/for_compatibility_only"/>
<p conref="../shared/impala_common.xml#common/added_in_220"/>
<p conref="../shared/impala_common.xml#common/usage_notes_blurb"/>
<p
conref="../shared/impala_common.xml#common/boolean_functions_vs_expressions"
/>
</dd>
</dlentry>
<dlentry id="nonnullvalue" rev="2.2.0">
<dt>
NONNULLVALUE(type expression)
</dt>
<dd>
<b>Purpose:</b> Returns <codeph>TRUE</codeph> if the expression is non-null and
returns <codeph>FALSE</codeph> if the expression is <codeph>NULL</codeph>.
<p>
Same as the <codeph>IS NOT NULL</codeph> operator.
</p>
<p>
The converse of <codeph>NULLVALUE()</codeph>.
</p>
<p
conref="../shared/impala_common.xml#common/return_type_boolean"/>
<p conref="../shared/impala_common.xml#common/for_compatibility_only"/>
<p conref="../shared/impala_common.xml#common/added_in_220"/>
</dd>
</dlentry>
<dlentry rev="1.3.0" id="nullif">
<dt>
NULLIF(type expr1, type expr2)
</dt>
<dd>
<b>Purpose:</b> Returns <codeph>NULL</codeph> if the two specified arguments are
equal. If the specified arguments are not equal, returns the value of
<varname>expr1</varname>. The data types of the expressions must be compatible,
according to the conversion rules from <xref href="impala_datatypes.xml#datatypes"/>.
You cannot use an expression that evaluates to <codeph>NULL</codeph> for
<varname>expr1</varname>; that way, you can distinguish a return value of
<codeph>NULL</codeph> from an argument value of <codeph>NULL</codeph>, which would
never match <varname>expr2</varname>.
<p>
<b>Usage notes:</b> This function is effectively shorthand for a
<codeph>CASE</codeph> expression of the form:
</p>
<codeblock>CASE
WHEN <varname>expr1</varname> = <varname>expr2</varname> THEN NULL
ELSE <varname>expr1</varname>
END</codeblock>
<p>
It is commonly used in division expressions, to produce a <codeph>NULL</codeph>
result instead of a divide-by-zero error when the divisor is equal to zero:
</p>
<codeblock>select 1.0 / nullif(c1,0) as reciprocal from t1;</codeblock>
<p>
You might also use it for compatibility with other database systems that support the
same <codeph>NULLIF()</codeph> function.
</p>
<p conref="../shared/impala_common.xml#common/return_same_type"/>
<p conref="../shared/impala_common.xml#common/added_in_130"/>
</dd>
</dlentry>
<dlentry rev="1.3.0" id="nullifzero">
<dt>
NULLIFZERO(type numeric_expr)
</dt>
<dd>
<b>Purpose:</b> Returns <codeph>NULL</codeph> if the numeric expression evaluates to
0, otherwise returns the result of the expression.
<p>
<b>Usage notes:</b> Used to avoid error conditions such as divide-by-zero in numeric
calculations. Serves as shorthand for a more elaborate <codeph>CASE</codeph>
expression, to simplify porting SQL with vendor extensions to Impala.
</p>
<p>
<b>Return type:</b> Same type as the input argument
</p>
<p conref="../shared/impala_common.xml#common/added_in_130"/>
</dd>
</dlentry>
<dlentry id="nullvalue" rev="2.2.0">
<dt>
NULLVALUE(type expression)
</dt>
<dd>
<b>Purpose:</b> Returns <codeph>TRUE</codeph> if the expression is
<codeph>NULL</codeph>, and returns <codeph>FALSE</codeph> otherwise.
<p>
Same as the <codeph>IS NULL</codeph> operator.
</p>
<p>
The converse of <codeph>NONNULLVALUE()</codeph>.
</p>
<p
conref="../shared/impala_common.xml#common/return_type_boolean"/>
<p conref="../shared/impala_common.xml#common/for_compatibility_only"/>
<p conref="../shared/impala_common.xml#common/added_in_220"/>
</dd>
</dlentry>
<dlentry id="nvl" rev="1.1">
<dt>
NVL(type a, type ifNull)
</dt>
<dd>
<b>Purpose:</b> Alias for the <codeph>ISNULL()</codeph> function. Returns the first
argument if the first argument is not <codeph>NULL</codeph>. Returns the second
argument if the first argument is <codeph>NULL</codeph>.
<p>
Equivalent to the <codeph>NVL()</codeph> function in Oracle Database or
<codeph>IFNULL()</codeph> in MySQL.
</p>
<p>
<b>Return type:</b> Same as the first argument value
</p>
<p conref="../shared/impala_common.xml#common/added_in_11"/>
</dd>
</dlentry>
<dlentry id="nvl2" rev="2.9.0 IMPALA-5030">
<dt>
NVL2(type a, type ifNotNull, type ifNull)
</dt>
<dd>
<b>Purpose:</b> Returns the second argument,
<codeph>ifNotNull</codeph>, if the first argument is not
<codeph>NULL</codeph>. Returns the third argument,
<codeph>ifNull</codeph>, if the first argument is
<codeph>NULL</codeph>. <p> Equivalent to the <codeph>NVL2()</codeph>
function in Oracle Database. </p>
<p>
<b>Return type:</b> Same as the first argument value </p>
<p conref="../shared/impala_common.xml#common/added_in_290"/>
<p conref="../shared/impala_common.xml#common/example_blurb"/>
<codeblock>
SELECT NVL2(NULL, 999, 0); -- Returns 0
SELECT NVL2('ABC', 'Is Not Null', 'Is Null'); -- Returns 'Is Not Null'</codeblock>
</dd>
</dlentry>
<dlentry rev="1.3.0" id="zeroifnull">
<dt>
ZEROIFNULL(type numeric_expr)
</dt>
<dd>
<b>Purpose:</b> Returns 0 if the numeric expression evaluates to
<codeph>NULL</codeph>, otherwise returns the result of the expression.
<p>
<b>Usage notes:</b> Used to avoid unexpected results due to unexpected propagation
of <codeph>NULL</codeph> values in numeric calculations. Serves as shorthand for a
more elaborate <codeph>CASE</codeph> expression, to simplify porting SQL with vendor
extensions to Impala.
</p>
<p>
<b>Return type:</b> Same type as the input argument
</p>
<p conref="../shared/impala_common.xml#common/added_in_130"/>
</dd>
</dlentry>
</dl>
</conbody>
</concept>