Home > Articles > Data > SQL Server

Normalizing Name Data in SQL Server

Need a good head start for developing your own stored procedures and user-defined functions that will normalize name data? This article by Baya Pavliashvili demonstrates a real-world example of denormalized data that contains individuals’ names.
Like this article? We recommend

Like this article? We recommend

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 rules—they'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 way—a 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 delimiters—periods 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.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020