Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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.
Written by Allen Wyatt (last updated March 9, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
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))
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.)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8031) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Extracting Street Numbers from an Address.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
When processing huge amounts of data, it can be a challenge to figure out how to derive the aggregate values you need. ...
Discover MoreWhen processing data in a worksheet, you may have a need to know what the smallest (lowest) even value in a range is. You ...
Discover MoreIf you want to limit what is returned by a formula to something between lower and upper boundaries, the solution is to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-03-10 22:33:36
Peter
Since the fig does not seem to have loaded, the following is a plain text version, starting in cell A1
Pattern FormulaText Address: 222/123 32nd Avenue
\d*\s =TRIM(RegExpExtract(D1,A2,1)) Number: 123
\s\w.* =TRIM(RegExpExtract(D1, A3,1)) Street: 32nd Avenue
2024-03-10 22:27:26
Peter
I played around with regular expressions to break down an address like 22/123 32nd Avenue.
VBA provides CreateObject("VBScript.RegExp"). I googled and found the proprietary site https://www.ablebits.com/office-addins-blog/excel-regex-formulas/ which has a free download.
To get the street number and street name in two cells requires two references to their RegExpExtract(). If I could figure out one pattern that covers both, I would only need one since it can return an array.
[{Fig}]
2024-03-09 16:03:06
J. Woolley
My Excel Toolbox includes the following functions that are useful for manipulating the text described in this Tip:
=Between(Text, BeginAfter, EndBefore, [CaseSensitive], [Direction])
=IsLike(Text, Pattern)
Between(...) is like a combination of TEXTBEFORE and TEXTAFTER.
IsLike(...) uses VBA's Like operator as follows:
Function IsLike(Text As String, Pattern As String) As Boolean
IsLike = Text Like Pattern
End Function
The following formulas produce the same results as Alex Blakenburg's formulas but do not require MS365 or O2021 (i.e., Excel 2021+):
=IF(IsLike(A1,"#*"),Between(A1,""," "),"")
=IF(B1="",A1,Between(A1," ",""))
Here is a simpler version of the last formula above:
=TRIM(Between(A1,B1,""))
See https://sites.google.com/view/MyExcelToolbox/
2024-03-09 06:33:33
Alex Blakenburg
Converting those to MS365 or O2021 TextBefore & TextAfter gives,
=IF(ISERROR(VALUE(LEFT(A1,1))),"",TEXTBEFORE(A1," "))
=IF(B1="",A1,TEXTAFTER(A1," "))
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments