SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Implicit conversion using COALESCE or CASE


Implicit conversion using COALESCE or CASE

Author
Message
jhager
jhager
SSC Veteran
SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)

Group: General Forum Members
Points: 210 Visits: 331
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
Luis Cazares
Luis Cazares
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16669 Visits: 19106
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
Erland Sommarskog
Erland Sommarskog
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2125 Visits: 872
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 sql_variant = 99
SELECT sql_variant_property (@s, 'BaseType')



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

Erland Sommarskog, SQL Server MVP, www.sommarskog.se
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)SSC Guru (86K reputation)

Group: General Forum Members
Points: 86834 Visits: 41103
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.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
jhager
jhager
SSC Veteran
SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)

Group: General Forum Members
Points: 210 Visits: 331
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
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16374 Visits: 19554
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
Exploring Recursive CTEs by Example Dwain Camps
jhager
jhager
SSC Veteran
SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)

Group: General Forum Members
Points: 210 Visits: 331
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
ScottPletcher
ScottPletcher
SSCertifiable
SSCertifiable (7.9K reputation)SSCertifiable (7.9K reputation)SSCertifiable (7.9K reputation)SSCertifiable (7.9K reputation)SSCertifiable (7.9K reputation)SSCertifiable (7.9K reputation)SSCertifiable (7.9K reputation)SSCertifiable (7.9K reputation)

Group: General Forum Members
Points: 7943 Visits: 7159
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)[size=2]Prosecutor James Blackburn, in closing argument in the Fatal Vision murders trial: If in the future, you should cry a tear, cry one for them [the murder victims]. If in the future, you should say a prayer, say one for them. And if in the future, you should light a candle, light one for them.[/size]
jhager
jhager
SSC Veteran
SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)SSC Veteran (210 reputation)

Group: General Forum Members
Points: 210 Visits: 331
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
Erland Sommarskog
Erland Sommarskog
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2125 Visits: 872
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.

Erland Sommarskog, SQL Server MVP, www.sommarskog.se
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search