IsNull() not behaving as expected; IsNull() vs. Coalesce()

  • A strange behavior of the Isnull() function.

    I found a behavior with the IsNull() function that I cannot explain. I am starting to believe that I may have found a bug.

    If you run the piece of code found below, you would expect to see that the output of IsNull() and Coalesce() to be identical (especially the fields: [src_flag_coalesce] and [src_flag_isnull]).

    However if you look closely at the returned lines for [SupplierID] 3 and 4, you will see that the IsNull() function does not return "0" but "10"!

    After many tests to reproduce it i found it only happens in this situation where I am using nested select statements.

    If we are to take out the SRC select statement into a separate @Table and then use that table in the join then the Isnull() behaves as expected.

    Another interesting point is the behavior of the code on the case statement: I was expecting to see the word ERROR in the [Message] column.

    As anyone experienced this before?

    I tried this on SQL 2000 SP4 : it does not work. @@version = Microsoft SQL Server 2000 - 8.00.2055 (Intel X86)

    I tried it on a SQL 2005 : it does work. @@version = Microsoft SQL Server 2005 - 9.00.4035.00 (Intel X86)

    Thanks for your help.

    Greg

    SQL CODE:

    DECLARE @SRC_Supplier TABLE ( [AccountNo] [char](4) , [ApplicationCode] [char](4) )

    INSERT INTO @SRC_Supplier ( [AccountNo] ) VALUES ( 'ADD1' )

    INSERT INTO @SRC_Supplier ( [AccountNo] ) VALUES ( 'ADD2' )

    INSERT INTO @SRC_Supplier ( [AccountNo] ) VALUES ( 'EDT1' )

    INSERT INTO @SRC_Supplier ( [AccountNo] ) VALUES ( 'EDT2' )

    -- INSERT INTO @SRC_Supplier ( [AccountNo] ) VALUES ( 'DEL1' )

    -- INSERT INTO @SRC_Supplier ( [AccountNo] ) VALUES ( 'DEL2' )

    DECLARE @EXST_Supplier TABLE ( [SupplierID] [int] , [AccountNo] [char](4) )

    INSERT INTO @EXST_Supplier ( [SupplierID] , [AccountNo] ) VALUES ( 1 , 'EDT1' )

    INSERT INTO @EXST_Supplier ( [SupplierID] , [AccountNo] ) VALUES ( 2 , 'EDT2' )

    INSERT INTO @EXST_Supplier ( [SupplierID] , [AccountNo] ) VALUES ( 3 , 'DEL1' )

    INSERT INTO @EXST_Supplier ( [SupplierID] , [AccountNo] ) VALUES ( 4 , 'DEL2' )

    -- DECLARE @EXST_SupplierApp TABLE ( [SupplierAppID] [int] , [SupplierID] [int] , [ApplicationCode] [char](4) )

    --

    -- INSERT INTO @EXST_SupplierApp ( [SupplierAppID] , [SupplierID] , [ApplicationCode] ) VALUES ( 13 , 1 , 'EDT1' )

    -- INSERT INTO @EXST_SupplierApp ( [SupplierAppID] , [SupplierID] , [ApplicationCode] ) VALUES ( 14 , 2 , 'EDT2' )

    -- INSERT INTO @EXST_SupplierApp ( [SupplierAppID] , [SupplierID] , [ApplicationCode] ) VALUES ( 15 , 3 , 'DEL1' )

    -- INSERT INTO @EXST_SupplierApp ( [SupplierAppID] , [SupplierID] , [ApplicationCode] ) VALUES ( 16 , 4 , 'DEL2' )

    SELECT

    src.[SupplierID]AS [src_SupplierID]

    , src.[AccountNo]AS [src_AccountNo]

    , dst.[SupplierID]AS [dst_SupplierID]

    , dst.[AccountNo]AS [dst_AccountNo]

    , Coalesce(src.[_Flag], 0) + Coalesce(dst.[_Flag], 0)AS [ActionFlag]-- > 0 = Not in SRC & DST ; 10 = in SRC only ; 20 = in DST only ; 30 = in both SRC & DST

    , IsNull(src.[_Flag], 0) + IsNull(dst.[_Flag], 0)AS [ActionFlag2]-- > 0 = Not in SRC & DST ; 10 = in SRC only ; 20 = in DST only ; 30 = in both SRC & DST

    , Coalesce(src.[_Flag], 0)AS [src_flag_coalesce]

    , IsNull(src.[_Flag], 0)AS [src_flag_isnull]

    , Coalesce(dst.[_Flag], 0)AS [dst_flag_coalesce]

    , IsNull(dst.[_Flag], 0)AS [dst_flag_isnull]

    , Case

    When ( Coalesce(src.[_Flag], 0) ) <> ( IsNull(src.[_Flag], 0) ) Then 'Error'

    When ( Coalesce(dst.[_Flag], 0) ) <> ( IsNull(dst.[_Flag], 0) ) Then 'Error'

    Else ''

    EndAS [Message]

    FROM

    (

    SELECT

    t1.[_Flag]AS [_Flag]

    , t2.[SupplierID]AS [SupplierID]

    , t1.[AccountNo]AS [AccountNo]

    FROM

    (

    SELECT

    cast(10 as int)AS [_Flag]

    , [AccountNo]

    FROM

    @SRC_Supplier

    )t1

    left outer join @EXST_Suppliert2

    On(t2.[AccountNo] = t1.[AccountNo]

    )

    )src

    Full Outer Join

    (

    SELECT

    cast(20 as int)AS [_Flag]

    , [SupplierID]

    , [AccountNo]

    FROM

    @EXST_Supplier

    )dst

    On(

    dst.[SupplierID] = src.[SupplierID]

    )

    QUERY RESULT

    src_SupplierID src_AccountNo dst_SupplierID dst_AccountNo ActionFlag ActionFlag2 src_flag_coalesce src_flag_isnull dst_flag_coalesce dst_flag_isnull Message

    -------------- ------------- -------------- ------------- ----------- ----------- ----------------- --------------- ----------------- --------------- -------

    1 EDT1 1 EDT1 30 30 10 10 20 20

    2 EDT2 2 EDT2 30 30 10 10 20 20

    NULL NULL 3 DEL1 20 30 0 10 20 20

    NULL NULL 4 DEL2 20 30 0 10 20 20

    NULL ADD1 NULL NULL 10 10 10 10 0 0

    NULL ADD2 NULL NULL 10 10 10 10 0 0

  • I don't think that the problem is with ISNULL or COALESCE, but with the way the optimizer treats the data in the test table. At some point it decides that some values are constants:

    Try adding SET SHOWPLAN_ALL ON before running the query and you will get, for the Compute Scalar operation row, the following Argument value:

    DEFINE ([Expr1007]=If ([Expr1002]NULL) then [Expr1002] else 0+If ([Expr1006]NULL) then [Expr1006] else 0, [Expr1008]=isnull(10, 0)+isnull([Expr1006], 0), [Expr1009]=If ([Expr1002]NULL) then [Expr1002] else 0, [ConstExpr1022]=isnull(10, 0), [Expr1011]=If ([Expr1006]NULL) then [Expr1006] else 0, [Expr1012]=isnull([Expr1006], 0), [Expr1013]=If (If ([Expr1002]NULL) then [Expr1002] else 0isnull([Expr1002], 0)) then 'Error' else If (If ([Expr1006]NULL) then [Expr1006] else 0isnull([Expr1006], 0)) then 'Error' else '')

    You see that the optimizer decides that 10 is the value to use in the ISNULL function, not the value stored in the table.

    If you repeat the same in SQL2005 you never get into the constant.

    I don't understand why this happens, maybe someone with stronger skills may help diggind into this.

    Nice catch, anyway.

    Regards

    Gianluca

    Edited: code garbled by emoticons

    -- Gianluca Sartori

  • Thank you Gianluca for you help.

    A very intricate case scenario; I am now wondering how many of my DBs are affected.

    Greg

Viewing 3 posts - 1 through 2 (of 2 total)

You must be logged in to reply to this topic. Login to reply