Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Extracting Street Numbers from an Address.

Extracting Street Numbers from an Address

by Allen Wyatt
(last updated February 25, 2016)

5

Allan has a list of several hundred names and addresses. The street addresses range from Main Street, 123 Main Street, US RT 2, or 187 South Elm St. He would like to break out the street number from the addresses. So the address 123 Main Street would end up with "123" in one cell and "Main Street" in another. If there is no street number, then nothing ends up in the street number column. The Text to Columns tool will not work and he wonders how he can do this.

In a perfect world, Excel would allow you to easily split the numbers from the street names. Since this option doesn't exist, you have a couple of choices. The most time-consuming option involves adding an additional column and retyping the data. If, however, you would like to save some time, you can use a variety of formulas to accomplish the task.

Assuming the list of addresses is in column A (beginning in cell A1), you could use a formula similar to the following to pull out the numeric portion of the address:

=IF(ISERROR(VALUE(LEFT(A1,1))),"",LEFT(A1,FIND(" ",A1)-1))

Assuming you put the formula in cell B1, you could then use a different formula to derive the non-numeric portion of the address:

=TRIM(RIGHT(A1,LEN(A1)-LEN(B1)))

Note that this approach does have a limitation. Some addresses, especially in major metropolitan areas, use a format such as 152-33 Bell Blvd. The formulas above will work for these addresses, but if the alternative, 152 33 Bell Blvd., is used, the formula will parse incorrectly. Unless you want to buy a professionally developed address parsing program, the formulas above and a quick eyeball scan of the results should be adequate.

Another formula works in this case. Assuming your address is in cell A2, enter the following formula into cell B2:

=IF(ISNUMBER(VALUE(LEFT(A2,1))),VALUE(LEFT(A2,FIND(" ",A2)-1)),"")

This formula is saying, "If the first character is not a number, leave the cell blank. Otherwise, give me all of the characters on the left out to, but not including, the first space." You can then use the result of this formula to pull out the non-numeric portion of the address:

=IF(B2="",A2,MID(A2,FIND(" ",A2)+1,99))

Another approach is to use an array formula. Here again, assuming your address is in cell A2, you can use the following:

=IF(ISNUMBER(1*MID(A2,ROW($1:$1),1)) = TRUE,LEFT(A2,FIND(" ",A2,1)),"")

Since this is an array formula you need to enter it by using Ctrl+Shift+Enter. The result is that the formula returns the leading numeric portion of the address. You can then determine the non-numeric portion by using the following array formula:

=IF(ISNUMBER(1*MID(A2,ROW($1:$1),1))=TRUE,RIGHT(A2,LEN(A2)-FIND(" ",A2,1)),A2)

Finally, the following macro can be used to break-out the street address from the street name.

Sub GetStreetNum()
    Dim sStreet As String
    Dim J As Integer
    Dim iNum As Integer

    For Each cell In Selection
        sStreet = cell.Value
        J = InStr(sStreet, " ")
        If J > 0 Then
            iNum = Val(Left(sStreet, J))
            If iNum > 0 Then
                cell.Offset(0, 1).Value = iNum
                sStreet = Trim(Mid(sStreet, J, Len(sStreet)))
            End If
        End If
        cell.Offset(0, 2).Value = sStreet
    Next
End Sub

To use this macro, simply select the range of cells that contain your addresses and then run it. The leading numeric portion of the address will appear in the cell to the right of each address and the balance of the address will be placed in the cell to the right of that. (So you should make sure that there are two blank columns to the right of the addresses you select.)

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8031) applies to Microsoft Excel 2007, 2010, and 2013. You can find a version of this tip for the older menu interface of Excel here: Extracting Street Numbers from an Address.

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

Capitalizing Just a Surname

Changing the capitalization of text is, believe it or not, a common task in Excel. Common or not, it can be frustrating to ...

Discover More

Printing a Range of Pages

If your worksheet, when printed, requires more than a single page to print, you may want to only print a range of the ...

Discover More

Renaming a Workbook

Renaming a workbook from within Excel can seem daunting, but it is actually quite easy. All you need to do is use the Open ...

Discover More

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

More ExcelTips (ribbon)

Pulling Formulas from a Worksheet

The formulas in your worksheet can be displayed (instead of formula results) by a simple configuration change. You can then ...

Discover More

Listing Combinations

You can easily use the COMBIN worksheet function to determine the number of combinations that can be made from a given number ...

Discover More

Counting Records Matching Multiple Criteria

Excel provides worksheet functions that make it easy to count things. What if you want to count records that match more than ...

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. 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 5?

2016-08-10 16:44:32

Chris

Hello, I have a cell in Excel that contains the following address: 123 Main Street, Los Angeles, CA 90001.

I would like to extract just 123 Main Street so that it is in its own cell and just Los Angeles, CA 90001 so that is in its own cell.

Can you help me with the formulas I will need to do that? Thanks!


2016-07-23 03:19:39

Michael (Micky) Avidan

@To whom it may concern.
In order to retrieve the Numeric part, no matter where it is locataed within the string - I would use the Array Formula suggeted in the following picture:
(see Figure 1 below)
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2017)
ISRAEL

Figure 1. Retrieve the Numeric part from a string


2016-07-21 12:20:09

Dario

HI Mr Wyatt,
I wonder if you can help me.
I am trying to extract numbers from a cell that contains numbers and text.
However some of the text has numbers on the begining and the end of the text and those numbers I wont to leave with the text as they are part of a name. All the other numbers I want to extract to the cell on the right of the colon. In this case it is two numbers always.

Flynnh68 : 23 pls rg xx
mike75 : 12 rg plz phone grid
fdane14 : 26 rg pls
65elle : 36 rg
tornado : 39 rg plz
gLISS_2011 : 51 rg plz
vegaswiz : 64 rg pls x
suelovs : 67 rg plz
sm12345 : 71 rg pl
shaz73 : 73 rg plz

I think I am on the right path with this: left(Xxx,instr(Xxx,":")+1)

but not sure, if you could have a look and get back to me that would be most appreciated.

Kind Regards,
Dario.
ps:Really enjoy your Excel Tips - Thanks.


2015-06-24 10:07:26

Bob

Thanks (again)! Your tips and sample formulas have saved me hours and hours of time.


2013-08-12 09:43:43

Bryan

Those "array" formulas don't make any sense. Row($1:$1) simply returns the number 1. MID(x,1,1) is the same as Left(x,1). Multiplying by 1 simply coerces a text value into a value. The = True is redundant. There are no arrays involved, so if you press Enter or Ctrl+Shift+Enter you will get the same result.

So if you simplify them, you simply get the same thing as your first formula, except that you forgot the -1 in the find, so you are including the trailing space. Am I missing something?

Additionally, I think you are saying that your third formula should work for addresses in the form of "152 33 Bell Blvd", but it doesn't. It gives the same result as the first formula, but throws an error when you have an address in the form "152-33 Bell Blvd" because of the extra VALUE formula in the True Part of the IF formula.


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu 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.