Scrape text based on last special character

Greymud

New Member
Joined
Feb 19, 2016
Messages
42
Office Version
  1. 365
  2. 2013
Platform
  1. Windows
I have a column of alphanumeric data with sections seperated by hyphens. I need to scrape the text after the last hyphen - but there are a variable number of hyphens in the field.

Example:

LOCATION
LINCOLN (WING01-FLR01-RM15-LAPTOP)
SIOUX CITY (WING02-FLR03-RM27-SEAT2-PHONE)
FRAMINGHAM (WING01-FLRB2-RM52-AUDTITORIUM-SEAT2-CEILING-PROJECTOR)

Thanks again!
 

Excel Facts

Create a chart in one keystroke
Select the data and press Alt+F1 to insert a default chart. You can change the default chart to any chart type
For an entry in cell A2, try this formula:
Excel Formula:
=TRIM(RIGHT(SUBSTITUTE(A2,"-",REPT(" ",100)),100))

If you want to get rid of the last character ")", you can modify it like this:
Excel Formula:
=TRIM(LEFT(RIGHT(SUBSTITUTE(A2,"-",REPT(" ",100)),100),99))
 
Upvote 0
Solution
How about
+Fluff v2.xlsm
AB
1LOCATION
2LINCOLN (WING01-FLR01-RM15-LAPTOP)LAPTOP
3SIOUX CITY (WING02-FLR03-RM27-SEAT2-PHONE)PHONE
4FRAMINGHAM (WING01-FLRB2-RM52-AUDTITORIUM-SEAT2-CEILING-PROJECTOR)PROJECTOR
Data
Cell Formulas
RangeFormula
B2:B4B2=SUBSTITUTE(TRIM(RIGHT(SUBSTITUTE(A2,"-",REPT(" ",100)),100)),")","")
 
Upvote 0
A VBA custom function.

Book1
AB
1LINCOLN (WING01-FLR01-RM15-LAPTOP)LAPTOP
2SIOUX CITY (WING02-FLR03-RM27-SEAT2-PHONE)PHONE
3FRAMINGHAM (WING01-FLRB2-RM52-AUDTITORIUM-SEAT2-CEILING-PROJECTOR)PROJECTOR
Sheet2
Cell Formulas
RangeFormula
B1:B3B1=Splitted(A1)


VBA Code:
Function Splitted(s As String)
Dim SP() As String: SP = Split(s, "-")
Splitted = Replace(SP(UBound(SP)), ")", "")
End Function
 
Upvote 0
LOCATIONLOCATION
LINCOLN (WING01-FLR01-RM15-LAPTOP)LAPTOP
SIOUX CITY (WING02-FLR03-RM27-SEAT2-PHONE)PHONE
FRAMINGHAM (WING01-FLRB2-RM52-AUDTITORIUM-SEAT2-CEILING-PROJECTOR)PROJECTOR

Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table5"]}[Content],
    TBD = Table.TransformColumns(Source, {{"LOCATION", each Text.BetweenDelimiters(_, "-", ")", {0, RelativePosition.FromEnd}, 0), type text}})
in
    TBD
 
Upvote 0
Wow - too many ways to do one thing. I'll bet this isn't half of the ways to do this.

Thanks everyone!
 
Upvote 0
Glad we could help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,215
Members
448,554
Latest member
Gleisner2

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