mode in filter function?

muppet77

Board Regular
Joined
Jan 24, 2004
Messages
223
is it possible to work out the modal value of a set of data if it has been filtered?
SUBTOTAL() doesn't allow a mode to be worked out.

eg i have two columns of data and i filter the first column, and i want to know the modal value for the values left in the second.
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.

barry houdini

MrExcel MVP
Joined
Mar 23, 2005
Messages
20,825
hello muppet,

If you are filtering on column A and B2:B100 contains numeric values then this will give you the MODE of the visible values

=MODE(IF(SUBTOTAL(3,OFFSET(B2:B100,ROW(B2:B100)-ROW(B2),,1)),B2:B100))

confirmed with CTRL+SHIFT+ENTER
 

wellous

New Member
Joined
Jul 16, 2012
Messages
6
hello muppet,

If you are filtering on column A and B2:B100 contains numeric values then this will give you the MODE of the visible values

=MODE(IF(SUBTOTAL(3,OFFSET(B2:B100,ROW(B2:B100)-ROW(B2),,1)),B2:B100))

confirmed with CTRL+SHIFT+ENTER

Thank you very much,
That helped me a lot!
 

Forum statistics

Threads
1,181,722
Messages
5,931,673
Members
436,798
Latest member
spprtpplcm

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
Top