The mode of a series of numeric values

Copper Contributor

Hello,
I am looking for an excel function that will allow me to determine the mode of a series of nominal values. The MODE () function is used but only for numeric values. From a PivotTable or frequency distribution I can determine the mode.
My problem is that I want to do it only from an Excel function.
Thank you

5 Replies

Hi,

 

You can provide each nominal value with a numeric ID, and depend on this ID in MODE function to determine the ID of the most occurred nominal value.

After you got the ID, you can use it in VLOOKUP to return the nominal value.

Get the Mode in nominal values.png

 

 

Instead, you can depend on this formula:

=INDEX($A$2:$A$8,MATCH(MAX(INDEX(COUNTIF(A2:A8,A2:A8),)),INDEX(COUNTIF(A2:A8,A2:A8),),0))

Get the Mode in nominal values 2.png

 

 

Hope that helps

Good evening Haytham and especially thank you for your message your method function very well. Once the known mode, if I know the number of instances there is this mode, is there also a formula?

Sorry, but I did not understand the question well!

In fact your formula allows to find the mode of a nominal series. Once I've determined the mode, I find a formula to count the number of times that mode is in the nominal series

Okay,

Simply, you use COUNTIF function to do so.

=COUNTIF(A2:A8,C3)

Result:

3

 

Or you can modify the original formula as below to display the nominal mode and the number of its occurrences all in a single cell.

=INDEX($A$2:$A$8,MATCH(MAX(INDEX(COUNTIF(A2:A8,A2:A8),)),INDEX(COUNTIF(A2:A8,A2:A8),),0))&" / "&COUNTIF(A2:A8,INDEX($A$2:$A$8,MATCH(MAX(INDEX(COUNTIF(A2:A8,A2:A8),)),INDEX(COUNTIF(A2:A8,A2:A8),),0)))&" Times."

Result:

cat / 3 Times.

 

Get the Mode in nominal values.png

 

 

Hope that helps