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


string Comparison.


string Comparison.

Author
Message
JohnyRotten
JohnyRotten
SSC-Addicted
SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)

Group: General Forum Members
Points: 426 Visits: 253
Maybe this is a widely known topic, but not for me.
I found some strange behavior.

A table with Customer names, where in some cases trailing blanks where inserted. I wanted to know which names had trailing blanks. (Coumn type = NVARCHAR)
so....
SELECT * FROM dbo.Customers
WHERE RTRIM(LTRIM(name)) <> name



No matches was the result. Huh?
I know there are some.
So i tried the same with LIKE operater.
There you go! 47 records in my case.

Then i tried
SELECT * FROM dbo.Customers
WHERE RTRIM(LTRIM(name))+'*' <> name+'*'



Hm. There are my 47 records.

Since when is this true?
SELECT 1 WHERE 'test' = 'test     '



Is this a Database setting or what?
Any Explanations on this?
Thanks for enlighten me ;-)
Henrico Bekker
Henrico Bekker
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13603 Visits: 5336
try the following:

select LEN(string2),len(RTRIM(LTRIM(string2))) from yourtablename



and compare the length it records.

-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
This thing is addressing problems that dont exist. Its solution-ism at its worst. We are dumbing down machines that are inherently superior. - Gilfoyle
JohnyRotten
JohnyRotten
SSC-Addicted
SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)

Group: General Forum Members
Points: 426 Visits: 253
Thanks for the info.

I allready know there are different ways to solve this. that was not my problem

I was curious if anyone knew this behaviour, and why it works this way. I could'nt find this in BOL.
GilaMonster
GilaMonster
SSC Guru
SSC Guru (460K reputation)SSC Guru (460K reputation)SSC Guru (460K reputation)SSC Guru (460K reputation)SSC Guru (460K reputation)SSC Guru (460K reputation)SSC Guru (460K reputation)SSC Guru (460K reputation)

Group: General Forum Members
Points: 460958 Visits: 47313
JohnyRotten (3/14/2011)

Since when is this true?
SELECT 1 WHERE 'test' = 'test     '



In SQL always.

SQL ignores trailing spaces when doing string comparisons. If it didn't, there would be all sorts of fun in comparing a char(4) to a char(10) (seeing as char is space-padded to its full length)

If you want to compare lengths of strings, use DATALENGTH (not LEN, as that too ignores trailing spaces). In general though don't worry too much about trailing spaces, seeing as SQL ignores them for comparison, filters and joins. Unless you're also working with something that doesn't (like SSIS)

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


GilaMonster
GilaMonster
SSC Guru
SSC Guru (460K reputation)SSC Guru (460K reputation)SSC Guru (460K reputation)SSC Guru (460K reputation)SSC Guru (460K reputation)SSC Guru (460K reputation)SSC Guru (460K reputation)SSC Guru (460K reputation)

Group: General Forum Members
Points: 460958 Visits: 47313
Henrico Bekker (3/14/2011)
try the following:

select LEN(string2),len(RTRIM(LTRIM(string2))) from yourtablename



and compare the length it records.


However note (from Books Online)

LEN (Transact-SQL)

Returns the number of characters of the specified string expression, excluding trailing blanks.


Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Henrico Bekker
Henrico Bekker
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13603 Visits: 5336
Ahh, excellent thanx Gail, I learnt something as well from this question.
Great stuff!

-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
This thing is addressing problems that dont exist. Its solution-ism at its worst. We are dumbing down machines that are inherently superior. - Gilfoyle
JohnyRotten
JohnyRotten
SSC-Addicted
SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)SSC-Addicted (426 reputation)

Group: General Forum Members
Points: 426 Visits: 253
Thanks you Gail.

Now this makes sense.
I didn't realize this behaviour till now.
Thanks for enlighten me. :-)
SGT_squeequal
SGT_squeequal
SSCrazy
SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)SSCrazy (2.6K reputation)

Group: General Forum Members
Points: 2607 Visits: 1118
Hi if you want to search in your table where the name filed has a leading or trailing space you could use the following

select * from table
where patindex('% %',collumn)>0

if there is a space anywhere in the collum a result will be returned

*************************************************************

The first is always the hardestw00t
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