Formula for third most frequent text with multiple criteria

Krieg

New Member
Joined
May 26, 2023
Messages
2
Office Version
  1. 365
Platform
  1. Windows
I have two criteria (name and month) and I am trying to calculate top-3 most frequent text occurrences in a large dataset. I already crafted the formulas for top-1 and top-2 and they are working well, but struggling to create one for the top-3.

Top-1:
=INDEX(data!$H:$H,MODE(IF((data!$C:$C=$D40) * (data!$W:$W=E$39),MATCH(data!$H:$H,data!$H:$H,0))))

Top-2:
=INDEX(data!$H:$H,MODE(IF(IF((data!$C:$C=$D41)*(data!$W:$W=E$39),MATCH(data!$H:$H,data!$H:$H,0))<>MODE(IF((data!$C:$C=$D41)*(data!$W:$W=E$39),MATCH(data!$H:$H,data!$H:$H,0))),IF((data!$C:$C=$D41)*(data!$W:$W=E$39),MATCH(data!$H:$H,data!$H:$H,0)),"")))

Top-3:
???


Will appreciate any help, if any additional detail is needed, happy to provide it.
 

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".
Hi & welcome to MrExcel.
How about
Excel Formula:
=LET(u,UNIQUE(FILTER(Data!$H:$H,(Data!$C:$C=$D40)*(Data!$W:$W=E$39))),TAKE(SORTBY(u,COUNTIFS(Data!$C:$C,$D40,Data!$W:$W,E$39,Data!$H:$H,u),-1),3))
 
Upvote 1
Solution
Hi & welcome to MrExcel.
How about
Excel Formula:
=LET(u,UNIQUE(FILTER(Data!$H:$H,(Data!$C:$C=$D40)*(Data!$W:$W=E$39))),TAKE(SORTBY(u,COUNTIFS(Data!$C:$C,$D40,Data!$W:$W,E$39,Data!$H:$H,u),-1),3))
Oh wow, it worked! I didn't even think there is such a clean way of doing this, I thought the only way to accomplish something like this without VBA is ~15 lines of formula code - thank you so much!
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 1

Forum statistics

Threads
1,223,099
Messages
6,170,107
Members
452,302
Latest member
TaMere

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