October 22, 2013 at 11:33 am
If a sql server table's column values
1. allows nulls
2. originally came from another database
3. occasionally contains the word NULL in it
4. is empty half the time
what are all the conditions that you must evaluate for in the case of a CASE statement in which you handle for that field being 'empty'.
I am currently using the following statement:
(1) CASE WHEN LEN(realname) = 0 and LEN(computer_name) = 0 then email
but I've also used:
(2) CASE WHEN realname IS NULL OR realname = '' and computer_name IS NULL OR computer_name = '' THEN email
WHICH IS BETTER, 1 OR 2?
--Quote me
October 22, 2013 at 1:16 pm
polkadot (10/22/2013)
If a sql server table's column values1. allows nulls
2. originally came from another database
3. occasionally contains the word NULL in it
4. is empty half the time
what are all the conditions that you must evaluate for in the case of a CASE statement in which you handle for that field being 'empty'.
I am currently using the following statement:
(1) CASE WHEN LEN(realname) = 0 and LEN(computer_name) = 0 then email
but I've also used:
(2) CASE WHEN realname IS NULL OR realname = '' and computer_name IS NULL OR computer_name = '' THEN email
WHICH IS BETTER, 1 OR 2?
According to your rules neither of these is accurate. They will both allow columns with the string literal 'NULL'. If you are ok with ignoring rule #3 than I would do a slightly different version of (2).
Case when ISNULL(realname, '') = '' AND ISNULL(computer_name, '') = '' then email
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
October 22, 2013 at 1:25 pm
Sean Lange (10/22/2013)
polkadot (10/22/2013)
According to your rules neither of these is accurate. They will both allow columns with the string literal 'NULL'. If you are ok with ignoring rule #3 than I would do a slightly different version of (2).
Case when ISNULL(realname, '') = '' AND ISNULL(computer_name, '') = '' then email
To handle the word NULL, couldn't we do this?
Case when ISNULL(NULLIF(realname, 'NULL'), '') = '' AND ISNULL(NULLIF(computer_name, 'NULL'), '') = '' then email
Jeffrey Williams
“We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”
― Charles R. Swindoll
How to post questions to get better answers faster
Managing Transaction Logs
October 22, 2013 at 1:30 pm
Jeffrey Williams 3188 (10/22/2013)
Sean Lange (10/22/2013)
polkadot (10/22/2013)
According to your rules neither of these is accurate. They will both allow columns with the string literal 'NULL'. If you are ok with ignoring rule #3 than I would do a slightly different version of (2).
Case when ISNULL(realname, '') = '' AND ISNULL(computer_name, '') = '' then email
To handle the word NULL, couldn't we do this?
Case when ISNULL(NULLIF(realname, 'NULL'), '') = '' AND ISNULL(NULLIF(computer_name, 'NULL'), '') = '' then email
Nicely done!!! I think that should do it.
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
October 24, 2013 at 3:02 pm
Thank you. By combining ISNULL and NULLIF functions it's the most elegant handling of the true NULL and text NULL scenario I've seen. Few months back I was doing it using AND, which made for very long statement. This is better.
WHEN ISNULL(NULLIF(realname, 'NULL'), '') = '' AND ISNULL(NULLIF(computer_name, 'NULL'), '') = '' then email
--Quote me
October 24, 2013 at 6:30 pm
Post retracted... not enough coffee this morning.
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply