ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   Arithmetical Mode Value for Filtered cells in Multiple Adjacent columns (https://www.excelbanter.com/excel-worksheet-functions/44147-arithmetical-mode-value-filtered-cells-multiple-adjacent-columns.html)

Sam via OfficeKB.com

Arithmetical Mode Value for Filtered cells in Multiple Adjacent columns
 
Hi All,

I require a Formula to produce the Arithmetical MODE for numerical values
taking into account the following:

Using Dynamic Named Range "Results" - spans 15 Columns and many Rows.

Dynamic Name "Results" is Defined as Refers To =OFFSET(History!$A$18,1,0,
COUNT(History!$A:$A),15)

Working with Auto-Filtered data so calculations need to display results for
Visible Filtered Cells.

Dynamic Range "Results" needs to be Offset one column to the right,
calculations will include columns 2-15.

Cells housing Formulas that return "" (blank) to be excluded from
calculations

Below is a link to a similar past Thread
http://www.officekb.com/Uwe/Forum.as...40OfficeKB.com


Would appreciate a Formula that can incorporate the Dynamic Named Range
"Results".


Thanks
Sam


--
Message posted via http://www.officekb.com

Domenic

In article ,
"Sam via OfficeKB.com" wrote:

Dynamic Name "Results" is Defined as Refers To =OFFSET(History!$A$18,1,0,
COUNT(History!$A:$A),15)

Dynamic Range "Results" needs to be Offset one column to the right,
calculations will include columns 2-15.


Insert Name Define

Name: Results2

Refers to:

=OFFSET(Results,0,1,,14)

I require a Formula to produce the Arithmetical MODE for numerical values
taking into account the following:

Working with Auto-Filtered data so calculations need to display results for
Visible Filtered Cells.

Cells housing Formulas that return "" (blank) to be excluded from
calculations

Below is a link to a similar past Thread
http://www.officekb.com/Uwe/Forum.as...thmetical-Mode
-Value-for-Filtered-cells-in-Multiple#5183599F654B4%40OfficeKB.com


Would appreciate a Formula that can incorporate the Dynamic Named Range
"Results".


=MODE(IF(SUBTOTAL(3,OFFSET(Results2,ROW(Results2)-MIN(ROW(Results2)),0,1)
),IF((MOD(COLUMN(Results2)-MIN(COLUMN(Results2))+0,8)=0)*(ISNUMBER(Result
s2)),Results2)))

....confirmed with CONTROL+SHIFT+ENTER.

Hope this helps!

Sam via OfficeKB.com

Hi Domenic,

Thank you very much. Your suggested Formula works great!

I just changed the MOD divisor to 1 instead of 8.

Domenic wrote:
Name: Results2
Refers to:
=OFFSET(Results,0,1,,14)


=MODE(IF(SUBTOTAL(3,OFFSET(Results2,ROW(Results 2)-MIN(ROW(Results2)),0,1)
),IF((MOD(COLUMN(Results2)-MIN(COLUMN(Results2))+0,8)=0)*(ISNUMBER(Result
s2)),Results2)))

...confirmed with CONTROL+SHIFT+ENTER


Cheers,
Sam

Domenic wrote:
Dynamic Name "Results" is Defined as Refers To =OFFSET(History!$A$18,1,0,
COUNT(History!$A:$A),15)

Dynamic Range "Results" needs to be Offset one column to the right,
calculations will include columns 2-15.


Insert Name Define

Name: Results2

Refers to:

=OFFSET(Results,0,1,,14)

I require a Formula to produce the Arithmetical MODE for numerical values
taking into account the following:

[quoted text clipped - 11 lines]
Would appreciate a Formula that can incorporate the Dynamic Named Range
"Results".


=MODE(IF(SUBTOTAL(3,OFFSET(Results2,ROW(Results 2)-MIN(ROW(Results2)),0,1)
),IF((MOD(COLUMN(Results2)-MIN(COLUMN(Results2))+0,8)=0)*(ISNUMBER(Result
s2)),Results2)))

...confirmed with CONTROL+SHIFT+ENTER.

Hope this helps!



--
Message posted via OfficeKB.com
http://www.officekb.com/Uwe/Forums.a...tions/200509/1

Domenic

In article ,
"Sam via OfficeKB.com" wrote:

Thank you very much. Your suggested Formula works great!


You're very welcome!

I just changed the MOD divisor to 1 instead of 8.


In that case, you can eliminate the MOD argument...

=MODE(IF(SUBTOTAL(3,OFFSET(Results2,ROW(Results2)-MIN(ROW(Results2)),0,1)
),IF(ISNUMBER(Results2),Results2)))

....confirmed with CONTROL+SHIFT+ENTER.

Hope this helps!

Sam via OfficeKB.com

Hi Domenic,

Thank you for all your helpful advice.

Cheers,
Sam

Sam wrote:
I just changed the MOD divisor to 1 instead of 8.


Domenic wrote:
In that case, you can eliminate the MOD argument...

=MODE(IF(SUBTOTAL(3,OFFSET(Results2,ROW(Results2 )-MIN(ROW(Results2)),0,1)
),IF(ISNUMBER(Results2),Results2)))

...confirmed with CONTROL+SHIFT+ENTER.

Hope this helps!



--
Message posted via OfficeKB.com
http://www.officekb.com/Uwe/Forums.a...tions/200509/1


All times are GMT +1. The time now is 01:31 AM.

Powered by vBulletin® Copyright ©2000 - 2025, Jelsoft Enterprises Ltd.
ExcelBanter.com