Implicit conversion using COALESCE or CASE

  • Hi,

    I've discovered that I always seem to get an implicit conversion to INT when using this syntax:

    SELECT ... ORDER BY COALESCE(SectionOrder, 99); (Column [SectionOrder] is defined as SMALLINT).

    The execution plan COMPUTE SCALAR operation shows this syntax as being changed to a CASE statement:

    CASE WHEN SectionOrder IS NOT NULL THEN convert_implicit(int,SectionOrder,0) ELSE (99) END

    Is this conversion a "feature" of SQL Server? Any info is appreciated.

    ~ Jeff

  • COALESCE will do an implicit conversion using Data Type Precedence.

    The convertion from COALESCE to CASE is just the way COALESCE works (at least a part of it).

    For more information on data type precedence for implicit conversion, check: http://msdn.microsoft.com/en-us/library/ms190309.aspx

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • To expand a little on Luis's answer, SQL Server has a strict data type-precedence which says that when two types meet, the type with lower precedence will be converted to the type with higher precedence - all provided that there is an implicit conversion at all. smallint has lower precedence than int.

    What puzzled me is that I seemed to recall that the data type of a literal < 256 is tinyint, but I was wrong. The way to find out the data type of a literal is this:

    DECLARE @s-2 sql_variant = 99

    SELECT sql_variant_property (@s, 'BaseType')

    And it gives that the type of 99 really is int.

    [font="Times New Roman"]Erland Sommarskog, SQL Server MVP, www.sommarskog.se[/font]

  • Welcome aboard, Mr. Sommarskog. Very nice to have you here.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Thanks all for replying; although I was aware of the "precedence" feature of COALESCE, I didn't realize that literal values would be typed differently, in this case 99 as an INT. Thanks for the code to determine type, I'll have to check many other code objects as we use COALESCE quite frequently in our work.

    ~ Jeff

  • jhager (7/5/2013)


    Thanks all for replying; although I was aware of the "precedence" feature of COALESCE, I didn't realize that literal values would be typed differently, in this case 99 as an INT. Thanks for the code to determine type, I'll have to check many other code objects as we use COALESCE quite frequently in our work.

    ~ Jeff

    If you are using COALESCE() where you might use ISNULL() - as in your first post - then you might benefit from reading this Adam Machanic article.

    “Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

    For fast, accurate and documented assistance in answering your questions, please read this article.
    Understanding and using APPLY, (I) and (II) Paul White
    Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden

  • Another great reply; I currently ask my team to use COALESCE exclusively because it's ANSI standard and more flexible due to multiple parameters...but your reply leads me back to "any tool in the toolbox". In the case I stated, it appears that ISNULL would have been the better option...so now I'll check for situations where ISNULL should be used instead of COALESCE.

    This is why I like this forum so much...I always get informed answers that I can trust (unlike many on the web), and usually from people who know this product and creative methods to use it.

    Thanks again,

    ~ Jeff

  • I'd suggest using COALESCE also, keeping in mind the difference between it and ISNULL in regard to data types.

    Given that, in this case you could explicitly CAST the 99 to smallint so the datatypes are identical, as below, which should avoid any implicit conversions:

    ORDER BY COALESCE(SectionOrder, CAST(99 AS smallint));

    SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".

  • Thanks for replying; I now have a situation where there are four possibilities:

    1) ISNULL

    2) COALESCE

    3) COALESCE with CAST/CONVERT

    4) Modify the column from SMALLINT to INT

    I've run each of the three "code" solutions, and notice that I get a slightly different exec plan with ISNULL vs. COALESCE; the Compute Scalar operations for the COALESCE versions each have a small (but larger) cost than the ISNULL version, and the COALESCE versions have the Compute Scalar operation before the Sort operation; the ISNULL Compute Scalar happens after the Sort. All that said, there seems to be no significant difference in performance benefit for any of the options. At this point, I'd vote for changing the column definition and using COALESCE.

    As an aside, I notice that most members of the forum have cool mottoes or quotes, so I guess I need one, too.

    Perhaps this: "I think myself quite a wit; my friends say I'm half right".

    ~ Jeff

  • jhager (7/5/2013)


    Another great reply; I currently ask my team to use COALESCE exclusively because it's ANSI standard and more flexible due to multiple parameters..

    However, there is a major problem with coalesce if you have subqueries in the argument list like this:

    coalesce((SELECT col FROM tbl WHERE key = @key), 11)

    This can return NULL, because this is implemented as

    CASE WHEN <subquery> IS NOT NULL THEN <subquery> ELSE 11 END

    That is, the subquery is computed twice, and in a multi-concurrency environment, the computations could have different results.

    [font="Times New Roman"]Erland Sommarskog, SQL Server MVP, www.sommarskog.se[/font]

  • ISNULL() has its own oddities:

    DECLARE @var1 char(1)

    SET @var1 = NULL

    SELECT ISNULL(@var1, 'N/A') -- Result = 'N'

    SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".

  • Yes, the data type for isnull is always the type of the first argument.

    [font="Times New Roman"]Erland Sommarskog, SQL Server MVP, www.sommarskog.se[/font]

Viewing 12 posts - 1 through 11 (of 11 total)

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