Robyn Page’s SQL Server String Manipulation Workbench

String searching and manipulation in SQL Server can be error-prone and tedious...unless you're armed with the techniques described in Robyn's string manipulation workbench...

This “workbench” on string handling and manipulation in SQL Server is a companion to my previous one on dates and times. Rather than rehash what is readily available on SQL Server Books Online, I’ve once again tried to provide a starting point for your own experiments.

You can download the article as a SQL script to paste in its entirety into the Query Analyser, SSMS or other GUI and execute the individual examples (and it is available, as an attachment to the article). You’ll find the download at the bottom of the article.

The main difficulty in dealing with Strings in SQL Server is that the techniques are rather open-ended. There are often a number of different ways to achieve the same end result. The String functions such as STUFF or REVERSE are of little use by themselves, but when used in conjunction with others, they become extremely useful. Other functions are there as ‘legacy items’ meaning that it is difficult to remove functions such as SOUNDEX as there are still a few die-hards still using them

As with the previous ‘workbench’, my advice is to download the .sql file (see the Code Download link to the right of the article title) open it up in SQL Server, and start experimenting!

Ideally, you’ll also have Books online open in a browser, to provide supplementary and background information.

I’ve added a few questions at the end just so you can check on your progress. Overall, I hope that this workbench illustrates how easy string handling is in SQL Server once the basic ideas are grasped.

Contents

As a practice table for this workbench we will create a temporary table and stock it with string data.

Note the way that one inserts the ‘ delimiter (as in “I can play ‘Chopsticks’ on the Wurlitzer”) by putting in a second ‘ character.

Selecting from a table

–you can, of course, select according to strings, or partial strings

SELECT line FROM #poem WHERE line LIKE ‘I Was%’–‘I Was’ at

–the start of the line (‘%’ means ‘any number 0-n of any character)

SELECT line FROM #poem WHERE line LIKE ‘%sam%’–‘sam’ anywhere

SELECT line FROM #poem WHERE line LIKE ‘%?%’–? anywhere

SELECT line FROM #poem WHERE line BETWEEN ‘a’ AND ‘e’–returns

–all lines starting with a,b,c or d

SELECT line FROM #poem WHERE line < ‘D’ –returns one line

SELECT line FROM #poem WHERE ‘ ‘+line LIKE ‘% g_tsam%’

–here we want only words starting with g?tsam. the underscore

–character means ‘one character, anything you like’. The leading

–space makes the logic simpler as it allows for occurences of the

–word at the beginning of the line

SELECT line FROM #poem WHERE ‘ ‘+line LIKE ‘%[aeiou][aeiou]%’

–any line with two consecutive vowels in it

–the ‘[]’ delimiters contain a range of characters

–and mean ‘one character, anything in the range’

–here, it is a list of vowels

SELECT line FROM #poem WHERE ‘ ‘+line LIKE ‘%[^a-z][aeiou][aeiou]%’

— returns any line containing a word beginning with two vowels

–the [^a-z] will mean a whitespace character in European

–languages as long as you set your collation accordingly!

The String Datatypes

SQL Server inherited from its Sybase ancestors a limit to the size of string. This complicated the manipulation of large quantities of text. However, this limit has been remedied since SQL Server 2005 with the special datatype, Varchar(MAX). TEXT is now deprecated as a datatype but is used sufficiently in versions previous to SQL Server 2005 to make it relevant.

There are three basic string types (Unicode equivalents shown in brackets):

  • Char (nChar)
  • Varchar (nVarchar)
  • Text (nText)

The nearest equivalents between the new 2005 string variables and previous versions is as follows:

  • XML -> nText
  • Varchar(MAX) -> Text
  • nVarchar(MAX) -> nText


(If replicating from a SQL Server 2005 publisher to a SQL Server 2000 subscriber, this mapping is done automatically but it’s well to be aware of what is going on).

Most European languages can be represented by the eight-bit character sets. For a ‘global’ system that can represent all languages, one must opt for Unicode, and use NVarchar, or NChar or NText. Peculiarly, the method of representing Unicode constants is case-sensitive, being the uppercase N prefix (N stands for National Language in the SQL-92 standard).

Unicode constants are interpreted as Unicode data, and are not evaluated using a code page. Unicode constants do have a collation, though, which determines comparisons and case sensitivity. Unicode data is stored using two bytes per character.

You’ll see that the first string needed twice the storage of the second Unicode string constants support enhanced collations.

Strings and Collations

Collations determine the result of sorts, and string comparisons. Constants are assigned the default collation of the current database, unless the COLLATE clause is used to override it.

To see what are available, use:

The name of the collation can include the language, the country or region, and the case, accent, and width sensitivity. Windows collations that designate a country or region name in addition to the language name are usually distinct because they have different sort orders than other collations in the same language and map to a different code page.

So any function or stored procedure that is intended to be portable across databases must be explicit about collation where necessary. Collations can be selected at Server, Database, column or expression, but we’ll only illustrate its selection in an expression.*/

Some of the jargon and abbreviations used in the names for the collations require explanation

Binary BIN

Binary is the fastest sorting order. It sorts and compares data based on the bit patterns defined for each character.

Binary sort order is case-sensitive (lowercase precedes uppercase), and accent-sensitive.

If one chooses a language-based sort rather than a binary sort, SQL Server follows sorting and comparison rules as defined in dictionaries for the associated language or alphabet.

Case-sensitive CS

Case-sensitive collation means that the uppercase and lowercase versions of letters are considered different.

Accent-sensitive AS

Accent-Sensitive collation means that, For example, ‘a’ is not equal to ‘â’. and will sort strings so that strings beginning with a but with different accents, will not be sorted together.

Kana-sensitive KS

Specifies that the two types of Japanese kana characters: Hiragana and Katakana, are different

Width-sensitive WS

Specifies that a single-byte (half-width) ‘hankaku’ character and the same character represented as a double-byte (full-width) ‘zenkaku’ character are different Half-width characters has a glyph image that occupies half of the character display cell.

Assignment and Truncation

String variables work similarly to string data in tables except for the way SQL Server behaves if an attempt is made to assign a string that is longer than the variable’s length.

One has to be very careful to watch out for truncation when assigning to string variables. Assigning to a string variable causes truncation without causing an error. This is done in order to achieve consistency with the behaviour of the CHAR datatype.

So, where necessary, it is wise to check the string inputs for possible overflow. Here is a fragment of a stored procedure that checks for overflow. I’ve been caught out many times so I advise you to put in a precaution like this:

The string Functions

LEN

The LEN function returns the length of the string. Finding the length of a string is not always straightforward.

…because the length of strings in SQL Server do not include trailing spaces this means that, if you want the true length of a string it must be done by:

In the first example, we substitute a different character for the space (it doesn’t matter what), whereas, in the second case we add a non-space character so the spaces aren’t trailing.

ASCII and UNICODE

The ASCII function returns the ASCII code of the first character of a char or Varchar string it returns the ASCII value of ? if it can’t do so!

So let’s use a simple bit of code, illustrating the use of ASCII, to display the character values of the characters in a string, (I’ve used this in an emergency in the past)

UNICODE does the same thing for a Unicode string that ASCII does for CHARs or VARCHARs.

NChar

This will give you the character represented by the Unicode. Note how one can represent character values as hex strings. Here, to illustrate its use, are some useful Unicode currency symbols!

You may need to set your results pane to Unicode to see these properly!

CHAR

Returns the ASCII character represented by the integer code. In this example we’ll put a CR/Linefeed sequence into a string.

PATINDEX

PATINDEX provides you with a great deal of versatility in finding strings in TEXT data. It also allows you to search by wildcard.

We could, for example, show the part of the string with the first occurrence of a word that starts with two or more vowels.

SELECT ‘…’+SUBSTRING(line,PATINDEX(‘% [aeiou][aeiou]%’,line),10)

+’…’

FROM #poem

WHERE ‘ ‘+line LIKE ‘% [aeiou][aeiou]%’

The usefulness of patindex is fundamentally lessened by the fact that there is no way of detecting the end of the sequence in the original string that matched the wildcard.

PatIndex is great if, for example, you want to extract the first number from a string.

CHARINDEX

Charindex provides a standard way of searching within strings to find a substring, and returning the starting position of the string. It has the added versatility of allowing you to specify the starting location of the search. This is especially useful in places where you must find all occurrences of a string. Consider the following simple routine which splits delimited strings (such as you might find in ‘serialised’ data) into a table.

You should see all the items from the list in a table. Once you have a function like this, you can then use it for such esoteric tasks as, for example, stripping tags out of HTML or XML!

Naturally, the technique works just as easily stripping bracketed text from strings or any other delimiter!

So with just three of the built-in functions used in a user-defined function, you have a powerful tool

REPLACE

We have seen the REPLACE function being used already a a work-around for LEN‘s quirks. It is one of the most useful of the String functions. It’ll replace all occurrences of one string with another.

For example…

But the simpleset way of stripping out unwanted extra spaces from a column would be to use something like this, even if it looks a bit awkward.

This version is safe for blocks of spaces up to 461 characters long, which should suffice.

The huge advantage is its speed, as it requires no UDF to clean up text with space in it.

Even neater, (thanks to Mladen Prajdic):

STUFF

STUFF is the Swiss army knife of string substitution. You can insert any number of characters at a particular point in a string, with the option of deleting existing characters at that point. With apologies for repeating myself, here is a good example of the use of STUFF, which inserts the ordinal suffix into a date. It is difficult to do it as concisely any other way.

One can even use it for awkward operations like deleting part of the string, as I will show later on in the article.

Slicing Strings Up: LEFT RIGHT and SUBSTRING

There are three functions that are generally used for slicing strings into substrings. These are LEFT, RIGHT and SUBSTRING. LEFT gives however many characters you specify from the left, or start, of the string and RIGHT gives however many characters you specify from the right, or end, of the string. SUBSTRING works like LEFT but allows you to specify the start position.

Here is another string-slicer based on using CHARINDEX, LEFT and STUFF which, likes the previous example, slices a series of delimited strings into a table.

So we can use this routine to get a word frequency count of the poem.

REPLICATE

Just occasionally, the REPLICATE function is very handy, though mainly in formatting fixed-width text. It creates a string, using whatever character you specify, to whatever length you specify.

Here, we’ll demonstrate its use:

Which draws a box! As an exercise, what about writing the poem within a box?

SPACE

SPACE(10) (return a string consisting of ten spaces) is equivalent to REPLICATE(' ',10). The SPACE function just returns a string with however many spaces you specify. It was more popular in the days of printed reports on fixed-width fonts where the results had to be printed in decimal point alignment, or right-aligned. eg:

REVERSE

The REVERSE function, which merely returns the string backwards. Execute this to discover the message…

REVERSE is occasionally very useful, and on those occasions nothing else will do. In this example, we find the last occurrence of a substring in a string and delete it.

How about this trick for getting just the last part of a url?

Changing case: LOWER and UPPER

There are two useful functions, LOWER and UPPER, which are pretty self-explanatory:

SELECT UPPER(‘i have drunk too much caffeine’),

LOWER(‘I MUST CALM DOWN’)

To do capitalisation, you may want a function like this, which shows a more complex use of UPPER:

So now we try it out…

Removing leading or trailing spaces RTRIM & LTRIM

There are two functions that can be used to trim either the leading spaced or trailing spaces from strings.

Fuzzy searches, SOUNDEX and DIFFERENCE

For doing fuzzy searches, there are two functions based on the old ‘soundex’ algorithm These are of no more than historical interest and they seem to be in there purely for historical reasons but I’d be interested if anyone can point out a use for them. Even if they worked in one language, which they don’t, they aren’t even internationally valid.

The functions are SOUNDEX and DIFFERENCE

e.g.

Manipulating TEXT and NTEXT

For the deprecated TEXT and NText datatype, there are a only a few functions that will work with them. These are PATINDEX, TEXTVALID, SUBSTRING, DATALENGTH and TEXTPTR As these are either covered elsewhere, or too esoteric to be within the scope of the workbench, I’d like to refer you to Books Online, which covers them very well.

Some questions

  1. What happens when you assign a string to a Varchar variable whose length is shorter then that of the string
  2. When replicating from a SQL 2005 publisher to a SQL 2000 subscriber, how is a nVarchar(MAX) mapped?
  3. How do you specify the sort order of strings?
  4. What is width-sensitivity in a collation?
  5. How would you, with one function, find the start of the first word in a string that starts with a lower case character.
  6. How might you go about decimal-aligning numbers in a fixed-width font?
  7. How might one go about stripping all text in brackets from a VARCHAR variable?
  8. What collation would be a good choice id you were writing a SQL Server Database that would be used in several European countries.

If you liked reading this workbench, then take a look at Robyn Page and Phil Factor’s subsequent series on string functions.