Conditional Expression Functions
Conditional Expression Functions
- coalesce(expr1, expr2, ..., exprn)
Returns the first of its arguments that are not null.
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.
- This value is replaced by the default value when data is displayed.
- 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 base_expr does not match each compare(n), 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.
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
gaussdb=# SELECT nullif(TRUE::BOOLEAN,'2012-12-24'::DATE); ERROR: operator does not exist: boolean = timestamp without time zone LINE 1: SELECT nullif(TRUE::BOOLEAN,'2012-12-24'::DATE) FROM sys_dummy; ^ HINT: No operator matches the given name and argument type(s). You might need to add explicit type casts.
- 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:
- nvl( expr1 , expr2 )
- 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)
Note: 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 data type of expr1 is returned. Otherwise, an error is returned.
- nvl2(expr1, expr2, expr3)
- 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:- If the value of any parameter is null, the function returns null.
- 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:- If the value of any parameter is null, the function returns null.
- 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); -- 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 but 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)
This function is valid only when a_format_version is set to 10c and a_format_dev_version is set to s2.
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot