Unique Abbreviation Problem

HunterA

New Member
Joined
May 18, 2018
Messages
7
Hello, I am trying to extract abbreviations from a string of words and display them in a new cell.

The abbreviations are as follows:

Wheat; W
Dairy; D
Egg; E
Fish; F
Shellfish; SH
Soy; S
Peanut; P
Tree Nut; TN
Vegan; VGN
Vegetarian; V


The Strings can be any combination of any or all of these in a single cell as follows (commas and all):

Wheat, Dairy, Egg, Soy, Vegetarian

or simply

Vegan


I can hide columns or use a back sheet, but it has to be automatic (for people who really dont know how to use excel), and without VBA (security wont allow VBA to pass through email.)


Can anybody help!!!?

I had someone suggest a comma delimited separation into columns, and then abbreviate, and then concatenate them but it isn't foolproof enough, or automatic.


Thanks in advance for anybodys suggestions!

-Alex
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
I did not mention the strings I would like to return in a single cell for the above two examples would be "W, D, E, S, V" and "VGN"
 
Upvote 0
Welcome to the MrExcel board!

I have made the following assumptions:
- There will be at most 20 items listed in a single cell in column A (we can expand though if needed)
- Since you have novice users, there could be inconsistencies with the comma space between the listed items. One consequence of my attempt to deal with that is the lookup list in columns X:Y below contains "TreeNut" not "Tree Nut" but I don't think that should worry your users as, in any case, that list may well be hidden or on another sheet?
- The sheet will be used with Excel through Office 365. Further note below my screen shot in case this assumption is incorrect.

Lookup list is housed in X2:Y21 (allowing for 20 items)
Formula in C2 is copied across to V2 (20 columns) and down
Formula in B2 is copied down.
All columns except A & B could be hidden after data/formulas have been added

Excel Workbook
ABCDEFGHIJKLMNOPQRSTUVWXY
1
2Wheat, Dairy, Egg, Soy, VegetarianW, D, E, S, VWDESVWheatW
3VeganVGNVGNDairyD
4Peanut, Tree Nut, FishP, TN, FPTNFEggE
5FishF
6ShellfishSH
7SoyS
8PeanutP
9TreeNutTN
10VeganVGN
11VegetarianV
12
Abbreviations



If you don't have an Excel version with the TEXTJOIN function, then the formula in B2 could be
Code:
=SUBSTITUTE(TRIM(C2&" "&D2&" "&E2&" "&F2&" "&G2&" "&H2&" "&I2&" "&J2&" "&K2&" "&L2&" "&M2&" "&N2&" "&O2&" "&P2&" "&Q2&" "&R2&" "&S2&" "&T2&" "&U2&" "&V2)," ",", ")
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,886
Messages
6,175,196
Members
452,616
Latest member
intern444

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