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?

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

<tbody>
</tbody>
 

Some videos you may like

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand

jproffer

Well-known Member
Joined
Dec 15, 2004
Messages
2,643
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
5,146
Hi,

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

<b>Excel 2010</b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th><th>C</th><th>D</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">1</td><td style=";">jmackey-sahara-L/XL</td><td style=";">sahara</td><td style=";">L/XL</td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style=";">jmackey-stealthy-S/M</td><td style=";">stealthy</td><td style=";">S/M</td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style=";">jmackey-recon-S/M</td><td style=";">recon</td><td style=";">S/M</td><td style="text-align: right;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">4</td><td style=";">cutie-doggie-cat-S/M/L</td><td style=";">doggie</td><td style=";">cat</td><td style=";">S/M/L</td></tr></tbody></table><p style="width:4.8em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet9</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: rgb(218,231,245);color: rgb(22,17,32)">B1</th><td style="text-align:left">=TRIM(<font color="Blue">MID(<font color="Red">SUBSTITUTE(<font color="Green">$A1,"-",REPT(<font color="Purple">" ",100</font>)</font>),COLUMN(<font color="Green">A1</font>)*100,100</font>)</font>)</td></tr></tbody></table></td></tr></table><br />

B1 formula copied down and across as far as needed.
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
46,337
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
 

Watch MrExcel Video

Forum statistics

Threads
1,109,530
Messages
5,529,385
Members
409,869
Latest member
snake93
Top