Replacing Multiple Values with Different Values

jmackey

New Member
Joined
Mar 29, 2018
Messages
3
I'm working on a project for work where I need to turn SKU numbers (just a string of numbers and characters) into a regular word. For example, if the cell contains "sahara" (full cell is jmackey-sahara-XL), I want to have a corresponding adjacent column that says "Sahara." There isn't a consistent length to the beginning or ending of the SKU number, it varies for each product (upwards of 15 products). I have included an example list to show what I want to do. Is there any way to do this?

ddQTnH
jmackey-sahara-L/XLSaharaL/XL
jmackey-stealthy-S/MStealthyS/M
jmackey-recon-S/MReconS/M

<tbody>
</tbody>
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.

jproffer

Well-known Member
Joined
Dec 15, 2004
Messages
2,647
Is the "real word" always between 2 dashes like you show there?

If so:

Column B would be: =MID(A1,FIND("-",A1)+1,FIND("-",A1,FIND("-",A1)+1)-FIND("-",A1)-1)

Column C would be: =RIGHT(A1,LEN(A1)-FIND("-",A1,FIND("-",A1)+1))
 

jtakw

Well-known Member
Joined
Jun 29, 2014
Messages
7,245
Office Version
  1. 2016
Platform
  1. Windows
Hi,

If the data you want extracted is Always after the first dash, and you want everything after that separated by dashes extracted:


Excel 2010
ABCD
1jmackey-sahara-L/XLsaharaL/XL
2jmackey-stealthy-S/MstealthyS/M
3jmackey-recon-S/MreconS/M
4cutie-doggie-cat-S/M/LdoggiecatS/M/L
Sheet9
Cell Formulas
RangeFormula
B1=TRIM(MID(SUBSTITUTE($A1,"-",REPT(" ",100)),COLUMN(A1)*100,100))


B1 formula copied down and across as far as needed.
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
55,804
Office Version
  1. 365
Platform
  1. Windows
Is there any way to do this?
You have a couple of formula suggestions, but based on your sample data, you could also do this manually fairly quickly as follows (assumes data is in column A)
1. Select the column by clicking its heading label
2. Data ribbon tab -> Text to Columns -> Delimited -> Next -> Clear Tab, Semicolon, Comma & Space boxes & type a - in the Other box -> Next -> Do not import this column -> Destination:= Type B1 -> Finish
 

Forum statistics

Threads
1,171,654
Messages
5,876,716
Members
433,206
Latest member
james_y

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