Appears Most

markoakes

Active Member
Joined
Jan 5, 2004
Messages
325
I have a table with 3 columns, A= Name, B= City, C=Item. This table may have thousands of rows of data. I then have a second table that list each City and each Item for that city. In column H I need to return the Name that appears most often for that combination of City and Item. I this example for Modesto and Table, Joe appeared most often. Incase of a tie, Miami and Chair I need the name that appears first in the list, Bill.

Excel 2016 (Windows) 32 bit
A
B
C
D
E
F
G
H
2
Name
City
Item
City
Item
Name
3
JoeModestoTableModestoTableJoe
4
JoeModestoTableModestoChairJoe
5
JoeModestoChairModestoLampTom
6
JoeModestoChairMiamiTableBill
7
TomModestoTableMiamiChairBill
8
TomModestoChairMiamiLampSally
9
TomModestoLamp
10
TomModestoLamp
11
BillMiamiTable
12
BillMiamiTable
13
BillMiamiChair
14
BillMiamiChair
15
SallyMiamiTable
16
SallyMiamiChair
17
SallyMiamiChair
18
SallyMiamiLamp
Sheet: Sheet1
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.
Maybe...

Assumes headers in row 2

Array formula in H3 copied down
=INDEX(A$3:A$18,MODE(IF(B$3:B$18=F3,IF(C$3:C$18=G3,{0,0}+MATCH(A$3:A$18,A$3:A$18,0)))))
confirmed with Ctrl+Shift+Enter, not just Enter

M.
 
Upvote 0
Array formula in cell H3:

=INDEX($A$3:$A$18, MATCH(MAX(COUNTIFS($B$3:$B$18, F3,$C$3:$C$18, G3,$A$3:$A$18, $A$3:$A$18)), COUNTIFS($B$3:$B$18, F3, $C$3:$C$18 ,G3, $A$3:$A$18, $A$3:$A$18), 0))

Copy cell H3 and paste to cells below.
 
Upvote 0

Forum statistics

Threads
1,213,535
Messages
6,114,194
Members
448,554
Latest member
Gleisner2

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