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 «««12345

Best Practice : coalesce vs. isnull? Expand / Collapse
Author
Message
Posted Tuesday, August 28, 2012 3:45 PM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Today @ 1:43 PM
Points: 1,757, Visits: 2,574
GSquared (12/14/2009)
BaldingLoopMan (12/14/2009)
To each their own.


Even in cases where the data type precedence won't cause a problem, I find the Coalesce version below much easier to read, understand, and maintain, than the second:

if object_id(N'tempdb..#People') is not null
drop table #People;

create table #People (
ID int identity primary key,
NamePrefix varchar(100),
NameFirst varchar(100),
NameMiddle varchar(100),
NameLast varchar(100),
NameSuffix varchar(100));

insert into #People (NamePrefix, NameFirst, NameMiddle, NameLast, NameSuffix)
select null, 'Adam', null, 'Abrahms', null union all
select '', 'Bob', null, 'Birch', null union all
select 'Dr', 'Carl', 'C', 'Carlson', 'PhD' union all
select 'Rev', null, null, 'Dodgy', 'Jr';

;with Cleanup (Prefix, First, Middle, Last, Suffix) as
(select IsNull(NullIf(NamePrefix, ''), 'Mr/Ms'), NullIf(NameFirst, ''), NullIf(NameMiddle, ''),
NullIf(NameLast, ''), NullIf(NameSuffix, '')
from #People)
select
coalesce(
Prefix + ' ' + First + ' ' + Middle + ' ' + Last + ', ' + Suffix,
Prefix + ' ' + First + ' ' + Middle + ' ' + Last,
Prefix + ' ' + First + ' ' + Last + ', ' + Suffix,
Prefix + ' ' + First + ' ' + Last,
Prefix + ' ' + Last + ', ' + Suffix,
Prefix + ' ' + Last)
from Cleanup;




I think there's an easier way to do that expression.

You can use the expression below directly in a SELECT, but to keep the definition consistent for all queries, I would add a computed column to the base table:


ALTER TABLE dbo.tablename
ADD full_name AS
ISNULL(Prefix, '') + ISNULL(' ' + First, '') + ISNULL(' ' + Middle) +
ISNULL(' ' + Last, '') + ISNULL(', ' + Suffix, '')
--if you need the NULLIFs, naturally add those in


SELECT
fullname,...
FROM dbo.tablename
--GROUP BY
--fullname --for example
--ORDER BY
--fullname --for example



SQL DBA,SQL Server MVP('07, '08, '09)
I'm not fat, I'm gravity challenged.
Post #1351309
Posted Thursday, August 30, 2012 11:36 AM


SSC-Dedicated

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

Group: General Forum Members
Last Login: Today @ 5:17 PM
Points: 36,002, Visits: 30,296
bambang (12/11/2009)
Just wondering,
I like to use ISNULL(column_name, 0) while my friend like to use COALESCE(column_name, 0).
We both try using ISNULL and COALESCE in our query and there is no different result.

In Books online, it's said that both behave differently. There's also the explanation, but I just don't
understand it completely :p

Is there any article regarding this topic?
And which one you usually use (ISNULL or COALESCE) and why you use it?

For now, I'll keep my habit using ISNULL, so will my friend keep using COALESCE

Thanx for any explanation, link, or you opinion


1. ISNULL is actually a tiny bit faster than COALESCE but it takes millions of rows to notice.
2. ISNULL is shorter to type than COALESCE.
3. ISNULL converts the second operand to the same datatype as the first. COALESCE selects the datatype of the operand that has the highest data precidence. THAT can make for some real performance problems if you're not careful.
4. If you believe in the myth of truly portable code (and I don't except maybe for basic "CRUD"), COALESCE is ANSI where ISNULL is not.

I agree that it's nearly a personal choice and my personal choice is to use ISNULL where ever I can.


--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 #1352397
« Prev Topic | Next Topic »

Add to briefcase «««12345

Permissions Expand / Collapse