Finding the last occurrence of specific character in a cell

kmeunier

New Member
Joined
Oct 2, 2006
Messages
24
I have a column of data that has a product number within each cell. The product # contains at least one hyphen, but possibly more. My goal is to locate the last hyphen in each cell and break the data into two parts. Everything after the last hyphen (including the hyphen) should be moved to a cell in a newly created column on the right.

Example of valid products codes:
Column1
123-EA1
BGF33201-R-GR-BX10

How can I do this so that I end up with

123 in column1 and -EA1 in column2
and
BGF33201-R-GR in column1 and -BX10 in column2?

Thank you in advance for any suggestions you can provide me!
Kathy M. - Richmond, VA
 

Excel Facts

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.
With three steps:

1) B1 =SUBSTITUTE(A1,"-","@",LEN(A1)-LEN(SUBSTITUTE(A1,"-",""))), copied down where @ is some character that will not appear in your data. (This will replace the last - with @)

2) Copy and paste values of column B

3) use data --> text to columns to break column B out with @ (from step 1) as a delimiter
 
Upvote 0
If your data is in A2 you could use this formula in B2

=LEFT(A2,LOOKUP(15^2,FIND("-",A2,ROW(INDIRECT("1:"&LEN(A2)))))-1)

and this in C2

=SUBSTITUTE(A2,B2,"")
 
Upvote 0
If your data is in A2 you could use this formula in B2

=LEFT(A2,LOOKUP(15^2,FIND("-",A2,ROW(INDIRECT("1:"&LEN(A2)))))-1)

and this in C2

=SUBSTITUTE(A2,B2,"")

nice. (y)
 
Upvote 0
Hallo to everybody,
who is so kind to explain me WHY and HOW the wonderful formula posted by barry houdini works (the one in B2)?

Thank you!
 
Upvote 0

Forum statistics

Threads
1,214,646
Messages
6,120,717
Members
448,985
Latest member
chocbudda

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