The art of doing mathematics consists in finding that special case which contains all the germs of generality.
David Hilbert
One of the most mindboggling values in the Oracle database is the NULL value. What is NULL? NULL is nothing. NULL is not even the same as NULL. NULL is undefined. But you need to work with NULL values (which are no actual values). Luckily Oracle provides us with a couple of functions to do the heavy lifting when it comes to checking for NULLs.
IS [NOT] NULL
Syntax:
1 |
expr1 IS [NOT] NULL |
This predicate returns rows from the table where the column value for expr1 contains (or
doesn’t contain) a NULL value.
EMPNO | ENAME | JOB | SAL | COMM | |
1 | 7876 | ADAMS | CLERK | 1100.00 | |
2 | 7499 | ALLEN | SALESMAN | 1600.00 | 300.00 |
3 | 7839 | KING | PRESIDENT | 5000.00 | |
4 | 7654 | MARTIN | SALESMAN | 1250.00 | 1400.00 |
5 | 7369 | SMITH | CLERK | 800.00 | |
6 | 7844 | TURNER | SALESMAN | 1500.00 | 0.00 |
If you want to see all the employees with no commission filled in you can issue a statement like this:
1 2 3 |
SELECT * FROM emp t WHERE t.comm IS NULL; |
EMPNO | ENAME | JOB | SAL | COMM | |
1 | 7876 | ADAMS | CLERK | 1100.00 | |
2 | 7839 | KING | PRESIDENT | 5000.00 | |
3 | 7369 | SMITH | CLERK | 800.00 |
Alternatively you can find the employees with a value in the commission column like this:
1 2 3 |
SELECT * FROM emp t WHERE t.comm IS NOT NULL; |
EMPNO | ENAME | JOB | SAL | COMM | |
2 | 7499 | ALLEN | SALESMAN | 1600.00 | 300.00 |
4 | 7654 | MARTIN | SALESMAN | 1250.00 | 1400.00 |
6 | 7844 | TURNER | SALESMAN | 1500.00 | 0.00 |
Notice NULL is not the same as 0 (zero). NULL is not even the same as NULL. NULL = NULL results in FALSE where NULL IS NULL results in TRUE
NVL
Syntax:
1 |
NVL(expr1, expr2) |
If expr1 contains a NULL value, then replace it with the value of expr2
The NVL function lets you substitute a value when a null value is encountered.
Examples:
NVL(‘A’,’B’) results in A
NVL(NULL,’B’) results in B
NVL(1,2) results in 1
NVL(NULL,2) results in 2
NVL(‘A’,2) results in A
NVL(1, ‘B’) results in an error
The last example results in an error because ‘B’ cannot be converted to a number. In the
one before it, it was possible to convert 2 to a varchar2 value.
NVL2
Syntax:
1 |
NVL2(expr1, expr2, expr3) |
If expr1 contains a NULL value, then return expr3. If the value of expr1 contains a non-NULL
value, then return expr2.
Examples:
NVL2(‘A’,’B’,’C’) results in B
NVL2(NULL,’B’,’C’) results in C
NVL2(1,2,3) results in 2
NVL2(NULL,2,3) results in 3
NULLIF
Syntax:
1 |
NULLIF(expr1, expr2) |
NULLIF returns NULL if expr1 is equal to expr2. If they are not equal expr1 is returned.
Expressions must be of the same data type, There is no implicit conversion performed.
Examples:
NULLIF(‘A’,’B’) results in A
NULLIF(‘A’,’A’) results in NULL
NULLIF(2,3) results in 2
NULLIF(2,2) results in NULL
NULLIF(‘2’,2) results in an error
NULLIF(2,’2’) results in an error
COALESCE
Syntax:
1 |
COALESCE(expr [, expr ]...) |
The coalesce function returns the first non-NULL value of the expressions in the list. The list
must consist of at least 2 values. If all expressions evaluate to NULL then NULL is returned.
Examples:
COALESCE(‘A’,’B’,’C’) results in A
COALESCE(NULL,’B’,’C’) results in B
COALESCE(NULL,NULL,’C’) results in C
COALESCE(NULL,’B’,NULL) results in B
COALESCE(‘A’) results in an error
LNNVL
Syntax:
1 |
LNNVL(condition) |
The LNNVL function is used in the WHERE clause of an SQL statement when one of the
operands may contain a NULL value. The function returns TRUE is the result of the
condition is FALSE and FALSE is the result of the condition is TRUE or UNKNOWN. LNNVL
can be used in a condition when you would otherwise need to combine a condition with an
IS [NOT] NULL or an NVL predicate.
The following queries have the same result:
1 2 3 4 5 6 7 |
SELECT * FROM emp e WHERE LNNVL(e.comm >= 100); SELECT * FROM emp e WHERE 1 = 1 AND ((e.comm |
Note that the condition must be inverted when using the LNNVL function.
DEFAULTS
When a column in a table is defined there is the possibility to have a default value for this column whenever it is inserted without a value.
1 2 3 4 |
create table def ( code number , value varchar2(30) default 'Empty' ) |
This is done on insert only. You can still update the column to be NULL (or insert a NULL value) when by supplying an explicit NULL value.
1 2 3 4 5 |
insert into def (code) values (10) select * from def insert into def (code, value) values (15, NULL) update def set value = null where code = 10 select * from def |
If you modify the default during the life of the table, the new default will be applied from that
moment on.
1 2 |
alter table DEF modify value default 'Really empty'; insert into def (code) values (20) |
Now how do you make sure a default is applied to columns already NULL? You can do this
by using the keyword DEFAULT.
1 2 |
update def set value = default where value is null select * from def |
DECODE
Syntax:
1 |
DECODE(expr, search, result [, search, result ]... [, default ]) |
Using DECODE you can the value of a column (or any expression) to decide what to return. It can for instance be used to build a decision table. Consider the following decision table:
Code | Value |
1 | Red |
2 | White |
3 | Blue |
4 | Yellow |
The column in our table just holds the code instead of the value. If we want to represent the value instead of the code we could write a query like this:
1 2 |
SELECT decode(color, 1, 'Red', 2, 'White', 3, 'Blue', 4, 'Yellow') FROM table; |
CASE
Syntax:
1 2 3 4 5 6 7 8 9 10 11 12 |
CASE { simple_case_expression | searched_case_expression } [ else_clause ] END simple_case_expression expr { WHEN comparison_expr THEN return_expr }... searched_case_expression { WHEN condition THEN return_expr }... else_clause ELSE else_expr |
The case statement has two flavors. The simple case and the searched case. In the simple case the expression is written only once and depending on the result of this expression one of the possible cases is being used. This can be helpful when you need to choose from a set of distinct values. In the searched case every case has its own expression. This can for instance be helpful when using ranges.
The same query as above can be written using a simple case expression.
1 2 3 4 5 6 7 8 |
SELECT CASE color WHEN 1 THEN 'Red' WHEN 2 THEN 'White' WHEN 3 THEN 'Blue' WHEN 4 THEN 'Yellow' ELSE 'Unknown' END color FROM table; |
The query can also be written using a searched case expression:
1 2 3 4 5 6 7 |
SELECT CASE WHEN color=1 THEN 'Red' WHEN color=2 THEN 'White' WHEN color=3 THEN 'Blue' WHEN color=4 THEN 'Yellow' END color FROM table; |
The else clause is optional. If none of the cases is valid for the expression, then NULL is
returned, as opposed to PL/SQL where an error is raised.
Conclusion
NULL values are one of the most mind-boggling values in the Oracle database. Luckily Oracle provides us with a lot of functionality to work with NULLs. The newer versions of the database also provide us with functionality to make your SQL (and PL/SQL) code more readable, for instance the CASE keyword which can replace the DECODE keyword and has more possibilities as well.
ref:
http://oracleworldblog.blogspot.nl/2009/10/oracle-null-functions.html
http://docs.oracle.com/cd/B19306_01/server.102/b14200/functions105.htm
http://docs.oracle.com/database/122/SQLRF/NVL2.htm#SQLRF00685
http://docs.oracle.com/database/122/SQLRF/NULLIF.htm#SQLRF00681
http://docs.oracle.com/database/122/SQLRF/COALESCE.htm#SQLRF00617
http://docs.oracle.com/database/122/SQLRF/LNNVL.htm#SQLRF06327
http://docs.oracle.com/database/122/SQLRF/DECODE.htm#SQLRF00631
http://docs.oracle.com/database/122/LNPLS/plsql-language-fundamentals.htm#LNPLS278
Load comments