THE SQL Server Blog Spot on the Web

Welcome to SQLblog.com - The SQL Server blog spot on the web Sign in | |
in Search

John Paul Cook

Why to use COALESCE instead of ISNULL

As of this writing, Books Online isn't completely clear about how ISNULL works. I submitted suggestion 778704 on Connect asking Microsoft to explicitly state that if the replacement_value is longer than the check_expression, it will be truncated to the length of the check_expression. A code sample that demonstrates the problem is shown below. To prevent this kind of truncation, use COALESCE instead of ISNULL as shown in the last step. Additionally, COALESCE is ANSI standard and ISNULL is not. Read Aaron's post if you want to know more about the performance implications of COALESCE vs. ISNULL. My primary point is to make people aware of how things actually work so that they can write more robust code. UPDATE: On February 12, 2013, Microsoft indicated that they would be clarifying the documentation on ISNULL.

DECLARE @msg NVARCHAR(4000);
DECLARE @str1 NCHAR(1);
DECLARE @str2 NCHAR(2);
DECLARE @str3 NCHAR(3);
DECLARE @str5 NCHAR(5);
DECLARE @str11 NCHAR(11);

/* notice that @str1, @str2, @str3, @str5, @str11 are never set, so they are NULL */
/* the objective is to display the value of @str1                                 */
/* is @str1 is actually NULL, then display "not defined"                          */

SET @msg = N'@str1 is ' + ISNULL (@str1, N'not defined');
SELECT N'str1 ISNULL', @msg;

SET @msg = N'@str2 is ' + ISNULL (@str2, N'not defined');
SELECT N'str2 ISNULL', @msg;

SET @msg = N'@str3 is ' + ISNULL (@str3, N'not defined');
SELECT N'str3 ISNULL', @msg;

SET @msg = N'@str5 is ' + ISNULL (@str5, N'not defined');
SELECT N'str5 ISNULL', @msg;

SET @msg = N'@str11 is ' + ISNULL (@str11, N'not defined');
SELECT N'str11 ISNULL', @msg;

SET @msg = N'@str1 is ' + COALESCE (@str1, N'not defined');
SELECT N'str1 COALESCE', @msg;

GO

 

Published Wednesday, February 06, 2013 6:53 PM by John Paul Cook

Comment Notification

If you would like to receive an email when updates are made to this post, please register here

Subscribe to this post's comments using RSS

Comments

 

Aaron Bertrand said:

I talk about this issue and a bunch of others in the following tip:

http://www.mssqltips.com/sqlservertip/2689/deciding-between-coalesce-and-isnull-in-sql-server/

The only place where ISNULL trumps COALESCE is when the expression is a subquery - with COALESCE it may be evaluated twice.

February 6, 2013 8:44 PM
 

Francesco Quaratino said:

really scary!

February 7, 2013 5:34 AM
 

Paul White said:

I prefer ISNULL in most cases for a range of detailed reasons, many related to better optimizer reasoning with ISNULL. The argument presented here is one small aspect of the differences which I do not find at all compelling.

February 7, 2013 2:13 PM
 

gbn said:

I prefer ISNULL too to avoid accidental datatype conversions due to datatype precedence. And as Paul said.

Discussion here: http://dba.stackexchange.com/q/4274/630

February 8, 2013 5:58 AM

Leave a Comment

(required) 
(required) 
Submit

About John Paul Cook

John Paul Cook is both a Registered Nurse and a Microsoft SQL Server MVP experienced in Microsoft SQL Server and Oracle database application design, development, and implementation. He has spoken at many conferences including Microsoft TechEd and the SQL PASS Summit. He has worked in oil and gas, financial, manufacturing, and healthcare industries. Experienced in systems integration and workflow analysis, John is passionate about combining his IT experience with his nursing background to solve difficult problems in healthcare. He sees opportunities in using business intelligence and Big Data to satisfy healthcare meaningful use requirements and improve patient outcomes. John graduated from Vanderbilt University with a Master of Science in Nursing Informatics and is an active member of the Sigma Theta Tau nursing honor society. Contributing author to SQL Server MVP Deep Dives and SQL Server MVP Deep Dives Volume 2.

This Blog

Syndication

Powered by Community Server (Commercial Edition), by Telligent Systems
  Privacy Statement