Separating Name & Address

jdub21

New Member
Joined
Sep 19, 2022
Messages
30
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
Hey Excel Gurus - Got a puzzling one - I am trying to separate location name from the address. I have tried using text to column but because the entries are different, it is never-ending. I need assistance please. I need to be able to cut anything before the address and place into a new cell.... Any help would be great.

Atria Senior Living - North Point - ASL010282 100 Somerby Drive
DRM/Ross #1874 310 East Martintown Road suite 300
Dollar General Store Number 13427 177 Main Street
Spirit Halloween 1945 West Palmetto Street
Buffalo Wild Wings 2625 Broad Street
 

Excel Facts

Convert text numbers to real numbers
Select a column containing text numbers. Press Alt+D E F to quickly convert text to numbers. Faster than "Convert to Number"
Bump - Does anyone have a possible solution for my dilemma?
 
Upvote 0
This is a very complex thing for which I seldom see good solutions for. The reason is because the data seldoms follows any sort of "rules" or "patterns" (at least not consistently!).
The thing to understand about programming is it is not "magic". On the contrary, it is very literal. It does only exactly what you tell it to (it cannot think on its own).

For problems like these, see if you can come up with some "logic" or "rules" (in plain English, not in programming), to instruct what should happen in different scenarios.
If you cannot come up with those "rules" in plain English (non-technical), then you cannot program (it would be like trying to build a house without a blueprint).

For example, you could tell it to "split it before the first number", and that would work in many cases, but would only be correct for some of the options.
You could add more rules, to try to identify different situations, but inevitably you will always have exceptions.

The best I have seem people do is come up with some rules that might work correctly on 80 - 90% of their data, but they still need to go through each row and make the corrections where necessary.

If you can come up with some "rules" (in plain English) for us to program to, we can probably do that for you.
But I don't think you are going to find a handful of rules that will handle the vast majority of your records correctly.
You can only do so much with "bad/unformatted" data.
 
Upvote 0
so I have been using this for the time being

=LEFT(A1,FIND(" ",A1,FIND(" ",A1)+1)-1)

and making adjustments accordingly but is there a way to extract the words upto the first numerical value?? I understand that there will still need to be some manual scrubbing but in a given month I am scrubbing through 20-30k records. I indicated below that section that I am looking to extract.

I am also open if there is a solution in PowerBI or PowerQuery instead.

Atria Senior Living - North Point - ASL010282 100 Somerby Drive
DRM/Ross #1874 310 East Martintown Road suite 300
Dollar General Store Number 13427 177 Main Street
Spirit Halloween 1945 West Palmetto Street
Buffalo Wild Wings 2625 Broad Street
 
Upvote 0
Joe - Again a life saver. I just tested this out and works like a charm. Yes I have to do some cleaning but there is at least 15k records that I wont have to manually touch now.
 
Upvote 0
This is always going to be a sloppy thing with addresses.
MrExcelPlayground12.xlsx
AB
1Atria Senior Living - North Point - ASL010282 100 Somerby DriveAtria Senior Living - North Point - ASL
2DRM/Ross #1874 310 East Martintown Road suite 300DRM/Ross #
3Dollar General Store Number 13427 177 Main StreetDollar General Store Number
4Spirit Halloween 1945 West Palmetto StreetSpirit Halloween
5Buffalo Wild Wings 2625 Broad StreetBuffalo Wild Wings
Sheet8
Cell Formulas
RangeFormula
B1:B5B1=TRIM(LEFT(A1,MIN(IFERROR(SEARCH(SEQUENCE(10,1,0),A1),9999))-1))
 
Upvote 0
You are welcome.
Glad we were able to help!
 
Upvote 0
Thank you everyone for your help on this. Now one last question.

What about reversing the formula to where it starts at the numerical value? This way I can trim the name into one cell and then the address into another. Again I know that there will be some manual fixing but 1k records will be better than 30k records.
 
Upvote 0

Forum statistics

Threads
1,224,827
Messages
6,181,199
Members
453,022
Latest member
RobertV1609

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