Normalizing Name Data in SQL Server
My article titled "String Manipulations with SQL Server 2000" gives a quick overview of all string functions supported in Microsoft SQL Server 2000. Now it's time to apply that knowledge into a real-world example. The business case this time is a text file or any other type of denormalized data that contains individuals' names. Your goal is to load this data into a normalized table that contains peoples' first names, middle names, last names, and suffixes. Please refer to the string manipulations article for a description and examples of all functions used in this article.
First, let's look at the data that we have to work with. Splitting names is challenging because they don't follow any rulesthey're specific to an individual. For instance, some people use only their middle initial instead of a full middle name. Others don't have a middle name at all. Still others use their first initial and a middle name. There might be initials that are spelled with a period (as in Jane M. Smith), as well as the ones that are spelled without a period (L Brian Brown). Suffixes complicate the matter even further; you can expect one of the suffixes shown in the following table:
Suffix |
Meaning of Suffix |
Jr. |
Junior |
Sr. |
Senior |
II |
Second |
III |
Third |
IV |
Fourth |
M.D. |
Medical Doctor |
In addition, some people have a double suffix, as in Gerhard J. Volzkoff, Jr., M.D. Suffixes can be separated from names by a space, comma, or period.
NOTE
Names are particularly specific to regions. In some countries, the individuals' names might consist of four, five, or even more names. For the sake of simplicity, we will only discuss getting the first, middle, and last names along with the suffix.
The following script creates the temporary table containing the data we'll manipulate:
CREATE TABLE #names ( name_id INT IDENTITY(1, 1) NOT NULL, full_name VARCHAR(110) NULL, first_name VARCHAR(30) NULL, middle_name VARCHAR(30) NULL, last_name VARCHAR(30) NULL, suffix VARCHAR(20) NULL ) INSERT #names (full_name) VALUES ( 'Jane M. Smith') INSERT #names (full_name) VALUES ( 'L Brian Brown') INSERT #names (full_name) VALUES ( ' Gerhard J. Volzkoff, Jr., M.D. ') INSERT #names (full_name) VALUES ( ' John J. Walters, Sr. ') INSERT #names (full_name) VALUES ( 'James P. McPherson III') INSERT #names (full_name) VALUES ( ' L. M Kim ') INSERT #names (full_name) VALUES ( ' Richard B. Johnson, IV ') INSERT #names (full_name) VALUES ( 'Karen Hornsby') INSERT #names (full_name) VALUES ( 'Bill Stanford JR') INSERT #names (full_name) VALUES ( 'I B. Prufen') INSERT #names (full_name) VALUES ( 'Erika L Grey') INSERT #names (full_name) VALUES ( 'J. B. Edwards')
Notice that I tried to populate the temporary table with a variety of names. Besides each name being different in its "architecture", some of the names also contain leading and trailing spaces.
As a first step, let's get rid of leading and trailing spaces so we don't see some odd results in our queries. The following UPDATE statement will do the job.
UPDATE #names SET full_name = LTRIM(RTRIM(full_name))
Next, let's try to grab all the suffixes and put them in the suffix column. Some of the suffixes will have two characters ('jr', 'sr', 'II', 'IV', 'md'). For names having such suffixes, you can grab the last two letters from the end and consider them a suffix; as long as the third character from the right is a space, comma, or a period.
Some other suffixes will be three characters long ('III', 'jr.', 'sr.'). The logic is similar: You check for three rightmost characters and ensure that the forth character from the right is a one of the suffix delimiters. Finally, the 'm.d.' suffix is four characters long. Of course, there can be many other suffixes that you can check for: 'Ph.D', 'P.C.', and so forth. The principles discussed in this article will apply to any suffix. Due to the differences in suffixes, we could run a couple of different UPDATE statements to catch all of these anomalies. However, there is a better waya single UPDATE query with a CASE statement shown below. See inline comments for a brief explanation of what each portion of CASE statement is doing:
UPDATE #names SET Suffix = CASE /* take care of 2 letter suffixes */ WHEN RIGHT(RTRIM(full_name), 2) IN ('jr', 'sr', 'ii', 'md', 'iv') AND SUBSTRING(REVERSE(full_name), 3, 1) IN (' ', ',', '.') THEN RIGHT(full_name, 2) /* take care of 3 letter suffixes */ WHEN RIGHT(RTRIM(full_name), 3) IN ('iii', 'jr.', 'sr.') AND SUBSTRING(REVERSE(LTRIM(RTRIM(full_name))), 4, 1) IN (' ', ',', '.') THEN RIGHT(full_name, 3) /* take care of 4 letter suffixes */ WHEN RIGHT(RTRIM(full_name), 4) = 'm.d.' AND SUBSTRING(REVERSE(full_name), 5, 1) IN (' ', ',', '.') THEN RIGHT(full_name, 4) /* if none of the above statements got the suffix, then the name does not have a suffix. If so, leave suffix as null. */ ELSE NULL END
Now, you've taken care of all suffixes except for the case when a person has a double suffix. Looking at my data, the only time I can expect a double suffix is when a person happens to be a medical doctor. Therefore, let's check and see if any of the M.D.s have additional suffixes. Again, the CASE statement helps us catch all possible suffixes:
UPDATE #names SET Suffix = CASE WHEN full_name LIKE '%m.d.%' AND /* check for a dual suffix of 'jr' */ full_name LIKE '%jr%' THEN 'Jr., ' + Suffix WHEN full_name LIKE '%m.d.%' AND /* check for a dual suffix of 'sr' */ full_name LIKE '%sr%' THEN 'Sr., ' + Suffix WHEN full_name LIKE '%m.d.%' AND /* check for a dual suffix of 'III' */ full_name LIKE '%iii%' THEN 'III, ' + Suffix WHEN full_name LIKE '%m.d.%' AND /* check for a dual suffix of 'IV' */ full_name LIKE '%iv%' THEN 'IV, ' + Suffix ELSE Suffix END
Now take a look at the suffix column along with the name and see how we did:
SELECT full_name, suffix FROM #names
Results:
Full_name |
suffix |
Jane M. Smith |
NULL |
L Brian Brown |
NULL |
Gerhard J. Volzkoff, Jr., M.D. |
Jr., M.D. |
John J. Walters, Sr. |
Sr. |
James P. McPherson III |
III |
L. M Kim |
NULL |
Richard B. Johnson, IV |
IV |
Karen Hornsby |
NULL |
Bill Stanford JR |
JR |
I B. Prufen |
NULL |
Erika L Grey |
NULL |
J. B. Edwards |
NULL |
Things are going well in the suffix department, so let's move on to the first names. As mentioned earlier, some first names consist of a single letter a first initial that might be followed by a period. Let's populate the first_name column with such names. To do so, simply check the second character of the full_name: If it is blank or a period, the first name is one character long:
UPDATE #names SET First_name = CASE WHEN CHARINDEX('.', full_name) = 2 THEN SUBSTRING(full_name, 1, (CHARINDEX('.', full_name)-1)) WHEN CHARINDEX(' ', full_name) = 2 THEN SUBSTRING(full_name, 1, (CHARINDEX(' ', full_name)-1)) END
Finding the rest of the first names is easy. Simply grab the portion of the full name before the first space. Ensure that you update only the first_name columns that are NULL, and that the second character is not a space or period:
UPDATE #names SET First_name = SUBSTRING (full_name, 1, (CHARINDEX(' ', full_name) - 1)) WHERE first_name IS NULL AND SUBSTRING(full_name, 2, 1) NOT IN ('.', ' ')
Now that we're done with the easy parts, let's move on to something more involved. Middle names are somewhat more difficult because they're not on the extreme left or extreme right. Therefore, we need to work with all possible variations of first names, suffixes, and delimiters used in the name.
The middle name dilemma can be resolved if we put a little thought into it. There are several different combinations that can occur, as shown in the following table:
First name |
Middle name |
Format of the full name |
Initial with a period |
Initial with a period |
'%.%.%' |
Initial without a period |
Initial without a period |
'% % %' |
Initial with a period |
Initial without a period |
'%.% %' |
Initial without a period |
Initial with a period |
'% %.%' |
Name |
Initial with a period |
'% %.%' |
Name |
Initial without a period |
'% % %' |
Initial with a period |
Name |
'%.% %' |
Initial without a period |
Name |
'% % %' |
Name |
Name |
'% % %' |
So there are really four combinations of periods and spaces to check for. Because names with periods are also delimited with spaces, it really boils down to three cases, as shown in the following query:
UPDATE #names SET Middle_name = CASE WHEN full_name NOT LIKE '%.%.%' AND CHARINDEX('.', full_name) <> 0 AND CHARINDEX(' ', full_name) <> 0 AND CHARINDEX('.', full_name) > CHARINDEX(' ', full_name) THEN SUBSTRING(full_name, (CHARINDEX(' ', full_name) + 1), ((CHARINDEX('.', full_name) - CHARINDEX(' ', full_name)-1))) WHEN full_name NOT LIKE '% % %' AND CHARINDEX('.', full_name) <> 0 AND CHARINDEX(' ', full_name) <> 0 AND CHARINDEX(' ', full_name) > CHARINDEX('.', full_name) THEN SUBSTRING(full_name, (CHARINDEX('.', full_name) + 1), ((CHARINDEX(' ', full_name) - CHARINDEX('.', full_name)-1))) WHEN full_name LIKE '% % %' THEN SUBSTRING(full_name, (CHARINDEX(' ', full_name) + 1), CHARINDEX(' ', (SUBSTRING(full_name, (CHARINDEX(' ', full_name) + 1), (LEN(full_name) - CHARINDEX(' ', full_name)))))) ELSE NULL END WHERE Middle_name IS NULL
I realize that the above query might be overwhelming, so let's dissect it one step at a time. If a period occurs before the space (CHARINDEX(' ', full_name) > CHARINDEX('.', full_name) ), we have a case with a first initial with a period and the middle initial without a period. If so, we need to grab the portion from the period to the space, after chopping off the first initial. If the space occurs before the period, we have a first initial with no period and the middle initial with a period. In that situation, we need to grab the portion of the full name from space to period after chopping off the part before the first space. Finally, in the case of two periods or two spaces delimiting first and middle names, we can grab the portion from the first space to the second, again after chopping off the part before the first space. Execute a single SELECT statement against each SUBSTRING function mentioned in the above query to get a better understanding of how this all fits together.
The last part is getting the last names. This might seem like an awefully difficult task because we have to go through the first name, middle name, and any delimiters to get to the last name. However, recall that the REVERSE function, let's see the mirror image of the string. So for the names without a suffix, finding the last name is easy. All you have to do is grab the portion of the reversed string up to the first blank:
UPDATE #names SET Last_name = LTRIM(REVERSE(SUBSTRING(REVERSE(full_name), 1, CHARINDEX(' ', REVERSE(full_name))) )) WHERE Suffix IS NULL
What about the ones with the suffixes? Well, fortunately we already have the suffixes in the suffix column. Therefore, all we have to do is remove those suffixes from the full name column and then find the first occurrence of the space in the reversed full name. Check out the query that finds the last name for the persons with suffixes:
UPDATE #names SET Last_name = LTRIM(REVERSE(SUBSTRING(REVERSE( RTRIM(SUBSTRING(full_name, 1, (CHARINDEX(Suffix, full_name)-1)))) , 1, CHARINDEX(' ', REVERSE( RTRIM(SUBSTRING(full_name, 1, (CHARINDEX(Suffix, full_name)-1)))) )))) FROM #names WHERE Suffix IS NOT NULL
Now we can examine our data table again and see if it needs further polishing:
SELECT * FROM #names
Results:
full_name |
First_name |
middle_name |
last_name |
suffix |
Jane M. Smith |
Jane |
M |
Smith |
NULL |
L Brian Brown |
L |
Brian |
Brown |
NULL |
Gerhard J. Volzkoff, Jr., M.D. |
Gerhard |
J. |
Volzkoff, |
Jr., M.D. |
John J. Walters, Sr. |
John |
J. |
Walters, |
Sr. |
James P. McPherson III |
James |
P |
McPherson |
III |
L. M Kim |
L |
M |
Kim |
NULL |
Richard B. Johnson, IV |
Richard |
B |
Johnson, |
IV |
Karen Hornsby |
Karen |
|
Hornsby |
NULL |
Bill Stanford JR |
Bill |
Stanford |
Stanford |
JR |
I B. Prufen |
I |
B |
Prufen |
NULL |
Erika L Grey |
Erika |
L |
Grey |
NULL |
J. B. Edwards |
J |
B. |
Edwards |
NULL |
The only slight problem is that some of the names have kept their delimitersperiods or commas. To make the data more consistent, we can get rid of any delimiters in first, middle, or last names:
UPDATE #names SET Last_name = LEFT(Last_name, (LEN(Last_name) - 1)) WHERE RIGHT(RTRIM(Last_name), 1) = ',' UPDATE #names SET First_name = LEFT(First_name, (LEN(First_name) - 1)) WHERE RIGHT(RTRIM(First_name), 1) = '.' UPDATE #names SET Middle_name = LEFT(Middle_name, (LEN(Middle_name) - 1)) WHERE RIGHT(RTRIM(Middle_name), 1) = '.'
Summary
In this article, I demonstrated a real-world solution that lets you split names into first name, middle name, last name, and suffixes. You can apply this solution to your own name dilemmas as long as you know all the anomalies that you might expect. Although this solution isn't error-proof for all possible names, it gives you a good head start for developing your own stored procedures and user-defined functions that will normalize the name data.