Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 12»»

Implicit conversion using COALESCE or CASE Expand / Collapse
Author
Message
Posted Wednesday, July 03, 2013 1:07 PM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Thursday, April 10, 2014 10:32 AM
Points: 58, Visits: 235
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
Post #1470204
Posted Wednesday, July 03, 2013 1:47 PM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Yesterday @ 10:00 PM
Points: 2,763, Visits: 5,905
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.
I am a great believer in luck, and I find the harder I work the more I have of it. Stephen Leacock

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1470212
Posted Wednesday, July 03, 2013 1:52 PM


Right there with Babe

Right there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with Babe

Group: General Forum Members
Last Login: Yesterday @ 4:43 AM
Points: 756, Visits: 631
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
Post #1470214
Posted Wednesday, July 03, 2013 3:11 PM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 7:19 AM
Points: 35,956, Visits: 30,245
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." -- 04 August 2013
(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1470246
Posted Friday, July 05, 2013 5:11 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Thursday, April 10, 2014 10:32 AM
Points: 58, Visits: 235
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
Post #1470669
Posted Friday, July 05, 2013 5:56 AM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Yesterday @ 9:33 AM
Points: 6,754, Visits: 12,854
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
Post #1470682
Posted Friday, July 05, 2013 7:11 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Thursday, April 10, 2014 10:32 AM
Points: 58, Visits: 235
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
Post #1470725
Posted Friday, July 05, 2013 11:46 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 4:04 PM
Points: 1,743, Visits: 2,545
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)
I'm not fat, I'm gravity challenged.
Post #1470828
Posted Friday, July 05, 2013 11:59 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Thursday, April 10, 2014 10:32 AM
Points: 58, Visits: 235
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

Post #1470831
Posted Friday, July 05, 2013 1:25 PM


Right there with Babe

Right there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with BabeRight there with Babe

Group: General Forum Members
Last Login: Yesterday @ 4:43 AM
Points: 756, Visits: 631
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
Post #1470860
« Prev Topic | Next Topic »

Add to briefcase 12»»

Permissions Expand / Collapse