Return column with largest number of matches to multiple criteria

KT0922

New Member
Joined
Apr 19, 2018
Messages
2
Hi,

I'm trying to reference a specific list and find a match in an array that has the most commonalities with that list. The goal in the table below would be to return the name "Larry" as he has the most matches to the target list.

ListNameJeffGeorgeLarry
ApplesApplesLemonApples
OrangesOrangesLimeOranges
BananasMelonsBananasBananas

<colgroup><col width="88" span="6" style="width:66pt"> </colgroup><tbody>
</tbody>


Any help would be greatly appreciated!
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
Row\Col
A​
B​
C​
D​
E​
F​
1​
2​
1​
3​
2​
ListNameJeffGeorgeLarry
3​
ApplesLarryApplesLemonApples
4​
OrangesOrangesLimeOranges
5​
BananasMelonsBananasBananas
6​

In D1 enter and copy across:

=SUMPRODUCT(COUNTIFS(D3:D5,$A$3:$A$5))

In B3 control+shift+enter, not just enter, and copy down:

=IFERROR(INDEX($D$2:$F$2,SMALL(IF($D$1:$F$1=MAX($D$1:$F$1),COLUMN($D$2:$F$2)-COLUMN($D$2)+1),ROWS($B$3:B3))),"")
 
Upvote 0
Hello and welcome to the board. I'm just going to ask, because I know everyone will want to know, what do you want to do in the case of a tie, or can there never be a tie?

Never mind, the master beat me to the response
 
Last edited:
Upvote 0
Thank you both! What if I also wanted to rank the top three matches for example? So the first name would be Larry, then Jeff, etc..

If i'm working with a much larger subset of data and am looking to do this sort of selection for multiple "lists," is there a better way to set this up so that you don't have multiple rows of sumproduct(countifs?
 
Upvote 0

Forum statistics

Threads
1,213,515
Messages
6,114,080
Members
448,548
Latest member
harryls

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