string Comparison.

  • 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 😉

  • 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

  • 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.

  • 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
  • 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
  • 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

  • Thanks you Gail.

    Now this makes sense.

    I didn't realize this behaviour till now.

    Thanks for enlighten me. 🙂

  • 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 step is always the hardest *******

Viewing 8 posts - 1 through 7 (of 7 total)

You must be logged in to reply to this topic. Login to reply