Find most frequent value/text in a range that has blanks without the blanks counting

JoeH7745

New Member
Joined
Feb 13, 2025
Messages
9
Office Version
  1. 365
Platform
  1. Windows
Working on a project and I need to identify the most frequent values in a column range that has blanks without the blanks being counted. Example if range C3:c412 has texts such as N4339A, N44321, N44329 and multiple blanks that will eventually be filled, how to I found the most frequent value without the blanks causing an error. I cannot use VBA. Thanks!
 
I would normally use a pivot table for this but see if this does what you want.
Excel Formula:
=LET(rData,C3:C412,
topN,1,
fltr,FILTER(rData,rData<>""),
TAKE(SORT(GROUPBY(fltr,fltr,COUNTA,1,0,-1),2,-1),topN))
 
Upvote 0
I would normally use a pivot table for this but see if this does what you want.
Excel Formula:
=LET(rData,C3:C412,
topN,1,
fltr,FILTER(rData,rData<>""),
TAKE(SORT(GROUPBY(fltr,fltr,COUNTA,1,0,-1),2,-1),topN))
Normally I would use Pivot tables as well but due to our sharepoint restrictions that function is blocked. I did try your formula and I couldn't get it to work. I appreciate your help!
 
Upvote 0
What happened when you tried it ?
We will have a better chance if you show us a sample of your data. Ideally using the Forum's XL2BB tool but you can start with an image that includes the row & column references. If you have formulas in the cells make sure one of the cells is active and include the formula bar in the image.

Also show us the expected result based on the sample data.

PS: How are they blocking the pivot table function ? I have not heard of that being done.
 
Upvote 0
I would normally use a pivot table for this but see if this does what you want.
Excel Formula:
=LET(rData,C3:C412,
topN,1,
fltr,FILTER(rData,rData<>""),
TAKE(SORT(GROUPBY(fltr,fltr,COUNTA,1,0,-1),2,-1),topN))
GROUPBY has filter and sort built-in. The OP might not have the function yet.
 
Upvote 0
Another option if you don't have Groupby is
Excel Formula:
=LET(u,UNIQUE(FILTER(C3:C412,C3:C412<>"")),TAKE(SORT(HSTACK(u,COUNTIFS(C3:C412,u)),2,-1),1))
 
Upvote 0

Forum statistics

Threads
1,226,795
Messages
6,193,045
Members
453,772
Latest member
aastupin

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