Forum Discussion
Return a value from a list depending if value in another cell contains this
Hi Excel community,
I am trying to build a large data file decoding part numbers. Part numbers have different lengths and compositions and they are all mixed up. All I need is a simple check saying if the cell with the part number contains in any position one of the following letters please return the value assigned to this letter:
In other words: if the part number contains "TR" please return "small", if it contains "PN" please return big etc.
TR | small |
PN | big |
CWR | middle |
EXT | large |
I tried several options but none of them was working.
Thanks in advance for your help
See the attached sample workbook. The Parts and Sizes names are dynamic in this version - they will automatically be adjusted when you add or remove part numbers. See Formulas > Name Manager for their definition.
Enter the little list from your post into a worksheet - it doesn't matter where.
Select its first column, with the letter combinations.
Click in the name box on the left hand side of the formula bar.
Type a name, for example Parts, and press Enter.
Select its second column, with the sizes.
Click in the name box on the left hand side of the formula bar.
Type a name, for example Sizes, and press Enter.
Now let's say your part numbers are in E2 and down.
In the cell next to it, enter the formula
=INDEX(Sizes,MATCH(TRUE,ISNUMBER(SEARCH(Parts,E2)),0))
or
=TEXTJOIN("",TRUE,IF(ISNUMBER(SEARCH(Parts,E2)),Sizes,""))
If you don't have Excel in Office 2021 or Microsoft 365, confirm with Ctrl+Shift+Enter.
Then fill down.
- martin7bCopper ContributorThanks for your quick answer - I have tried both of your options and in the first one I get N/A as result and in the second one #NAME? error. Any idea? Thanks
See the attached sample workbook. The Parts and Sizes names are dynamic in this version - they will automatically be adjusted when you add or remove part numbers. See Formulas > Name Manager for their definition.
- goldmaxCopper Contributor
HansVogelaar I have a similar problem as described in this thread. I have a table titled "Properties" with a column titled "Property Name" listing properties by name and another column titled "County" listing which county each property is found within. Each property is found within one of 4 regions. I want to use the associated county to prescribe a region to each property in a third column titled "Region". I have a separate table titled "Counties by Region" with each region number as headers and the counties contained within in their respective region column. How do I write a formula in the "region" column of the "properties" table that searches for each county within the "Counties by Region" table and returns the column header in which the county name was found?
I'd use a range like this:
You can then use a simple VLOOKUP or XLOOKUP formula to return the region that a specific county belongs to.
- tauqeeracmaSteel Contributor
Hi martin7b
You may take help from SEARCH() functions, assume the parts numbers are stored in column A then use below formula column B.
=IF(IFERROR(SEARCH("TR",A3,1),0)>0,"Small",IF(IFERROR(SEARCH("PN",A3,1),0)>0,"Big",IF(IFERROR(SEARCH("CWR",A3,1),0)>0,"Middle","Large")))
You may also refer to the attached sample file for more understanding.
Thanks
Tauqeer
- martin7bCopper Contributor
Thanks for your quick answer - I have this solution - the issue is that the list with the codes is very long (+50 different codes and this makes the formula very long as well) - we are also modifying the list from time to time so I would like to have it dynamic for an enduser who is not familiar with formulas so he just can edit the list. sorry for the missing additional information from my side in the innitial post. Any idea?
Thanks