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


Question of the Day for 10 Mar 2006


Question of the Day for 10 Mar 2006

Author
Message
David le Quesne
David le Quesne
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: 1057 Visits: 32

Well I learned something...

I tried comparing the results of the following in QA:

SELECT LEN(' ') returns 0 (all blanks are trimmed from the expression)

SELECT DATALENGTH(' ') returns 6 (6 blanks)

SELECT LEN(' a ') also returns 6 (the a is the 6th character, the trailing blank is trimmed)

SELECT DATALENGTH(' a ') returns 7 (the trailing blank is included)

but why does if '' = char(32) select 'Yes' return Yes ?

The fact that the string '' evaluates to something other than NULL causes me problems when my application removes a value from a field, because the field does not return to NULL, it returns to '', so I cannot use IS NULL when searching.

I have the same problem with dates, SQL Server seems to set the date field to -1 if the value in the field is cleared, giving me a date value of 31-Dec-1899, much to the bemusement of my users.

David



If it ain't broke, don't fix it...
Hugo Kornelis
Hugo Kornelis
SSChampion
SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)SSChampion (11K reputation)

Group: General Forum Members
Points: 11204 Visits: 12004

why does if '' = char(32) select 'Yes' return Yes ?

That's a result of how ANSI defines string comparisons.

If two strings are of unequal length, ANSI says that the shorter string is first padded with spaces to match the length of the longer one, then the actual comparison (character by character) is carried out.

So '' (length 0) is padded to the length of CHAR(32) )(length 1) by adding one space - which is the same character as CHAR(32). After this padding, the strings coompare equal.

(Note: technically, ANSI also allows for a string comparison without padding; the collation dictates which method has to be used. For backwardsd compatibility reasons, MS SQL Server (and AFAIK all other major DB's) still offer only the method with padding)

The fact that the string '' evaluates to something other than NULL causes me problems when my application removes a value from a field, because the field does not return to NULL, it returns to '', so I cannot use IS NULL when searching.

I have the same problem with dates, SQL Server seems to set the date field to -1 if the value in the field is cleared, giving me a date value of 31-Dec-1899, much to the bemusement of my users.

You'll have to make sure that your frontend sends NULL to the server when your users delete the contents of a field. For instance, if you use Enterprise Manager to edit data (which I really should recommend against!), then you can hit Ctrl-0 in any field to set it to NULL, whereas simply deleting the contents of a char field would set it to '' (the empty string).

--
Hugo Kornelis (SQL Server MVP)




Hugo Kornelis, SQL Server MVP
Visit my SQL Server blog: http://sqlblog.com/blogs/hugo_kornelis
Mike C
Mike C
SSCrazy
SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)SSCrazy (2.7K reputation)

Group: General Forum Members
Points: 2727 Visits: 1168

LEN() strips trailing pad characters (normally spaces, but could vary depending on collation) and DATALENGTH() does not.

'' isn't the same thing as NULL. To solve your problem, you might check into NULLIF(), or force a NULL value via an UPDATE statement. For example, NULLIF('', '') returns NULL.

P.S., you could also create a TRIGGER to force the value to NULL if it is '' at insert or update time.


kapil_kk
kapil_kk
Hall of Fame
Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)Hall of Fame (3.1K reputation)

Group: General Forum Members
Points: 3129 Visits: 2766
nice and tricy one...
thanks Hugo for the explanation

_______________________________________________________________
To get quick answer follow this link:
http://www.sqlservercentral.com/articles/Best+Practices/61537/
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