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


what are all the possible values that a blank field in a sql server table could be?


what are all the possible values that a blank field in a sql server table could be?

Author
Message
polkadot
polkadot
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1094 Visits: 1112
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?
Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

Group: General Forum Members
Points: 26255 Visits: 17553
polkadot (10/22/2013)
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?





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.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Jeffrey Williams 3188
Jeffrey Williams 3188
SSCertifiable
SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)SSCertifiable (7.8K reputation)

Group: General Forum Members
Points: 7783 Visits: 9971
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
Problems are opportunities brilliantly disguised as insurmountable obstacles.

How to post questions to get better answers faster
Managing Transaction Logs

Sean Lange
Sean Lange
One Orange Chip
One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)One Orange Chip (26K reputation)

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

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
polkadot
polkadot
Ten Centuries
Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)Ten Centuries (1.1K reputation)

Group: General Forum Members
Points: 1094 Visits: 1112
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
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)

Group: General Forum Members
Points: 7371 Visits: 6431
Post retracted... not enough coffee this morning.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
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