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

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

Oaktree

MrExcel MVP
Joined
Jun 20, 2002
Messages
8,053
Office Version
  1. 365
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
8,053
Office Version
  1. 365
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
2,746
Office Version
  1. 365
  2. 2010
Platform
  1. Windows
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!
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,168,030
Messages
5,856,935
Members
431,841
Latest member
jaybeem

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
Top