Look up string in a list

Fudging

New Member
Joined
Aug 26, 2022
Messages
10
Office Version
  1. 365
Platform
  1. Windows
Excel multiple selection.png
I wrote this code which takes a cell with text in it and looks to find if every word is part of a given list.
Excel Formula:
=IF(SUM(IF(ISNUMBER(FIND(TRIM(MID(SUBSTITUTE(C2," ",REPT(" ",LEN(C2))),SEQUENCE(1,LEN(C2)-LEN(SUBSTITUTE(C2," ",""))+1,1,LEN(C2)),LEN(C2))),A2:A10)),1,0))=LEN(TRIM(C2))-LEN(SUBSTITUTE(C2," ",""))+(LEN(TRIM(C2))>0), "acceptable response", "requires review")
.

While this works great, my only issue with it is that I think it works by verifying letter by letter, meaning if the cell I'm verifying contains "Straw" and I had in my list "Strawberry", it will still return "True" since Straw is in one of the words that's part of my list.

The reason I'm doing this is because I have a multiple selection drop down list in my questionnaire and I'm building a verification tab for it to ensure all users inputs are correct.

The way the code is written, it takes the word count and compares it to how many matches it found in my given list, meaning if a user was to remove the data validation in that cell with multiple selection (like pasting something in there), it will most probably always flag it as an error.

What I wanted to know is if it is possible to make it verify the entire word and not go letter by letter? As mentioned, my current code works perfectly fine, I am just curious to know if what I am suggesting is possible in Excel formulas.

(FYI) I am aware that if there is a solution, I will have to amend my list to contain the word itself as well as the word following a comma.

Thanks a lot in advance for the help :)
 

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
Do you have the new TEXTSPLIT function which has just been released to the monthly channel?
 
Upvote 0
Ok, how about
Fluff.xlsm
ABCD
1
2CherryCherry, pineapple, Strawberry, figTRUE
3pineappleCherry, apple, Strawberry, figFALSE
4StrawberryCherry, Pineapple, Straw, figFALSE
5Guava
6Fig
7Melon
8
Input
Cell Formulas
RangeFormula
D2:D4D2=LET(f,FILTERXML("<k><m>"&SUBSTITUTE(C2,",","</m><m>")&"</m></k>","//m"),COUNT(MATCH(f,$A$2:$A$10,0))=ROWS(f))
 
Upvote 0
Solution
Ok, how about
Fluff.xlsm
ABCD
1
2CherryCherry, pineapple, Strawberry, figTRUE
3pineappleCherry, apple, Strawberry, figFALSE
4StrawberryCherry, Pineapple, Straw, figFALSE
5Guava
6Fig
7Melon
8
Input
Cell Formulas
RangeFormula
D2:D4D2=LET(f,FILTERXML("<k><m>"&SUBSTITUTE(C2,",","</m><m>")&"</m></k>","//m"),COUNT(MATCH(f,$A$2:$A$10,0))=ROWS(f))
Works like a charm, thank you very much :)
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0
How we can display how many words from column A (complete list ) are present each row of column c

So it should display on
Row 2 = 4
Row 3 = 3
Row 4 = 3

Also then can we show it by comparing case also
Row 2 = 4
Row 3 = 3
Row 4 = 2
 
Upvote 0
Hi & welcome to MrExcel.

Please start a new thread for your question.
When you do so please post some sample data.

MrExcel has a tool called “XL2BB” that lets you post samples of your data that will allow us to copy/paste it to our Excel spreadsheets, so we can work with the same copy of data that you are. Instructions on using this tool can be found here: XL2BB Add-in

Note that there is also a "Test Here” forum on this board. This is a place where you can test using this tool (or any other posting techniques that you want to test) before trying to use those tools in your actual posts.

Also please update your profile to show the actual version of Excel you are using, not every single one.
 
Upvote 0

Forum statistics

Threads
1,213,549
Messages
6,114,261
Members
448,558
Latest member
aivin

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