Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Extracting a State and a ZIP Code.

Extracting a State and a ZIP Code

by Allen Wyatt
(last updated June 18, 2020)

4

Dan has a column of cells and each cell contains three items: city, state and ZIP Code. (All three are in a single cell, much like you see in an address line.) Some of the ZIP Codes are five digits and some are nine. Dan needs to pull both the two-character state and the five-digit ZIP Code into their own cells, to the right of the current data. Dan knows he can use the Text to Columns tool, but feels that it involves a lot of work since he would need to deal with multiple-word city names and commas. Dan can't help but think there may be a formulaic approach that would be easier.

There needs to be a few assumptions made about the data in order to make any recommendations. Let's assume, for example, that all the data is in this format:

My Town, CA 98765-4321

The portion from the dash onward (the trailing part of the ZIP Code) is optional, but the position of the comma is static—it always follows the name of the town—and the state always consists of two characters. In this case it is easy to devise two formulas that extract the state abbreviation and the first five digits of the ZIP Code:

=MID(A1,FIND(",",A1)+2,2)
=MID(A1,FIND(",",A1)+5,5)

Both formulas key on the comma; it serves as a delimiter between the city and the two items really want. If there is no comma in the data or if there are multiple commas, then the formulas won't return the desired information.

The formulas also assume that there are no extra spaces in your data; at most there is a single space after the comma and between the state and ZIP Code. This is, of course, easy enough to enforce—just use Find and Replace to replace two spaces with a single space anywhere in your worksheet.

Of course, if your data is this structured, you can still rely on the Text to Columns tool to do your work. All you need to do is run the tool and split your data based on the comma. This will leave the city in one cell and put the state and ZIP Code together in the next cell. Then you can use Text to Columns again, this time on the second cell (not the city name) and divide the contents based on the space.

If your data is not that structured—perhaps it has multiple commas in the address or extra spaces—then an entirely different approach is called for. To deal with this the basic technique involves trimming the data to remove extraneous spaces (leading, trailing, and internal), then determining the location of the last space and the second-to-last space.

You can pull out the five digits in the ZIP Code, which is defined as immediately following the last space in the data, by using this formula:

=MID(TRIM(A1),FIND(CHAR(1),SUBSTITUTE(TRIM(A1)," ",
CHAR(1),LEN(TRIM(A1))-LEN(SUBSTITUTE(TRIM(A1)," ",""))))+1,5)

The two-character state abbreviation can be returned by pulling out the two characters immediately following the second-to-last space:

=MID(TRIM(A1),FIND(CHAR(1),SUBSTITUTE(TRIM(A1)," ",CHAR(1),
LEN(TRIM(A1))-LEN(SUBSTITUTE(TRIM(A1)," ",""))-1))+1,2)

If your data is even less structured—perhaps it includes addresses that don't all have two-character state abbreviations (N.J. instead of NJ)—then you would best be served to use a macro to divide up the data. The reason for this is that VBA has a much richer set of text handling functions than what you can do using Excel formulas. The following macro creates a user-defined function that can return either the state or ZIP Code:

Function GetStateZIP(rstrAddress As String, iAction As Integer) As String
    Dim arr As Variant
    Dim sState As String
    Dim sZIP As String
    Dim J As Integer
    Dim K As Integer

    Application.Volatile
    rstrAddress = Trim(rstrAddress)
    If Len(rstrAddress) = 0 Then Exit Function

    sState = "?"
    sZIP = "?"
    For J = Len(rstrAddress) To 1 Step -1
        If Mid(rstrAddress, J, 1) = " " And sZIP = "?" Then
            sZIP = Mid(rstrAddress, J + 1, 5)
            rstrAddress = Trim(Left(rstrAddress, J))
            For K = Len(rstrAddress) To 1 Step -1
                If Mid(rstrAddress, K, 1) = " " And sState = "?" Then
                    sState = Mid(rstrAddress, K + 1, 20)
                    rstrAddress = Trim(Left(rstrAddress, K))
                End If
            Next K
        End If
    Next J
    If iAction = 1 Then
        GetStateZIP = sState
    End If
    If iAction = 2 Then
        GetStateZIP = sZIP
    End If
End Function

To use this function, simply provide a cell reference and either 1 (if you want the state) or 2 (if you want the ZIP Code). Here is an example of requesting the ZIP Code for whatever address is in cell A1:

=GetStateZIP(A1,2)

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9598) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Extracting a State and a ZIP Code.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Updating an Entire TOC from a Macro

The TOC (Table of Contents) is generated by a field. This field may be updated in a macro using a single command line.

Discover More

Spell Check Misses Misspelled Words

If you do a spelling check and notice that Word doesn't catch a word that you know is misspelled, it is easy to get ...

Discover More

Engraving Text

Word allows you to format your text in a number of different ways. One rather esoteric way to format your text is by ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (menu)

Understanding Operators

At the heart of working with Excel is the process of creating formulas that calculate results based on information within ...

Discover More

Determining a Simple Moving Average

A moving average can be a great way to analyze a series of data points that you've collected over time. Setting up a ...

Discover More

Solving Simultaneous Equations

One branch of mathematics allows you to work with what are called "simultaneous equations." Working with this type of ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is nine minus 2?

2020-06-30 15:13:55

Daryl

Relating to Extracting State, Zip Code Or City From an Address In Excel.
I'm working with data where people sometimes enter the city, state and zip in the address line. The delimiter is a space for all information in the address line.
I have code that works if the city and state are only one word. The issue arises when the city and/or state are two or more words.
e.g. New Mexico, South Carolina etc... for state
e.g. New Haven, New London etc... for city
When a person types the information sometimes there is just the street address sometimes there is also the city, state and other times there is also the city, state and zip. There is no consistency in what is on the address line.
Any thoughts?


2019-12-03 14:49:04

Mike

iI had a text entry in F2, containing a mix of Canadian and US postal codes (5 and 9 digit zips) and used the following to extract state or province, figuring where the last space would fall in the address to determine where the state would be:

=IF(LEFT(RIGHT(F2,4),1)=" ",LEFT(RIGHT(F2,10),2),IF(LEFT(RIGHT(F2,6),1)=" ",LEFT(RIGHT(F2,8),2),LEFT(RIGHT(F2,13),2)))


2016-09-13 02:49:47

Mary Caller

I came across this tip and it also explains a similar formula. https://www.sheetzoom.com/xlstools/tlln01 Maybe this can give you a clue.


2015-09-29 16:46:02

Gail

Great suggestions, but I just need to separate county and state...but there is no comma just a space....and some of the counties include a space like San Diego CA...etc.

so how can i separte into two columns, the county and then the state?


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.