I am seeing a lot of searches for SQL + Nulls from this site so I decided to blog about it
Before I start I would like to point out that all the code will behave this way if ANSI_NULLS is set to on ,not to off
CREATE TABLE testnulls (ID INT)
INSERT INTO testnulls VALUES (1)
INSERT INTO testnulls VALUES (2)
INSERT INTO testnulls VALUES (null)
CREATE TABLE testjoin (ID INT)
INSERT INTO testjoin VALUES (1)
INSERT INTO testjoin VALUES (3)
--We get back value 1 here
SELECT * FROM testjoin WHERE ID IN(SELECT ID FROM testnulls)
--Nothing is returned
SELECT * FROM testjoin WHERE ID NOT IN(SELECT ID FROM testnulls)
--Value 3 is returned
SELECT * FROM testjoin WHERE ID NOT IN(SELECT ID FROM testnulls WHERE ID IS NOT NULL)
--value 3 is returned
SELECT * FROM testjoin j
WHERE NOT EXISTS (SELECT n.ID
FROM testnulls n
WHERE n.ID = j.ID)
--value 3 is returned
SELECT j.* FROM testjoin j
LEFT OUTER JOIN testnulls n ON n.ID = j.ID
WHERE n.ID IS NULL
--a count of 3 is returned
SELECT COUNT(*) FROM testnulls
-- a count of 2 is returned, the count ignores NULL values
SELECT COUNT(id) FROM testnulls
--By using coalesce the count is also 3
SELECT COUNT(COALESCE(id,0)) FROM testnulls
--all 3 rows are returned
SELECT * FROM testnulls
-- 1 row is returned
SELECT * FROM testnulls
WHERE ID = 1
-- only 1 row is returned the row with the NULL value is ignored
SELECT * FROM testnulls
WHERE ID <> 1
-- Now both rows that are not 1 are returned
SELECT * FROM testnulls
WHERE ID <>1
OR ID IS NULL
-- Now both rows that are not 1 are returned also
SELECT * FROM testnulls
WHERE COALESCE(ID,0) <> 1
Some more NULL Fun
You can''t compare NULL with anything
Since both values are unknown even a comparison with another NULL is unknown
DECLARE @v INT
DECLARE @v2 INT
SELECT @v =NULL,@v2 = NULL
IF @v = @v2
SELECT 'yes'
ELSE
SELECT 'No'
Be carefull with forgetting to initialize parameters while building string
DECLARE @SQL VARCHAR(500)
DECLARE @Id INT
SELECT @SQL = 'SELECT * FROM testnulls
WHERE ID =' + CONVERT(VARCHAR,@Id)
SELECT @SQL
3 comments:
I can understand why the "in" query returns 1, but, for the life of me, i can't seem to figure out why the "not in" query returns nothing. can you elaborate?
This is because SELECT ID FROM testnulls
returns at least one null
1
2
NULL
since you can't compare NULLs with anything (even themselves) it disregards the whole set. run this piece of code
if null = null
print 'yes'
else
print 'no'
as you will see no will be printed
if you did this
SELECT * FROM testjoin WHERE ID NOT IN(SELECT ID FROM testnulls where id is not null)
you would get back 3, the same would happen if you used NOT EXISTS or a LEFT JOIN
How about an IsNull? ;-)
SELECT ISNULL(ID, 0) FROM testnulls ORDER BY ID
Returns:
0
1
2
Post a Comment