8.9 Conditional Functions

8.9.1 COALESCE()

Available inDSQL, PSQL

Syntax

COALESCE (<exp1>, <exp2> [, <expN> ... ])

Table 8.9.1.1 COALESCE Function Parameters
ParameterDescription

exp1, exp2 …​ expN

A list of expressions of any compatible types

Result typeDepends on input.

DescriptionThe COALESCE function takes two or more arguments and returns the value of the first non-NULL argument. If all the arguments evaluate to NULL, the result is NULL.

ExampleThis example picks the Nickname from the Persons table. If it happens to be NULL, it goes on to FirstName. If that too is NULL, 'Mr./Mrs.' is used. Finally, it adds the family name. All in all, it tries to use the available data to compose a full name that is as informal as possible. Notice that this scheme only works if absent nicknames and first names are really NULL: if one of them is an empty string instead, COALESCE will happily return that to the caller.

select
  coalesce (Nickname, FirstName, 'Mr./Mrs.') || ' ' || LastName
    as FullName
from Persons

See alsoSection 8.9.3, IIF(), Section 8.9.6, NULLIF(), CASE

8.9.2 DECODE()

Available inDSQL, PSQL

Syntax

DECODE(<testexpr>,
  <expr1>, <result1>
  [<expr2>, <result2> …]
  [, <defaultresult>])

The equivalent CASE construct:

CASE <testexpr>
  WHEN <expr1> THEN <result1>
  [WHEN <expr2> THEN <result2> …]
  [ELSE <defaultresult>]
END
Table 8.9.2.1 DECODE Function Parameters
ParameterDescription

testexpr

An expression of any compatible type that is compared to the expressions expr1, expr2 …​ exprN

expr1, expr2, …​ exprN

Expressions of any compatible types, to which the testexpr expression is compared

result1, result2, …​ resultN

Returned values of any type

defaultresult

The expression to be returned if none of the conditions is met

Result typeVaries

DescriptionDECODE is a shorthand for the so-called simple CASE construct, in which a given expression is compared to a number of other expressions until a match is found. The result is determined by the value listed after the matching expression. If no match is found, the default result is returned, if present. Otherwise, NULL is returned.

⚠︎
Caution

Matching is done with the = operator, so if testexpr is NULL, it won’t match any of the exprs, not even those that are NULL.

Example

select name,
  age,
  decode(upper(sex),
         'M', 'Male',
         'F', 'Female',
         'Unknown'),
  religion
from people

See alsoCASE, Simple CASE

8.9.3 IIF()

Available inDSQL, PSQL

Syntax

IIF (<condition>, ResultT, ResultF)

Table 8.9.3.1 IIF Function Parameters
ParameterDescription

condition

A true|false expression

resultT

The value returned if the condition is true

resultF

The value returned if the condition is false

Result typeDepends on input.

DescriptionIIF takes three arguments. If the first evaluates to true, the second argument is returned; otherwise the third is returned.

  • IIF could be likened to the ternary ?: operator in C-like languages.

Example

select iif( sex = 'M', 'Sir', 'Madam' ) from Customers

🛈︎
Note

IIF(<Cond>, Result1, Result2) is a shorthand for CASE WHEN <Cond> THEN Result1 ELSE Result2 END.

See alsoCASE, Section 8.9.2, DECODE()

8.9.4 MAXVALUE()

Available inDSQL, PSQL

Syntax

MAXVALUE (<expr1> [, ... , <exprN> ])

Table 8.9.4.1 MAXVALUE Function Parameters
ParameterDescription

expr1 …​ exprN

List of expressions of compatible types

Result typeVaries according to input — result will be of the same data type as the first expression in the list (expr1).

DescriptionReturns the maximum value from a list of numerical, string, or date/time expressions. This function fully supports text BLOBs of any length and character set.

  • If one or more expressions resolve to NULL, MAXVALUE returns NULL. This behaviour differs from the aggregate function MAX.

Example

SELECT MAXVALUE(PRICE_1, PRICE_2) AS PRICE
  FROM PRICELIST

See alsoSection 8.9.5, MINVALUE()

8.9.5 MINVALUE()

Available inDSQL, PSQL

Syntax

MINVALUE (<expr1> [, ... , <exprN> ])

Table 8.9.5.1 MINVALUE Function Parameters
ParameterDescription

expr1 …​ exprN

List of expressions of compatible types

Result typeVaries according to input — result will be of the same data type as the first expression in the list (expr1).

DescriptionReturns the minimum value from a list of numerical, string, or date/time expressions. This function fully supports text BLOBs of any length and character set.

  • If one or more expressions resolve to NULL, MINVALUE returns NULL. This behaviour differs from the aggregate function MIN.

Example

SELECT MINVALUE(PRICE_1, PRICE_2) AS PRICE
  FROM PRICELIST

See alsoSection 8.9.4, MAXVALUE()

8.9.6 NULLIF()

Available inDSQL, PSQL

Syntax

NULLIF (<exp1>, <exp2>)

Table 8.9.6.1 NULLIF Function Parameters
ParameterDescription

exp1

An expression

exp2

Another expression of a data type compatible with exp1

DescriptionNULLIF returns the value of the first argument, unless it is equal to the second. In that case, NULL is returned.

Result typeDepends on input.

Example

select avg( nullif(Weight, -1) ) from FatPeople

This will return the average weight of the persons listed in FatPeople, excluding those having a weight of -1, since AVG skips NULL data. Presumably, -1 indicates weight unknown in this table. A plain AVG(Weight) would include the -1 weights, thus skewing the result.

See alsoSection 8.9.1, COALESCE(), Section 8.9.2, DECODE(), Section 8.9.3, IIF(), CASE