ACE Director Alum Daniel Morgan, founder of Morgan's Library, is scheduling
complimentary technical Workshops on Database Security for the first 30
Oracle Database customers located anywhere in North America, EMEA, LATAM, or
APAC that send an email to
asra_us@oracle.com. Request a Workshop for
your organization today.
Purpose
NOTE: Null In Oracle is an absence of information. A null can be assigned but it can not be equated with anything: Even itself.
While this behavior is ANSI compliant it is not similar to the behavior in many other commercial RDBMS products.
New in 21c
As of version 21c IS NULL and IS NOT NULL support
the new JSON data type.
Equality with NULL
A simple SELECT statement to use for demonstrating the properties of NULL
SELECT COUNT(*)
FROM all_tables
WHERE 1 = 1;
A NULL is not equal to a NULL
SELECT COUNT(*)
FROM all_tables
WHERE NULL = NULL;
A NULL cannot be not equal to a NULL
SELECT COUNT(*)
FROM all_tables
WHERE NULL <> NULL;
A NULL is does not equal an empty string
SELECT COUNT(*)
FROM all_tables
WHERE NULL = '';
A NULL can be used in an INSERT
conn uwclass/uwclass@pdbdev
CREATE TABLE test (
test1 NUMBER(10),
test2 VARCHAR2(20));
INSERT INTO test
(test1, test2)
VALUES
(1, NULL);
INSERT INTO test
(test1, test2)
VALUES
(NULL, 'A');
SELECT *
FROM test;
NULL is a state of being that can be interrogated as to whether it does or does not exist.
A simple SELECT based on a column with a NULL
SELECT *
FROM test
WHERE test1 IS NULL;
SELECT *
FROM test
WHERE test1 IS NOT NULL;
A NULL can be used in an UPDATE
UPDATE test
SET test1 = '2'
WHERE test2 IS NULL;
SELECT *
FROM test;
UPDATE test
SET test2 = 'B'
WHERE test2 IS NOT NULL;
SELECT *
FROM test;
A column can be updated to not contain a value
UPDATE test
SET test1 = NULL
WHERE ROWNUM = 1;
SELECT *
FROM test;
NULL can be used as part of the WHERE clause criteria in a DELETE statement
DELETE FROM test
WHERE test1 IS NULL;
SELECT *
FROM test;
Understand the implications of NULL
conn uwclass/uwclass@pdbdev
CREATE TABLE t (
col1 NUMBER(3),
col2 NUMBER(3),
col3 NUMBER(3));
desc t
INSERT INTO t
(col1, col2, col3)
VALUES
(1, NULL, NULL);
INSERT INTO t
(col1, col2, col3)
VALUES
(NULL, 2, NULL);
INSERT INTO t
(col1, col2, col3)
VALUES
(NULL, NULL, 3);
INSERT INTO t
(col1, col2, col3)
VALUES
(4, 4, 4);
COMMIT;
SELECT *
FROM t;
SELECT SUM(RESULT_TMP) RESULT
FROM (
SELECT col1 - (col2 + col3) RESULT_TMP
FROM t);
SELECT SUM(col1) - (SUM(col2) + SUM(col3)) RESULT
FROM t;
Note: For any row that has one of the values null, the entire row sums to null and is not included in the second query but the other columns in the row contribute to the sums in the query.
So the first query includes more terms than the second.