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
 

Some videos you may like

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"

Oaktree

MrExcel MVP
Joined
Jun 20, 2002
Messages
7,986
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
 

barry houdini

MrExcel MVP
Joined
Mar 23, 2005
Messages
20,825
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,"")
 

Oaktree

MrExcel MVP
Joined
Jun 20, 2002
Messages
7,986
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)
 

Anthony47

Well-known Member
Joined
Mar 29, 2006
Messages
1,939
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!
 

Watch MrExcel Video

Forum statistics

Threads
1,114,403
Messages
5,547,750
Members
410,811
Latest member
adustin42
Top