How to count maximum & minimum occurrence from a range?

xlmaniac

Well-known Member
Joined
Jul 2, 2009
Messages
527
Office Version
  1. 2010
Platform
  1. Windows
Dear All,
I do have a sample data set as follows.
I would like to count the maximum & minimum occurrence from the data set.
I have written a formula which is yielding the correct count of the maximum occurrence but I am unable to find out how write the same for the minimum occurrence.
Here in this case the count of the minimum occurrence needs to be 1(since number 3 is there only once).
Could somebody help me out with the formula in C2 which can deliver the desired result?
Regards
Sheet1

*ABC
11Count Of Maximum Occurrence6
22Count Of Maximum Occurrence*
33**
42**
51**
61**
71**
81**
91**

<colgroup><col style="width: 30px; font-weight: bold;"><col style="width: 64px;"><col style="width: 194px;"><col style="width: 64px;"></colgroup><tbody>
</tbody>

Spreadsheet Formulas
CellFormula
C1=COUNTIF(A1:A9,A1:A9)

<tbody>
</tbody>

<tbody>
</tbody>


Excel tables to the web >> http://www.excel-jeanie-html.de/index.php?f=1" target="_blank"> Excel Jeanie HTML 4
 

Excel Facts

Copy formula down without changing references
If you have =SUM(F2:F49) in F50; type Alt+' in F51 to copy =SUM(F2:F49) to F51, leaving the formula in edit mode. Change SUM to COUNT.
I think your current formula is not working, but seems correct because of a coincidence between where you've put it and what it shows.

Try the following for the count of the maximum occurrence:
Code:
=COUNTIF($A$1:$A$9,MAX($A$1:$A$9))

Substitute MIN() for MAX() to get the count of the minimum occurrence
 
Upvote 0
Assuming your real example is numbers:

=MAX(FREQUENCY(A1:A9,A1:A9))

=MIN(IF(FREQUENCY(A1:A9,A1:A9)>0,FREQUENCY(A1:A9,A1:A9)))

These are both array formulas so need to be entered using CTRL+SHIFT+ENTER. If done correctly then Excel will automatically put { } around your formulas.
 
Upvote 0
I think your current formula is not working, but seems correct because of a coincidence between where you've put it and what it shows.

Try the following for the count of the maximum occurrence:
Code:
=COUNTIF($A$1:$A$9,MAX($A$1:$A$9))

Substitute MIN() for MAX() to get the count of the minimum occurrence

Dear MisterBates,
Thank you for your help.
I have tried with your proposed formula but it is yielding the opposite result for maximum/ minimum occurrence.
Pls see below.
Pls suggest further.
Excel Workbook
ABC
11Count Of Maximum Occurrence1
22Count Of Minimum Occurrence6
33
42
51
61
71
81
91
Sheet1
 
Upvote 0
Dear Mr Colin,
Thank you so much for your help.
Really appreciate the same.
It is yielding the desired result.
Regards
 
Upvote 0
I guess it depends what you understand by maximum and minimum. If, to you, the maximum value is "1", then you need to use MIN() in your formula, as Excel uses numeric max/min and 1 is the minimum value.
Try switching the MAX() and MIN() in the formulae.

(edit)
Duh - my misunderstanding. I gave formulae for counting the occurrence of the maximum and minimum values, while you wanted formulae to give the maximum and minimum frequencies.
... got it ... please ignore my posts.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,215,219
Messages
6,123,684
Members
449,116
Latest member
HypnoFant

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