Help to split address into columns

darrenmccoy

New Member
Joined
Mar 26, 2019
Messages
37
Office Version
  1. 2019
Hi Experts, Could you help me with formulas to split addresses?

I need to count the spaces from the left and split the street number into column B, then split the street name(s) into column C, then count the spaces from the right and split the the street type into column D.

ADDRESSSTREET NUMBERSSTREET NAMESTREET TYPE
478 ST KILDA RD478ST KILDARD
23 HAMPTON AVE23HAMPTONAVE
45 WEST LANGHAM RD45WEST LANGHAMRD
42 JACKSON ST42JACKSONST

<colgroup><col><col><col><col></colgroup><tbody>
</tbody>
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
You can do this with Power Query.

Code:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    SplitRight = Table.SplitColumn(Source, "ADDRESS", Splitter.SplitTextByEachDelimiter({" "}, QuoteStyle.Csv, true), {"ADDRESS.1", "ADDRESS.2"}),
    SplitLeft = Table.SplitColumn(SplitRight, "ADDRESS.1", Splitter.SplitTextByEachDelimiter({" "}, QuoteStyle.Csv, false), {"ADDRESS.1.1", "ADDRESS.1.2"}),
    Rename = Table.RenameColumns(SplitLeft,{{"ADDRESS.1.1", "Street Numbers"}, {"ADDRESS.1.2", "Street Name"}, {"ADDRESS.2", "Street Type"}})
in
    Rename
 
Upvote 0
Thanks, but I dont know how to use power query, I do however know how to use formulas, can you help with that?
 
Upvote 0
Try this formulas


Book1
ABCD
1ADDRESSSTREET NUMBERSSTREET NAMESTREET TYPE
2478 ST KILDA RD478ST KILDARD
323 HAMPTON AVE23HAMPTONAVE
445 WEST LANGHAM RD45WEST LANGHAMRD
542 JACKSON ST42JACKSONST
Sheet1
Cell Formulas
RangeFormula
B2=LEFT(SUBSTITUTE(A2," ",REPT(" ",99)),99)+0
C2=MID(A2,LEN(B2)+2,LEN(A2)-LEN(B2)-LEN(D2)-2)
D2=TRIM(RIGHT(SUBSTITUTE(A2," ",REPT(" ",99)),99))
 
Upvote 0
Try this formulas

ABCD
1ADDRESSSTREET NUMBERSSTREET NAMESTREET TYPE
2478 ST KILDA RD478ST KILDARD
323 HAMPTON AVE23HAMPTONAVE
445 WEST LANGHAM RD45WEST LANGHAMRD
542 JACKSON ST42JACKSONST

<colgroup><col style="width: 25pxpx"><col><col><col><col></colgroup><thead>
</thead><tbody>
</tbody>


Worksheet Formulas
CellFormula
B2=LEFT(SUBSTITUTE(A2," ",REPT(" ",99)),99)+0
C2=MID(A2,LEN(B2)+2,LEN(A2)-LEN(B2)-LEN(D2)-2)
D2=TRIM(RIGHT(SUBSTITUTE(A2," ",REPT(" ",99)),99))

<thead>
</thead><tbody>
</tbody>

<tbody>
</tbody>

This works very well, except when I get to an ADDRESS with characters, such as <style type="text/css"><!--td {border: 1px solid #ccc;}br {mso-data-placement:same-cell;}--></style>10/5-7 PRINCES ST it breaks the formula and produces the result
ErrorFunction ADD parameter 1 expects number values. But '1/2A ' is a text and cannot be coerced to a number.

Could you help edit the formula so it supports address with a slash or dash such as:

10/5-7 PRINCES ST
12/25 PRINCES ST
4-5 PRINCES ST

Thank you!

 
Upvote 0
You could try these.

<b>Split Address</b><br /><br /><table border="1" cellspacing="0" cellpadding="0" style="font-family:Arial,Arial; font-size:8pt; background-color:#ffffff; padding-left:2pt; padding-right:2pt; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:169px;" /><col style="width:140px;" /><col style="width:127px;" /><col style="width:108px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td></tr><tr style="height:21px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="font-size:10pt; ">ADDRESS</td><td style="font-size:10pt; text-align:right; ">STREET NUMBERS</td><td style="font-size:10pt; ">STREET NAME</td><td style="font-size:10pt; ">STREET TYPE</td></tr><tr style="height:21px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="font-size:10pt; ">478 ST KILDA RD</td><td style="font-size:10pt; text-align:right; ">478</td><td style="font-size:10pt; ">ST KILDA</td><td style="font-size:10pt; ">RD</td></tr><tr style="height:21px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="font-size:10pt; ">23 HAMPTON AVE</td><td style="font-size:10pt; text-align:right; ">23</td><td style="font-size:10pt; ">HAMPTON</td><td style="font-size:10pt; ">AVE</td></tr><tr style="height:21px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td style="font-size:10pt; ">45 WEST LANGHAM RD</td><td style="font-size:10pt; text-align:right; ">45</td><td style="font-size:10pt; ">WEST LANGHAM</td><td style="font-size:10pt; ">RD</td></tr><tr style="height:21px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td style="font-size:10pt; ">42 JACKSON ST</td><td style="font-size:10pt; text-align:right; ">42</td><td style="font-size:10pt; ">JACKSON</td><td style="font-size:10pt; ">ST</td></tr><tr style="height:21px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td style="font-size:10pt; ">10/5-7 PRINCES ST</td><td style="font-size:10pt; text-align:right; ">10/5-7</td><td style="font-size:10pt; ">PRINCES</td><td style="font-size:10pt; ">ST</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b>Spreadsheet Formulas</b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >B2</td><td >=LEFT(A2,FIND<span style=' color:008000; '>(" ",A2)</span>-1)</td></tr><tr><td >C2</td><td >=MID(A2,LEN<span style=' color:008000; '>(B2)</span>+2,LEN<span style=' color:008000; '>(A2)</span>-LEN<span style=' color:008000; '>(B2&D2)</span>-2)</td></tr><tr><td >D2</td><td >=TRIM(RIGHT<span style=' color:008000; '>(SUBSTITUTE<span style=' color:#0000ff; '>(A2," ",REPT<span style=' color:#ff0000; '>(" ",20)</span>)</span>,20)</span>)</td></tr></table></td></tr></table>
 
Upvote 0
Change this

=LEFT(SUBSTITUTE(A2," ",REPT(" ",99)),99)+0

For this

=TRIM(LEFT(SUBSTITUTE(A2," ",REPT(" ",99)),99))
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,551
Messages
6,114,272
Members
448,558
Latest member
aivin

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