There seems to be a lot of confusion on newsgroups about NULLs and how they behave.
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
First create these 2 tables
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)
Now run these queries and you will understand why NOT IN should never be used
--We get back value 1 here
SELECT * FROM testjoin WHERE ID IN(SELECT ID FROM testnulls)
--Nothing is returned because testnulls contains NULL values
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
Counts are also tricky with NULLS
--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
The WHERE clause is also something that people have problems with
-- 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)
--Oops nothing is returned because NULL + anything else is always NULL
SELECT @SQL
Tuesday, May 22, 2007
NULL and SQL Problematic?
Posted by Denis at 8:11 AM
Labels: Null, SQL Server, SQL Server 2000, SQL Server 2005
Subscribe to:
Post Comments (Atom)
No comments:
Post a Comment