Skip to Main Content

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, gary.

Asked: July 28, 2016 - 10:23 am UTC

Last updated: July 02, 2019 - 4:22 am UTC

Version: 11.2.0.4

Viewed 50K+ times! This question is

You Asked

hi
Why doesn't NULL_CASE2 return the same result as NULL_CASE1?

CREATE TABLE CASENULL (DUMMY VARCHAR(10))

INSERT INTO CASENULL VALUES (NULL);
INSERT INTO CASENULL VALUES ('X');

COMMIT;

SELECT NVL(DUMMY,'NULL') AS DUMMY,
CASE
WHEN DUMMY IS NULL
THEN 'Y'
ELSE 'N'
END AS NULL_CASE1,
CASE
DUMMY
WHEN NULL
THEN 'Y'
ELSE 'N'
END AS NULL_CASE2
FROM CASENULL

DUMMY NULL_CASE1 NULL_CASE2
NULL Y N
X N N


and Chris said...

For the same reason

when dummy = null then 'Y'


will never return Y.

case dummy when null then 'Y'

Checks whether dummy equals null. Not whether it "is null". Anything = null is never true.

Rating

  (1 rating)

Is this answer out of date? If it is, please let us know via a Comment

Comments

A reader, July 01, 2019 - 8:48 pm UTC

using

where
NVL(field, 'no') = case (field2 = '1') then 'other' (field2 = '2') then 'no';

validate null (true)

Connor McDonald
July 02, 2019 - 4:22 am UTC

True, but I generally try to steer clear of NVL when it comes to special values. You never know when that "special" value becomes a real one and your app silently breaks.

One nice thing with decode is:

decode(x,y,1,2)

will return 1 when x=y *including* when both are null