Forum Discussion
Sander1988
Aug 03, 2022Copper Contributor
Search cell text for maximum reference value
Hello, My excel file contains substances (e.g. "A"), which have multiple comma-separated labels in a single cell (e.g. "H311, H331, H207, R22). The labels correspond to 2 tables and each label ha...
- Aug 03, 2022
Try below formula. See the attached file.
=LET(x,FILTERXML("<t><s>"&SUBSTITUTE([@Labels],",","</s><s>")&"</s></t>","//s"),MAX(XLOOKUP(x,H_labels[label],H_labels[Category],0,0),XLOOKUP(x,R_labels[Label],R_labels[Category],0,0)))
Sander1988
Aug 03, 2022Copper Contributor
Harun24HRThank you for your quick reply! I would have never been able to come up with this solution. One problem though: when the maximum label is category 1, the output is 0 instead of 1.
Harun24HR
Aug 03, 2022Bronze Contributor
You do not have R200 in any label of tables. So, how it would be 1? Can you please explain.
- Sander1988Aug 04, 2022Copper ContributorApologies, I meant to say (and type) H200. Even then the problem persists, the formula produces a 0 instead of 1. Do you know a solution?
- Harun24HRAug 04, 2022Bronze Contributor
Because you have trailing space after data in first table (Column A). I have removed those. Check the attached file to this comment.
- Sander1988Aug 04, 2022Copper Contributor
Thank you very much for this great solution!