Extract value between text and character

lcm7721

New Member
Joined
Dec 5, 2018
Messages
7
Hello,
I need to extract the route number, which can be between 1 to 3 digits, see example below:

Route 1-1 South
Route 26-7 Ludlam
Route 29-2 West
Route A 101-1 North

As you can see the Route value and (-) dash character are constant.

Is there a formula in excel and/or PowerBi I can use to extract these values and get only the route numbers?

Expected results:
1
26
29
101

Thanks,
lcm
 

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
Try this

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:221.47px;" /><col style="width:76.04px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="color:#333333; font-family:Verdana; font-size:9pt; ">Route 1-1 South</td><td style="text-align:right; ">1</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td style="color:#333333; font-family:Verdana; font-size:9pt; ">Route 26-7 Ludlam</td><td style="text-align:right; ">26</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td style="color:#333333; font-family:Verdana; font-size:9pt; ">Route 29-2 West</td><td style="text-align:right; ">29</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td style="color:#333333; font-family:Verdana; font-size:9pt; ">Route A 101-1 North</td><td style="text-align:right; ">101</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></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 >B1</td><td >=RIGHT(SUBSTITUTE(REPLACE(A1,FIND("-",A1),100,"")," ", REPT(" ",99)),99)+0</td></tr></table></td></tr></table>
 
Upvote 0
Perfect, thank you!!!


Try this

AB
1Route 1-1 South1
2Route 26-7 Ludlam26
3Route 29-2 West29
4Route A 101-1 North101

<colgroup><col style="font-weight:bold; width:30px; "><col style="width:221.47px;"><col style="width:76.04px;"></colgroup><tbody>
</tbody>

CellFormula
B1=RIGHT(SUBSTITUTE(REPLACE(A1,FIND("-",A1),100,"")," ", REPT(" ",99)),99)+0

<tbody>
</tbody>

<tbody>
</tbody>
 
Upvote 0
or

Code:
[SIZE=1]// Table1
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Extract = Table.AddColumn(Source, "Text Between Delimiters", each Text.BetweenDelimiters([src], " ", "-", {1, RelativePosition.FromEnd}, 0), type text)
in
    Extract[/SIZE]
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,571
Messages
6,120,302
Members
448,954
Latest member
EmmeEnne1979

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