Updated on 2024-06-03 GMT+08:00

Conditional Expression Functions

Conditional Expression Functions

  • coalesce(expr1, expr2, ..., exprn)

    Description:

    Returns the first non-NULL value in the parameter list.

    COALESCE(expr1, expr2) is equivalent to CASE WHEN expr1 IS NOT NULL THEN expr1 ELSE expr2 END.

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT coalesce(NULL,'hello');
     coalesce
    ----------
     hello
    (1 row)
    

    Note:

    • NULL is returned only if all parameters are NULL.
    • It is often used to replace NULL with the default value.
    • Like a CASE expression, COALESCE only evaluates the parameters that are needed to determine the result. That is, parameters to the right of the first non-NULL parameter are not evaluated.
  • decode(base_expr, compare1, value1, Compare2,value2, ... default)

    Description: Compares base_expr with each compare(n) and returns value(n) if they are matched. If no matching result is found, the default value is returned.

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT decode('A','A',1,'B',2,0);
     case
    ------
     1
    (1 row)
    

    Note: Operations on the XML data are not supported.

  • nullif(expr1, expr2)

    Description: Returns NULL only when expr1 is equal to expr2. Otherwise, expr1 is returned.

    nullif(expr1, expr2) is equivalent to CASE WHEN expr1 = expr2 THEN NULL ELSE expr1 END.

    The nullif(expr1, expr2) function is a mapping function. Therefore, the corresponding function definition cannot be found in the pg_proc system catalog.

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT nullif('hello','world');
     nullif 
    --------
     hello
    (1 row)
    

    Note: Operations on the XML data are not supported.

    Assume the two parameter data types are different:

    • If implicit conversion exists between the two data types, implicitly convert the parameter of lower priority to this data type using the data type of higher priority. If the conversion succeeds, computation is performed. Otherwise, an error is reported. Example:
      1
      2
      3
      4
      5
      gaussdb=# SELECT nullif('1234'::VARCHAR,123::INT4);
       nullif 
      --------
         1234
      (1 row)
      
      1
      2
      gaussdb=# SELECT nullif('1234'::VARCHAR,'2012-12-24'::DATE);
      ERROR:  invalid input syntax for type timestamp: "1234"
      
    • If implicit conversion is not applied between two data types, an error is displayed. Example:
      1
      2
      3
      4
      5
      6
      gaussdb=# SELECT nullif(1::bit, '1'::MONEY);
      ERROR:  operator does not exist: bit = money
      LINE 1: SELECT nullif(1::bit, '1'::MONEY);
                     ^
      HINT:  No operator matches the given name and argument type(s). You might need to add explicit type casts.
      CONTEXT:  referenced column: nullif
      
  • nvl( expr1 , expr2 )

    Description:

    • If the value of expr1 is NULL, the value of expr2 is returned.
    • If the value of expr1 is not NULL, the value of expr1 is returned.

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT nvl('hello','world');
      nvl  
    -------
     hello
    (1 row)
    

    Parameters expr1 and expr2 can be of any data type. If expr1 and expr2 are of different data types, NVL checks whether expr2 can be implicitly converted to expr1. If it can, the expr1 data type is returned. If epr2 cannot be implicitly converted to expr1 but epr1 can be implicitly converted to expr2, the expr2 data type is returned. If no implicit type conversion exists between the two parameters and the parameters are different data types, an error is reported.

  • nvl2(expr1, expr2, expr3)

    Description:

    • If expr1 is NULL, expr3 is returned.
    • If expr1 is not NULL, expr2 is returned.

      This function is valid only when a_format_version is set to 10c and a_format_dev_version is set to s1.

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT nvl2('hello','world','other');
      case  
    -------
     world
    (1 row)
    

    Note: The expr2 and expr3 parameters can be of any type. If the last two parameters of NVL2 are of different types, check whether expr3 can be implicitly converted to expr2. If expr3 cannot be implicitly converted to expr2, an error is returned. If the first parameter is of the numeric type, the function converts this parameter and other parameters to the numeric type, and then compares them. If the parameters cannot be converted, an error message is displayed. If the first parameter is of another type, the function converts other parameters to the type of the first parameter for comparison. If the parameters cannot be converted, an error message is displayed.

  • greatest(expr1 [, ...])

    Description: Selects the largest value from a list of any number of expressions.

    Return type:

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT greatest(1*2,2-3,4-1);
     greatest 
    ----------
            3
    (1 row)
    
    1
    2
    3
    4
    5
    gaussdb=# SELECT greatest('HARRY', 'HARRIOT', 'HAROLD');
     greatest 
    ----------
     HARRY
    (1 row)
    

    Note: Operations on the XML data are not supported.

    When a_format_version is set to 10c and a_format_dev_version is set to s1:

    1. If the value of any parameter is null, the function returns null.
    2. If the first parameter is of the numeric type, the function converts this parameter and other parameters to the numeric type, and then compares them. If the parameters cannot be converted, an error message is displayed. If the first parameter is of another type, the function converts other parameters to the type of the first parameter for comparison. If the parameters cannot be converted, an error message is displayed.
  • least(expr1 [, ...])

    Description: Selects the smallest value from a list of any number of expressions.

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT least(1*2,2-3,4-1);
     least 
    -------
        -1
    (1 row)
    
    1
    2
    3
    4
    5
    gaussdb=# SELECT least('HARRY','HARRIOT','HAROLD');
     least  
    --------
     HAROLD
    (1 row)
    

    Note: Operations on the XML data are not supported.

    When a_format_version is set to 10c and a_format_dev_version is set to s1:

    1. If the value of any parameter is null, the function returns null.
    2. If the first parameter is of the numeric type, the function converts this parameter and other parameters to the numeric type, and then compares them. If the parameters cannot be converted, an error message is displayed. If the first parameter is of another type, the function converts other parameters to the type of the first parameter for comparison. If the parameters cannot be converted, an error message is displayed.
  • EMPTY_BLOB()

    Description: Initiates a BLOB variable in an INSERT or an UPDATE statement to a NULL value.

    Return type: BLOB

    Example:

    1
    2
    3
    4
    5
    6
    -- Create a table.
    gaussdb=# CREATE TABLE blob_tb(b blob,id int) DISTRIBUTE BY REPLICATION;
    -- Insert data.
    gaussdb=# INSERT INTO blob_tb VALUES (empty_blob(),1);
    -- Drop the table.
    gaussdb=# DROP TABLE blob_tb;
    

    Note: The length is 0 obtained using DBE_LOB.GET_LENGTH.

  • EMPTY_CLOB()

    Description: Initiates a CLOB variable in an INSERT or UPDATE statement to a null value.

    This function is valid only when a_format_version is set to 10c and a_format_dev_version is set to s1.

    Return type: CLOB

    Example:

    1
    2
    3
    4
    5
    6
    -- Create a table.
    gaussdb=# CREATE TABLE clob_tb(c clob,id int);
    -- Insert data.
    gaussdb=# INSERT INTO clob_tb VALUES (empty_clob(),1);
    -- Drop the table.
    gaussdb=# DROP TABLE clob_tb;
    

    Note: The length is 0 obtained using DBE_LOB.GET_LENGTH.

  • lnnvl(condition)

    Description: Checks the condition in the WHERE clause of a query statement. If the condition is true, false is returned. If the condition is unknown or false, true is returned.

    condition: The value must be a logical expression. However, it cannot be used in composite conditions with keywords such as AND, OR, and BETWEEN.

    Return type: Boolean

    Example:

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    17
    18
    19
    -- Create a table.
    gaussdb=# CREATE TABLE student_demo (name VARCHAR2(20), grade  NUMBER(10,2));
    CREATE TABLE
    
    -- Insert data.
    gaussdb=# INSERT INTO student_demo VALUES ('name0',0);
    INSERT 0 1
    gaussdb=# INSERT INTO student_demo VALUES ('name1',1);
    INSERT 0 1
    gaussdb=# INSERT INTO student_demo VALUES ('name2',2);
    INSERT 0 1
    
    -- Invoke lnnvl.
    gaussdb=# SELECT * FROM student_demo WHERE LNNVL(name = 'name1');
     name  | grade 
    -------+-------
     name0 |  0.00
     name2 |  2.00
    (2 rows)
    

    The lnnvl function is supported only when the value of a_format_version is 10c and the value of a_format_dev_version is s2.

  • isnull(expr)

    Description: Checks whether expr is NULL. If expr is NULL, true is returned. Otherwise, false is returned. The isnull function is the mapping of the is null expression. isnull(expr) is equivalent to the expr is null expression. The isnull function is compatible in full mode.

    Parameter: Any type of input is supported.

    Return type: Boolean

    Example:

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    gaussdb=# SELECT isnull(null);
     ?column? 
    ----------
     t
    (1 row)
    
    gaussdb=# SELECT isnull(1);
     ?column? 
    ----------
     f
    (1 row)
    

    The isnull(expr) function is a mapping function. Therefore, the corresponding function definition cannot be found in the pg_proc system catalog.

  • if(expr1, expr2, expr3)

    Description: Checks the value of expr1. If expr1 is true, expr2 is returned. Otherwise, expr3 is returned.

    if(expr1, expr2, expr3) is logically equivalent to CASE WHEN expr1 THEN expr2 ELSE expr3 END.

    Parameters: See Table 1.

    Table 1 Parameter types

    Parameter

    Valid Input Parameter Type

    Description

    expr1

    boolean

    Determines the return value of the if() function.

    expr2

    Any type

    If expr1 is true, expr2 is returned.

    expr3

    Any type

    If expr1 is false, expr3 is returned.

    Return value type: related to the input parameter type. For details about the output rules, see the description.

    • if(expr1, expr2, expr3) is supported only in MySQL compatibility mode.
    • When the compatibility parameters b_format_version is set to '' and b_format_dev_version is set to '', the output result type of the if(expr1, expr2, expr3) function is the same as that of the CASE WHEN expr1 THEN expr2 ELSE expr3 END function. When the compatibility parameters b_format_version is set to '5.7' and b_format_dev_version is set to 's1', the return value type is deduced according to the following rules in descending order:
      • If the two input parameters are of the same type, the return value type is the same as the input parameter type.
      • If one of the input parameters is of the SET type, the return value is of the TEXT type.
      • If one of the input parameters is of the BLOB type, the return value is of the BLOB type.
      • If one of the input parameters is of the TEXT type, the return value is of the TEXT type.
      • If one of the input parameters is of the STRING type, the return value is of the TEXT type.
      • If the two input parameters are of the time type, the return value is of the TIMESTAMPTZ type; if one of the input parameters is of the time type but the other is not, the return value is of the TEXT type.
      • If both input parameters are signed integers and one input parameter is of the BIGINT type, the return value is of the BIGINT type; otherwise, the return value is of the INT type.
      • If both input parameters are unsigned integers and one input parameter is of the UNSIGNED BIGINT type, the return value is of the UNSIGNED BIGINT type; otherwise, the return value is of the UNSIGNED INT type.
      • If the two input parameters are of the floating point type and integer type respectively, the return value is of the floating point type.
      • Except the preceding NUMERIC type combinations, the return value for other NUMERIC type combinations is of the NUMERIC type.
      • If no implicit conversion function exists between the input parameter type and return value type, an error is reported.
    • If the input parameter expr1 is NULL, the returned result is the same as that when expr1 is FALSE.
    • The if(expr1, expr2, expr3) function is a mapping function. Therefore, the corresponding function definition cannot be found in the pg_proc system catalog.

    Example:

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    -- expr1 is an expression.
    gaussdb=# select if(2>3, 'true', 'false');
     case
    -------
     false
    (1 row)
    
    -- If the input parameter expr1 is NULL, the result is the same as that when expr1 is false, and the value of expr2 is returned.
    gaussdb=# select if(null, 'not null', 'is null');
      case
    ---------
     is null
    (1 row)
    
  • ifnull(expr1, expr2)

    Description: Returns the value of expr2 if expr1 is NULL; otherwise, returns the value of expr1.

    ifnull(expr1, expr2) is logically equivalent to nvl(expr1, expr2).

    Parameter: any type.

    Return value type: related to the input parameter type. For details about the output rules, see the description.

    • ifnull(expr1, expr2) is supported only in MySQL compatibility mode.
    • When the compatibility parameters b_format_version is set to '' and b_format_dev_version is set to '', the output result type of the ifnull(expr1, expr2) function is the same as that of the nvl(expr1, expr2) function. When the compatibility parameters b_format_version is set to '5.7' and b_format_dev_version is set to 's1', the return value type is deduced according to the following rules in descending order:
      • If the two input parameters are of the same type, the return value type is the same as the input parameter type.
      • If one of the input parameters is of the SET type, the return value is of the TEXT type.
      • If one of the input parameters is of the BLOB type, the return value is of the BLOB type.
      • If one of the input parameters is of the TEXT type, the return value is of the TEXT type.
      • If one of the input parameters is of the STRING type, the return value is of the TEXT type.
      • If the two input parameters are of the time type, the return value is of the TIMESTAMPTZ type; if one of the input parameters is of the time type but the other is not, the return value is of the TEXT type.
      • If one input parameter is of the FLOAT4 type and the other is of any numeric type, the return type is DOUBLE.
      • If both input parameters are of the NUMERIC type, the return value is of the type with higher precision. For example, if the input parameter types are TINYINT and INT, the return value type is INT.
      • If no implicit conversion function exists between the input parameter type and return value type, an error is reported.
    • If both input parameters are NULL, the return value is NULL; otherwise, the first value that is not NULL is returned.
    • The ifnull(expr1, expr2) function is a mapping function. Therefore, the corresponding function definition cannot be found in the pg_proc system catalog.

    Example:

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    17
    18
    19
    20
    -- If the input parameter is an empty string, the output is an empty string instead of NULL.
    gaussdb=# SELECT ifnull('', null) is null as a;
     a
    ---
     f
    (1 row)
    
    -- If both input parameters are NULL, the output is NULL.
    gaussdb=# SELECT ifnull(null, null) is null as a;
     a
    ---
     t
    (1 row)
    
    -- If the input parameters are NULL and a character string, the output is the first non-null value.
    gaussdb=# SELECT ifnull(null, 'A') as a;
     a
    ---
     A
    (1 row)