ExcelBanter

ExcelBanter (https://www.excelbanter.com/)
-   Excel Worksheet Functions (https://www.excelbanter.com/excel-worksheet-functions/)
-   -   Show weighted average value after filter. (https://www.excelbanter.com/excel-worksheet-functions/24564-show-weighted-average-value-after-filter.html)

BillC

Show weighted average value after filter.
 
Problem.
Using the SUBTOTAL(1,D5:D13) will return the simple average after I have
filtered a list of values in colum d or another colum. However I want to show
the Weighted average correctly after a filter is applied.
I.E Currently I use this, =SUMPRODUCT(D5:D12,$J$5:$J$12)/SUM($J$5:$J$12) but
the value will not change if I filter and of the colums.

Hope someone can help and thatnks in advance.

Peo Sjoblom

One way


=SUMPRODUCT(--($D$5:$D$12),--($J$5:$J$12),(SUBTOTAL(3,OFFSET($J$5,ROW($J$5:$J$1 2)-MIN(ROW($J$5:$J$12)),,))))/SUBTOTAL(9,$J$5:$J$12)

--
Regards,

Peo Sjoblom


"BillC" wrote in message
...
Problem.
Using the SUBTOTAL(1,D5:D13) will return the simple average after I have
filtered a list of values in colum d or another colum. However I want to
show
the Weighted average correctly after a filter is applied.
I.E Currently I use this, =SUMPRODUCT(D5:D12,$J$5:$J$12)/SUM($J$5:$J$12)
but
the value will not change if I filter and of the colums.

Hope someone can help and thatnks in advance.



Aladin Akyurek

Peo Sjoblom wrote:
One way


=SUMPRODUCT(--($D$5:$D$12),--($J$5:$J$12),(SUBTOTAL(3,OFFSET($J$5,ROW($J$5:$J$1 2)-MIN(ROW($J$5:$J$12)),,))))/SUBTOTAL(9,$J$5:$J$12)



A bit shorter, also expecting no text-formatted numbers:

=SUMPRODUCT($D$5:$D$12,SUBTOTAL(9,OFFSET($J$5,ROW( $J$5:$J$12)-MIN(ROW($J$5:$J$12)),,)))/SUBTOTAL(9,$J$5:$J$12)

On Excel 2003, I'd turn the data area into a list by running
Data|List|Create List. The setup allows AutoFiltering and the ranges in
the Subtotal formula are automatically updated when new records are
added or records are deleted.

Duke Carey

Assuming you're filtering column D with some simple criteria, this works just
fine. Change the "5" to your filter criteria.

=SUMPRODUCT(--(D5:D125),D5:D12,E5:E12)/SUMPRODUCT(--(D5:D125),D5:D12)

"BillC" wrote:

Problem.
Using the SUBTOTAL(1,D5:D13) will return the simple average after I have
filtered a list of values in colum d or another colum. However I want to show
the Weighted average correctly after a filter is applied.
I.E Currently I use this, =SUMPRODUCT(D5:D12,$J$5:$J$12)/SUM($J$5:$J$12) but
the value will not change if I filter and of the colums.

Hope someone can help and thatnks in advance.



All times are GMT +1. The time now is 01:40 PM.

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