Impala Conditional Functions
Impala supports the following conditional functions for testing equality, comparison operators, and nullity:
-
CASE a WHEN b THEN c [WHEN d THEN e]... [ELSE f] END
-
Purpose: Compares an expression to one or more possible values, and returns a corresponding result
when a match is found.
Return type: same as the initial argument value, except that integer values are promoted to
BIGINT
and floating-point values are promoted toDOUBLE
; useCAST()
when inserting into a smaller numeric columnUsage notes:
In this form of the
CASE
expression, the initial valueA
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 asBETWEEN
orIN
, regular expressions, orNULL
.Examples:
Although this example is split across multiple lines, you can put any or all parts of a
CASE
expression on a single line, with no punctuation or other separators between theWHEN
,ELSE
, andEND
clauses.select case x when 1 then 'one' when 2 then 'two' when 0 then 'zero' else 'out of range' end from t1;
-
CASE WHEN a THEN b [WHEN c THEN d]... [ELSE e] END
-
Purpose: Tests whether any of a sequence of expressions is true, and returns a corresponding
result for the first true expression.
Return type: same as the initial argument value, except that integer values are promoted to
BIGINT
and floating-point values are promoted toDOUBLE
; useCAST()
when inserting into a smaller numeric columnUsage notes:
CASE
expressions without an initial test value have more flexibility. For example, they can test different columns in differentWHEN
clauses, or use comparison operators such asBETWEEN
,IN
andIS NULL
rather than comparing against discrete values.CASE
expressions are often the foundation of long queries that summarize and format results for easy-to-read reports. For example, you might use aCASE
function call to turn values from a numeric column into category strings corresponding to integer values, or labels such as "Small", "Medium" and "Large" 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 useCASE
to signal problems with out-of-bounds values,NULL
values, and so on.By using operators such as
OR
,IN
,REGEXP
, and so on inCASE
expressions, you can build extensive tests and transformations into a single query. Therefore, applications that construct SQL statements often rely heavily onCASE
calls in the generated SQL code.Because this flexible form of the
CASE
expressions allows you to perform many comparisons and call multiple functions when evaluating each row, be careful applying elaborateCASE
expressions to queries that process large amounts of data. For example, when practical, evaluate and transform values throughCASE
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.Examples:
Although this example is split across multiple lines, you can put any or all parts of a
CASE
expression on a single line, with no punctuation or other separators between theWHEN
,ELSE
, andEND
clauses.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;
-
coalesce(type v1, type v2, ...)
-
Purpose: Returns the first specified argument that is not
NULL
, orNULL
if all arguments areNULL
.Return type: same as the initial argument value, except that integer values are promoted to
BIGINT
and floating-point values are promoted toDOUBLE
; useCAST()
when inserting into a smaller numeric column -
decode(type expression, type search1, type result1 [, type search2, type result2 ...] [, type default] )
-
Purpose: Compares an expression to one or more possible values, and returns a corresponding result
when a match is found.
Return type: same as the initial argument value, except that integer values are promoted to
BIGINT
and floating-point values are promoted toDOUBLE
; useCAST()
when inserting into a smaller numeric columnUsage notes:
Can be used as shorthand for a
CASE
expression.The original expression and the search expressions must of the same type or convertible types. The result expression can be a different type, but all result expressions must be of the same type.
Returns a successful match If the original expression is
NULL
and a search expression is alsoNULL
. theReturns
NULL
if the finaldefault
value is omitted and none of the search expressions match the original expression.Examples:
The following example translates numeric day values into descriptive names:
SELECT event, decode(day_of_week, 1, "Monday", 2, "Tuesday", 3, "Wednesday", 4, "Thursday", 5, "Friday", 6, "Saturday", 7, "Sunday", "Unknown day") FROM calendar;
-
if(boolean condition, type ifTrue, type ifFalseOrNull)
-
Purpose: Tests an expression and returns a corresponding result depending on whether the result is
true, false, or
NULL
.Return type: Same as the
ifTrue
argument value -
ifnull(type a, type ifNull)
-
Purpose: Alias for the
isnull()
function, with the same behavior. To simplify porting SQL with vendor extensions to Impala.Added in: Impala 1.3.0
-
isfalse(boolean)
-
Purpose: Tests if a Boolean expression is
false
or not. Returnstrue
if so. If the argument isNULL
, returnsfalse
. Identical toisnottrue()
, except it returns the opposite value for aNULL
argument.Return type:
BOOLEAN
Added in: Impala 2.2.0
Usage notes:
In Impala 2.11 and higher, you can use the operators
IS [NOT] TRUE
andIS [NOT] FALSE
as equivalents for the built-in functionsistrue()
,isnottrue()
,isfalse()
, andisnotfalse()
. -
isnotfalse(boolean)
-
Purpose: Tests if a Boolean expression is not
false
(that is, eithertrue
orNULL
). Returnstrue
if so. If the argument isNULL
, returnstrue
. Identical toistrue()
, except it returns the opposite value for aNULL
argument.Return type:
BOOLEAN
Usage notes: Primarily for compatibility with code containing industry extensions to SQL.
Added in: Impala 2.2.0
Usage notes:
In Impala 2.11 and higher, you can use the operators
IS [NOT] TRUE
andIS [NOT] FALSE
as equivalents for the built-in functionsistrue()
,isnottrue()
,isfalse()
, andisnotfalse()
. -
isnottrue(boolean)
-
Purpose: Tests if a Boolean expression is not
true
(that is, eitherfalse
orNULL
). Returnstrue
if so. If the argument isNULL
, returnstrue
. Identical toisfalse()
, except it returns the opposite value for aNULL
argument.Return type:
BOOLEAN
Added in: Impala 2.2.0
Usage notes:
In Impala 2.11 and higher, you can use the operators
IS [NOT] TRUE
andIS [NOT] FALSE
as equivalents for the built-in functionsistrue()
,isnottrue()
,isfalse()
, andisnotfalse()
. -
isnull(type a, type ifNull)
-
Purpose: Tests if an expression is
NULL
, and returns the expression result value if not. If the first argument isNULL
, returns the second argument.Compatibility notes: Equivalent to the
nvl()
function from Oracle Database orifnull()
from MySQL. Thenvl()
andifnull()
functions are also available in Impala.Return type: Same as the first argument value
-
istrue(boolean)
-
Purpose: Tests if a Boolean expression is
true
or not. Returnstrue
if so. If the argument isNULL
, returnsfalse
. Identical toisnotfalse()
, except it returns the opposite value for aNULL
argument.Return type:
BOOLEAN
Usage notes: Primarily for compatibility with code containing industry extensions to SQL.
Added in: Impala 2.2.0
Usage notes:
In Impala 2.11 and higher, you can use the operators
IS [NOT] TRUE
andIS [NOT] FALSE
as equivalents for the built-in functionsistrue()
,isnottrue()
,isfalse()
, andisnotfalse()
. -
nonnullvalue(expression)
-
Purpose: Tests if an expression (of any type) is
NULL
or not. Returnsfalse
if so. The converse ofnullvalue()
.Return type:
BOOLEAN
Usage notes: Primarily for compatibility with code containing industry extensions to SQL.
Added in: Impala 2.2.0
-
nullif(expr1,expr2)
-
Purpose: Returns
NULL
if the two specified arguments are equal. If the specified arguments are not equal, returns the value of expr1. The data types of the expressions must be compatible, according to the conversion rules from Data Types. You cannot use an expression that evaluates toNULL
for expr1; that way, you can distinguish a return value ofNULL
from an argument value ofNULL
, which would never match expr2.Usage notes: This function is effectively shorthand for a
CASE
expression of the form:CASE WHEN expr1 = expr2 THEN NULL ELSE expr1 END
It is commonly used in division expressions, to produce a
NULL
result instead of a divide-by-zero error when the divisor is equal to zero:select 1.0 / nullif(c1,0) as reciprocal from t1;
You might also use it for compatibility with other database systems that support the same
NULLIF()
function.Return type: same as the initial argument value, except that integer values are promoted to
BIGINT
and floating-point values are promoted toDOUBLE
; useCAST()
when inserting into a smaller numeric columnAdded in: Impala 1.3.0
-
nullifzero(numeric_expr)
-
Purpose: Returns
NULL
if the numeric expression evaluates to 0, otherwise returns the result of the expression.Usage notes: Used to avoid error conditions such as divide-by-zero in numeric calculations. Serves as shorthand for a more elaborate
CASE
expression, to simplify porting SQL with vendor extensions to Impala.Return type: same as the initial argument value, except that integer values are promoted to
BIGINT
and floating-point values are promoted toDOUBLE
; useCAST()
when inserting into a smaller numeric columnAdded in: Impala 1.3.0
-
nullvalue(expression)
-
Purpose: Tests if an expression (of any type) is
NULL
or not. Returnstrue
if so. The converse ofnonnullvalue()
.Return type:
BOOLEAN
Usage notes: Primarily for compatibility with code containing industry extensions to SQL.
Added in: Impala 2.2.0
-
nvl(type a, type ifNull)
-
Purpose: Alias for the
isnull()
function. Tests if an expression isNULL
, and returns the expression result value if not. If the first argument isNULL
, returns the second argument. Equivalent to thenvl()
function from Oracle Database orifnull()
from MySQL.Return type: Same as the first argument value
Added in: Impala 1.1
-
nvl2(type a, type ifNull, type ifNotNull)
-
Purpose: Enhanced variant of the
nvl()
function. Tests an expression and returns different result values depending on whether it isNULL
or not. If the first argument isNULL
, returns the second argument. If the first argument is notNULL
, returns the third argument. Equivalent to thenvl2()
function from Oracle Database.Return type: Same as the first argument value
Added in: Impala 2.9.0
Examples:
The following examples show how a query can use special indicator values to represent null and not-null expression values. The first example tests an
INT
column and so uses special integer values. The second example tests aSTRING
column and so uses special string values.select x, nvl2(x, 999, 0) from nvl2_demo; +------+---------------------------+ | x | if(x is not null, 999, 0) | +------+---------------------------+ | NULL | 0 | | 1 | 999 | | NULL | 0 | | 2 | 999 | +------+---------------------------+ select s, nvl2(s, 'is not null', 'is null') from nvl2_demo; +------+---------------------------------------------+ | s | if(s is not null, 'is not null', 'is null') | +------+---------------------------------------------+ | NULL | is null | | one | is not null | | NULL | is null | | two | is not null | +------+---------------------------------------------+
-
zeroifnull(numeric_expr)
-
Purpose: Returns 0 if the numeric expression evaluates to
NULL
, otherwise returns the result of the expression.Usage notes: Used to avoid unexpected results due to unexpected propagation of
NULL
values in numeric calculations. Serves as shorthand for a more elaborateCASE
expression, to simplify porting SQL with vendor extensions to Impala.Return type: same as the initial argument value, except that integer values are promoted to
BIGINT
and floating-point values are promoted toDOUBLE
; useCAST()
when inserting into a smaller numeric columnAdded in: Impala 1.3.0