Formula to extract City, State & Zip from address

tbream

New Member
Joined
Jul 19, 2019
Messages
2
I have a series of addresses that are in the following format:

273 Winding Road Boyertown OH, 19512
16 Penn Lane Wayne PA, 19087
519 Conshocken State Rd Happy Valley PA, 15208

What separates the city from the address line is two spaces. I'm trying to figure out how to pull the City, State and Zip from this individually by formula. Any suggestions?

Thank you
 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
To add to the above, the auto-editor in this thread removed them, but just to be clear, in my data I have two spaces between the address line and the city. For example, per the sample listed, there are two spaces between Road and Boyertown, two spaces between Lane and Wayne, and two spaces between Rd and Happy.
 
Upvote 0
You can use Power Query.

Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    ExtractI = Table.TransformColumns(Source, {{"Address", each Text.AfterDelimiter(Text.Trim(_), "  "), type text}}),
    SplitI = Table.SplitColumn(ExtractI, "Address", Splitter.SplitTextByDelimiter(", ", QuoteStyle.Csv), {"Address.1", "Address.2"}),
    SplitII = Table.SplitColumn(SplitI, "Address.1", Splitter.SplitTextByEachDelimiter({" "}, QuoteStyle.Csv, true), {"Address.1.1", "Address.1.2"}),
    Rename = Table.RenameColumns(SplitII,{{"Address.1.1", "City"}, {"Address.1.2", "State"}, {"Address.2", "Zip"}})
in
    Rename







<caption>LEGO HTML</caption><colgroup><col style="width: 54px"><col width="338"><col width="124"><col width="142"></colgroup><tbody>
[TH="bgcolor: #A6A6A6"] C [/TH]
[TH="bgcolor: #A6A6A6"] D [/TH]
[TH="bgcolor: #A6A6A6"] E [/TH]

[TH="bgcolor: #A6A6A6"] 1 [/TH]
[TD="bgcolor: #FFFFFF"] City [/TD]
[TD="bgcolor: #FFFFFF"] State [/TD]
[TD="bgcolor: #FFFFFF"] Zip [/TD]

[TH="bgcolor: #A6A6A6"] 2 [/TH]
[TD="bgcolor: #FFFFFF"] Boyertown [/TD]
[TD="bgcolor: #FFFFFF"] OH [/TD]
[TD="bgcolor: #FFFFFF"] 19512 [/TD]

[TH="bgcolor: #A6A6A6"] 3 [/TH]
[TD="bgcolor: #FFFFFF"] Wayne [/TD]
[TD="bgcolor: #FFFFFF"] PA [/TD]
[TD="bgcolor: #FFFFFF"] 19087 [/TD]

[TH="bgcolor: #A6A6A6"] 4 [/TH]
[TD="bgcolor: #FFFFFF"] Happy Valley [/TD]
[TD="bgcolor: #FFFFFF"] PA [/TD]
[TD="bgcolor: #FFFFFF"] 15208 [/TD]

</tbody>
 
Upvote 0
Another way using formulas,
<table valign="top"><caption>LEGO HTML</caption><col width="54"><col width="314"><col width="108"><col width="105"><col width="142">
<tr><td></td><th style="background-color:rgb(166, 166, 166)"><font style="color:rgb(0, 0, 0)">A</font></th><th style="background-color:rgb(166, 166, 166)"><font style="color:rgb(0, 0, 0)">B</font></th><th style="background-color:rgb(166, 166, 166)"><font style="color:rgb(0, 0, 0)">C</font></th><th style="background-color:rgb(166, 166, 166)"><font style="color:rgb(0, 0, 0)">D</font></th></tr>
<tr><th style="background-color:rgb(166, 166, 166)"><font style="color:rgb(0, 0, 0)">1</font></th><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">Address</font></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">Zip</font></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">State</font></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">City</font></td></tr>
<tr><th style="background-color:rgb(166, 166, 166)"><font style="color:rgb(0, 0, 0)">2</font></th><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">273 Winding Road Boyertown OH, 19512</font></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">19512</font></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">OH</font></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">Boyertown</font></td></tr>
<tr><th style="background-color:rgb(166, 166, 166)"><font style="color:rgb(0, 0, 0)">3</font></th><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">16 Penn Lane Wayne PA, 19087</font></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">19087</font></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">PA</font></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">Wayne</font></td></tr>
<tr><th style="background-color:rgb(166, 166, 166)"><font style="color:rgb(0, 0, 0)">4</font></th><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">519 Conshocken State Rd Happy Valley PA, 15208</font></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">15208</font></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">PA</font></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">Happy Valley</font></td></tr></table><table style="width:100%" valign="top"><caption>Worksheet Formulas</caption><tr><th style="background-color:rgb(166, 166, 166)"><font style="color:rgb(0, 0, 0)">Cell</font></th><th style="background-color:rgb(166, 166, 166)"><font style="color:rgb(0, 0, 0)">Formula</font></th></tr><tr><th style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">B2</font></th></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">=RIGHT(A2,5)</font></td></tr><tr><th style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">C2</font></th></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">=RIGHT(TRIM(SUBSTITUTE(SUBSTITUTE(A2,B2,""),",","")),2)</font></td></tr><tr><th style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">D2</font></th></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">=MID(A2,SEARCH(" ",A2)+2,SEARCH(C2,A2)-SEARCH(" ",A2)-3)</font></td></tr><tr><th style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">B3</font></th></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">=RIGHT(A3,5)</font></td></tr><tr><th style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">C3</font></th></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">=RIGHT(TRIM(SUBSTITUTE(SUBSTITUTE(A3,B3,""),",","")),2)</font></td></tr><tr><th style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">D3</font></th></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">=MID(A3,SEARCH(" ",A3)+2,SEARCH(C3,A3)-SEARCH(" ",A3)-3)</font></td></tr><tr><th style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">B4</font></th></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">=RIGHT(A4,5)</font></td></tr><tr><th style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">C4</font></th></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">=RIGHT(TRIM(SUBSTITUTE(SUBSTITUTE(A4,B4,""),",","")),2)</font></td></tr><tr><th style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">D4</font></th></td><td style="background-color:rgb(255, 255, 255)"><font style="color:rgb(0, 0, 0)">=MID(A4,SEARCH(" ",A4)+2,SEARCH(C4,A4)-SEARCH(" ",A4)-3)</font></td></tr></table>
 
Last edited:
Upvote 0
Put these formulas in the indicated cells and then copy them down to the end of your data...

Code:
B2: =RIGHT(A2,5)

C2: =MID(A2,LEN(A2)-8,2)

D2: =MID(LEFT(A2,LEN(A2)-10),FIND("  ",A2)+2,99)
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,164
Messages
6,170,444
Members
452,326
Latest member
johnshaji

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top