DECODE scalar function

The DECODE function does equality comparisons between arguments, also treating null values as equal, to determine which argument to return as the result.

Read syntax diagramSkip visual syntax diagramDECODE(expression1 ,expression2,result-expression ,else-expression )

The schema is SYSIBM.

The DECODE function compares each expression2 to expression1. If expression1 is equal to expression2, or both expression1 and expression2 are null, the value of the following result-expresssion is returned. If no expression2 matches expression1, the value of else-expression is returned; otherwise a null value is returned.

The DECODE function is similar to the CASE expression except for the handling of null values:
  • A null value of expression1 will match a corresponding null value of expression2.
  • If the NULL keyword is used as an argument in the DECODE function, it must be cast to an appropriate data type.
The rules for determining the result type of a DECODE expression are based on the corresponding CASE expression.

Examples

  • Example 1: The DECODE expression:
       DECODE (c1, 7, 'a', 6, 'b', 'c')
    achieves the same result as the following CASE expression:
       CASE c1
         WHEN 7 THEN 'a'
         WHEN 6 THEN 'b'
         ELSE 'c'
       END
  • Example 2: The DECODE expression:
       DECODE (c1, var1, 'a', var2, 'b')
    where the values of c1, var1, and var2 could be null values, achieves the same result as the following CASE expression:
       CASE
         WHEN c1 = var1 OR (c1 IS NULL AND var1 IS NULL) THEN 'a'
         WHEN c1 = var2 OR (c1 IS NULL AND var2 IS NULL) THEN 'b'
         ELSE NULL
       END
  • Example 3: Consider also the following query:
       SELECT ID, DECODE(STATUS, 'A', 'Accepted',
                                 'D', 'Denied',
                                 CAST(NULL AS VARCHAR(1)), 'Unknown',
                                 'Other')
       FROM CONTRACTS
    Here is the same statement using a CASE expression:
       SELECT ID,
         CASE
           WHEN STATUS = 'A' THEN 'Accepted'
           WHEN STATUS = 'D' THEN 'Denied'
           WHEN STATUS IS NULL THEN 'Unknown'
           ELSE 'Other'
         END
       FROM CONTRACTS