Working with NULLS

Collapse
This topic is closed.
X
X
 
  • Time
  • Show
Clear All
new posts
  • rcamarda

    Working with NULLS

    I have a field that may be null which is valid, and I am finding
    something I didnt expect when working with nulls.
    SELECT NULL/4.0 will return NULL (which I expect), however, when I test
    it with a case it does not:

    SELECT NULL/4.0 AS 'TEST1', TEST2 = CASE NULL/4.0 WHEN NULL THEN
    'HURAY' ELSE 'OH DARN' END

    I can work around by testing for NULL first else CASE ..., but I'd like
    to understand why the CASE does not test for null.
    TIA
    rob
    SQL 2005 Enterprise x64, SP1

  • Mike C#

    #2
    Re: Working with NULLS

    Use a searched CASE expression with IS NULL. The way you're doing it is
    effectively doint the comparison NULL/4.0 = NULL, which evaluates to
    UNKNOWN, which means your CASE will drop through to the next WHEN (or the
    ELSE in this case). NULL comparisons need to use IS NULL or IS NOT NULL.

    SELECT NULL/4.0 AS 'TEST1', TEST2 =
    CASE
    WHEN NULL/4.0 IS NULL THEN 'HURAY'
    ELSE 'OH DARN'
    END

    "rcamarda" <robc390@hotmai l.comwrote in message
    news:1154022027 .273127.29840@m 73g2000cwd.goog legroups.com...
    >I have a field that may be null which is valid, and I am finding
    something I didnt expect when working with nulls.
    SELECT NULL/4.0 will return NULL (which I expect), however, when I test
    it with a case it does not:
    >
    SELECT NULL/4.0 AS 'TEST1', TEST2 = CASE NULL/4.0 WHEN NULL THEN
    'HURAY' ELSE 'OH DARN' END
    >
    I can work around by testing for NULL first else CASE ..., but I'd like
    to understand why the CASE does not test for null.
    TIA
    rob
    SQL 2005 Enterprise x64, SP1
    >

    Comment

    • rcamarda

      #3
      Re: Working with NULLS

      DOH, forgot about IS
      Thanks Mike
      Mike C# wrote:
      Use a searched CASE expression with IS NULL. The way you're doing it is
      effectively doint the comparison NULL/4.0 = NULL, which evaluates to
      UNKNOWN, which means your CASE will drop through to the next WHEN (or the
      ELSE in this case). NULL comparisons need to use IS NULL or IS NOT NULL.
      >
      SELECT NULL/4.0 AS 'TEST1', TEST2 =
      CASE
      WHEN NULL/4.0 IS NULL THEN 'HURAY'
      ELSE 'OH DARN'
      END
      >
      "rcamarda" <robc390@hotmai l.comwrote in message
      news:1154022027 .273127.29840@m 73g2000cwd.goog legroups.com...
      I have a field that may be null which is valid, and I am finding
      something I didnt expect when working with nulls.
      SELECT NULL/4.0 will return NULL (which I expect), however, when I test
      it with a case it does not:

      SELECT NULL/4.0 AS 'TEST1', TEST2 = CASE NULL/4.0 WHEN NULL THEN
      'HURAY' ELSE 'OH DARN' END

      I can work around by testing for NULL first else CASE ..., but I'd like
      to understand why the CASE does not test for null.
      TIA
      rob
      SQL 2005 Enterprise x64, SP1

      Comment

      • --CELKO--

        #4
        Re: Working with NULLS

        The CASE expression is an *expression* and not a control statement;
        that is, it returns a value of one datatype. SQL-92 stole the idea and
        the syntax from the ADA programming language. Here is the BNF for a
        <case specification>:

        <case specification:: = <simple case| <searched case>

        <simple case::=
        CASE <case operand>
        <simple when clause>...
        [<else clause>]
        END

        <searched case::=
        CASE
        <searched when clause>...
        [<else clause>]
        END

        <simple when clause::= WHEN <when operandTHEN <result>

        <searched when clause::= WHEN <search conditionTHEN <result>

        <else clause::= ELSE <result>

        <case operand::= <value expression>

        <when operand::= <value expression>

        <result::= <result expression| NULL

        <result expression::= <value expression>

        The searched CASE expression is probably the most used version of the
        expression. The WHEN ... THEN ... clauses are executed in left to
        right order. The first WHEN clause that tests TRUE returns the value
        given in its THEN clause. And, yes, you can nest CASE expressions
        inside each other. If no explicit ELSE clause is given for the CASE
        expression, then the database will insert a default ELSE NULL clause.
        If you want to return a NULL in a THEN clause, then you must use a CAST
        (NULL AS <datatype>) expression. I recommend always giving the ELSE
        clause, so that you can change it later when you find something
        explicit to return.

        The <simple case expressionis defined as a searched CASE expression
        in which all the WHEN clauses are made into equality comparisons
        against the <case operand>. For example

        CASE iso_sex_code
        WHEN 0 THEN 'Unknown'
        WHEN 1 THEN 'Male'
        WHEN 2 THEN 'Female'
        WHEN 9 THEN 'N/A'
        ELSE NULL END

        could also be written as:

        CASE
        WHEN iso_sex_code = 0 THEN 'Unknown'
        WHEN iso_sex_code = 1 THEN 'Male'
        WHEN iso_sex_code = 2 THEN 'Female'
        WHEN iso_sex_code = 9 THEN 'N/A'
        ELSE NULL END

        There is a gimmick in this definition, however. The expression

        CASE foo
        WHEN 1 THEN 'bar'
        WHEN NULL THEN 'no bar'
        END

        becomes

        CASE WHEN foo = 1 THEN 'bar'
        WHEN foo = NULL THEN 'no_bar' -- error!
        ELSE NULL END

        The second WHEN clause is always UNKNOWN.

        The SQL-92 Standard defines other functions in terms of the CASE
        expression, which makes the language a bit more compact and easier to
        implement. For example, the COALESCE () function can be defined for
        one or two expressions by

        1) COALESCE (<value exp #1>) is equivalent to (<value exp #1>)

        2) COALESCE (<value exp #1>, <value exp #2>) is equivalent to

        CASE WHEN <value exp #1IS NOT NULL
        THEN <value exp #1>
        ELSE <value exp #2END

        then we can recursively define it for (n) expressions, where (n >= 3),
        in the list by

        COALESCE (<value exp #1>, <value exp #2>, . . ., n), as equivalent to:

        CASE WHEN <value exp #1IS NOT NULL
        THEN <value exp #1>
        ELSE COALESCE (<value exp #2>, . . ., n)
        END

        Likewise, NULLIF (<value exp #1>, <value exp #2>) is equivalent to:

        CASE WHEN <value exp #1= <value exp #2>
        THEN NULL
        ELSE <value exp #1END

        It is important to be sure that you have a THEN or ELSE clause with a
        datatype that the compiler can find to determine the highest datatype
        for the expression.

        A trick in the WHERE clause is use it for a complex predicate with
        material implications.

        WHERE CASE
        WHEN <search condition #1>
        THEN 1
        WHEN <search condition #2>
        THEN 1
        ...
        ELSE 0 END = 1

        Gert-Jan Strik posted some exampels of how ISNULL() and COALESCE() on
        2004 Aug 19

        CREATE TABLE #t(a CHAR(1));
        INSERT INTO #t VALUES (NULL);
        SELECT ISNULL(a,'abc') FROM #t;
        SELECT COALESCE(a, 'abc') FROM #t;
        DROP TABLE #t;

        He always use COALESCE, with the exception of the following type of
        situation, because of its performance consequences:

        SELECT ...,
        ISNULL((SELECT COUNT(*) -- or other aggregate
        FROM B
        WHERE B.key = A.key), 0)
        FROM A;

        Likewise, Alejandro Mesa cam up with this example:

        SELECT 13 / COALESCE(CAST(N ULL AS INTEGER), 2.00); -- promote to
        highest type (decimal)
        SELECT 13 / ISNULL(CAST(NUL L AS INTEGER), 2.00); -- promote to first
        type (integer)

        Comment

        Working...