Extract all text to right of last remaining dash in string

Sean15

Well-known Member
Joined
Jun 25, 2005
Messages
698
Office Version
  1. 2010
Platform
  1. Windows
Hello:

I want to extract all text to the right of the last remaining dash in a string.

Sheet1 lookup values in column F are:
2854261-160-587-P00791
758524-176-365-P00807.09

Sheet2 required values in range G2:G100 are:
P00791
P00807.09

In M2 sheet1 I have the following formula:
=INDEX(sheet2!$G$2:$G$100,MATCH(RIGHT(F2,FIND("-",F2)-1),sheet2!$E$2:$E$100,0))

Formula is returning required value P00791 for lookup value 2854261-160-587-P00791.
Formula is returning #N/A for lookup 758524-176-365-P00807.09.
It should have returned P00807.09

Could you help please?

Sean
 
Last edited:

Excel Facts

Workdays for a market open Mon, Wed, Friday?
Yes! Use "0101011" for the weekend argument in NETWORKDAYS.INTL or WORKDAY.INTL. The 7 digits start on Monday. 1 means it is a weekend.
hello:

There's a bit of miss information in post #1.

Sheet2 required values in range G2:G100 are:
Tom Jones
David Jones

Sheet2 lookup array in range E2:E100
P00791
P00807.09

Formula is returning required value Tom Jones for lookup value 2854261-160-587-P00791
Formula is returning #N/A for lookup 758524-176-365-P00807.09
It should have returned David Jones

Sorry for confusion
 
Upvote 0
Try:
Sheet1
Book1
FGHIJKLM
1
22854261-160-587-P00791Tom Jones
3758524-176-365-P00807.09David Jones
Sheet1
Cell Formulas
RangeFormula
M2:M3M2=INDEX(Sheet2!$G$2:$G$100,MATCH(RIGHT(Sheet1!F2,LEN(Sheet1!F2)-SEARCH("\",SUBSTITUTE(Sheet1!F2,"-","\",LEN(Sheet1!F2)-LEN(SUBSTITUTE(Sheet1!F2,"-",""))))),Sheet2!$E$2:$E$100))


Sheet2
Book1
EFG
1
2P00791Tom Jones
3P00807.09David Jones
Sheet2
 
Upvote 0
An alternative (with same Sheet2 as in post #3)

Sean15.xlsm
FM
1
22854261-160-587-P00791Tom Jones
3758524-176-365-P00807.09David Jones
Sheet1
Cell Formulas
RangeFormula
M2:M3M2=VLOOKUP(TRIM(RIGHT(SUBSTITUTE(F2,"-",REPT(" ",30)),30)),Sheet2!E$2:G$100,3,0)
 
Upvote 0
Solution
Thank you very much. I have decided to use the shorter formula.

Sean
 
Upvote 0
You're welcome. Glad we could help. Thanks for the follow-up. :)
 
Upvote 0
It works for "P00791" with/without "-" prefix, or/and it is in middle of string, like:
XXX-XXX-P00791
XXX-XXX-P00791-YYY
XXX-XXXP00791
XXX-XXXP00791YYY

Book2
FGHIJKLM
22854261-160-587-P00791Tom Jones
3758524-176-365-P00807.09David Jones
Sheet1
Cell Formulas
RangeFormula
M2:M3M2=LOOKUP(2,1/ISNUMBER(SEARCH(Sheet2!$E$2:$E$3,F2)),Sheet2!$G$2:$G$3)

Book2
EFG
2P00791Tom Jones
3P00807.09David Jones
Sheet2
 
Upvote 0
The question clearly stated (and included examples to show) that was not the case
I dont think so! Maybe he/she want to say with:

(1) statement:
"I want to extract all text to the right of the last remaining dash in a string."
It means "XXX-YYY-ZZZ" ===> "ZZZ"
Thats what your formula did (get strings after last "-")

And:
(2) statement:
"Sheet2 required values in range G2:G100 are:
P00791
P00807.09"

to said that text could be:
XXX-YYY-ZZZ
XXX-YYY-P00791

My solution is "general", reply to any scenarios.
 
Upvote 0

Forum statistics

Threads
1,214,956
Messages
6,122,465
Members
449,085
Latest member
ExcelError

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