How to calculate weighted average with multiple criteria

dahl07

New Member
Joined
Apr 25, 2012
Messages
11
Hello,

I have figured out how to calculate the total weighted average in my data sheet with this formula:

=SUMPRODUCT((DATA!AA285:AA20000)*(DATA!N285:N20000))/(SUM(DATA!N285:N20000))

Now I need to figure out, how I can calculate this with two criterias;
1) DATA!AH285:AH20000=Distrikter!C3
2) DATA!H285:H20000=Distrikter!D2

I am not sure what to do from here - maybe IF or another SUMPRODUCT.

Thank you for considering my request, I have used several hours on this now...
 
Last edited:
Try...
Rich (BB code):
=SUMPRODUCT(
    --(DATA!AH285:AH20000=Distrikter!C3),
    --(DATA!H285:H20000=Distrikter!D2),
    DATA!AA285:AA20000,
    DATA!N285:N20000)/
  SUMPRODUCT(
    --(DATA!AH285:AH20000=Distrikter!C3),
    --(DATA!H285:H20000=Distrikter!D2),
    DATA!N285:N20000)

If you re on Excel 2007 or later:
Rich (BB code):
=SUMPRODUCT(
    --(DATA!AH285:AH20000=Distrikter!C3),
    --(DATA!H285:H20000=Distrikter!D2),
    DATA!AA285:AA20000,
    DATA!N285:N20000)/
  SUMIFS(
    DATA!N285:N20000
    DATA!AH285:AH20000,Distrikter!C3,
    DATA!H285:H20000,Distrikter!D2)

It still returns #N/A. By the way - how do easily type in the code as you have written? (I may be a newbie: I just corrected ',' into ';' and deleted new lines)
 
Upvote 0

Excel Facts

Will the fill handle fill 1, 2, 3?
Yes! Type 1 in a cell. Hold down Ctrl while you drag the fill handle.
Thanks everyone, I have learned how to use iferror now..

I just registered at this community today, and I am very thankful for all your quick responses!
 
Upvote 0
2010 - how do I do that?

Wrap the formule between [x] and [/x] where x = code.

If you modify the formula in the range in AH such that it does not return #N/A...
Rich (BB code):
=SUMPRODUCT(
    --(DATA!AH285:AH20000=Distrikter!C3),
    --(DATA!H285:H20000=Distrikter!D2),
    DATA!AA285:AA20000,
    DATA!N285:N20000)/
  SUMIFS(
    DATA!N285:N20000,
    DATA!AH285:AH20000,Distrikter!C3,
    DATA!H285:H20000,Distrikter!D2)


Otherwise:

Control+shift+enter, not just enter...
Rich (BB code):
=SUM(
   IF(1-ISNA(DATA!AH285:AH20000),
   IF(DATA!AH285:AH20000=Distrikter!C3,
   IF(DATA!H285:H20000=Distrikter!D2,
    DATA!AA285:AA20000*DATA!N285:N20000))))/
 SUM(
   IF(1-ISNA(DATA!AH285:AH20000),
   IF(DATA!AH285:AH20000=Distrikter!C3,
   IF(DATA!H285:H20000,Distrikter!D2,
    DATA!N285:N20000))))
 
Upvote 0
Wrap the formule between [x] and [/x] where x = code.

If you modify the formula in the range in AH such that it does not return #N/A...
Rich (BB code):
=SUMPRODUCT(
    --(DATA!AH285:AH20000=Distrikter!C3),
    --(DATA!H285:H20000=Distrikter!D2),
    DATA!AA285:AA20000,
    DATA!N285:N20000)/
  SUMIFS(
    DATA!N285:N20000,
    DATA!AH285:AH20000,Distrikter!C3,
    DATA!H285:H20000,Distrikter!D2)


Otherwise:

Control+shift+enter, not just enter...
Rich (BB code):
=SUM(
   IF(1-ISNA(DATA!AH285:AH20000),
   IF(DATA!AH285:AH20000=Distrikter!C3,
   IF(DATA!H285:H20000=Distrikter!D2,
    DATA!AA285:AA20000*DATA!N285:N20000))))/
 SUM(
   IF(1-ISNA(DATA!AH285:AH20000),
   IF(DATA!AH285:AH20000=Distrikter!C3,
   IF(DATA!H285:H20000,Distrikter!D2,
    DATA!N285:N20000))))

Thanks a lot, this is very helpful! :)
 
Upvote 0
Hi everyone,

I'm trying to calculate something very similar and I can't seem to get the formula to work. Here's an example table:

[TABLE="width: 500"]
<tbody>[TR]
[TD]Group[/TD]
[TD]Score[/TD]
[TD]Percentage[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]8769[/TD]
[TD]94%[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]986757[/TD]
[TD]96%[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]685[/TD]
[TD]100%[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]765874[/TD]
[TD]87%[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]7644[/TD]
[TD]90%[/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]76875[/TD]
[TD]90%[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]7654[/TD]
[TD]2%[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]76546[/TD]
[TD]40%[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]76453[/TD]
[TD]89%[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]8765[/TD]
[TD]65%[/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]876554[/TD]
[TD]98%
[/TD]
[/TR]
</tbody>[/TABLE]

I would like the weighed average of a group to return in one cell based on the group I select. Essentially, if group=1, return the weighted average of group 1, if group=2, return the weighted average of group 2 and so on.

I'm using a sumproduct formula but it's not dynamic, so when I filter by various groups I get the same weighted average:
=SUMPRODUCT($B$4:$B$219,$C$4:$C$219)/SUM($B$4:$B$219)

Could you all please help me adjust the formula so that it is dynamic based on a selected group? Thanks a million for your help.
 
Upvote 0
@ctrl s

[Table="width:, class:grid"][tr][td]Row\Col[/td][td]
A​
[/td][td]
B​
[/td][td]
C​
[/td][td]
D​
[/td][td]
E​
[/td][td]
F​
[/td][/tr]
[tr][td]
1​
[/td][td]Group[/td][td]Score[/td][td]Percentage[/td][td][/td][td][/td][td][/td][/tr]


[tr][td]
2​
[/td][td]
1
[/td][td]
8769
[/td][td]
94%
[/td][td][/td][td]
1​
[/td][td]
329729.2​
[/td][/tr]


[tr][td]
3​
[/td][td]
1
[/td][td]
986757
[/td][td]
96%
[/td][td][/td][td]
2​
[/td][td]
278044​
[/td][/tr]


[tr][td]
4​
[/td][td]
1
[/td][td]
685
[/td][td]
100%
[/td][td][/td][td][/td][td][/td][/tr]


[tr][td]
5​
[/td][td]
2
[/td][td]
765874
[/td][td]
87%
[/td][td][/td][td][/td][td][/td][/tr]


[tr][td]
6​
[/td][td]
2
[/td][td]
7644
[/td][td]
90%
[/td][td][/td][td][/td][td][/td][/tr]


[tr][td]
7​
[/td][td]
2
[/td][td]
76875
[/td][td]
90%
[/td][td][/td][td][/td][td][/td][/tr]


[tr][td]
8​
[/td][td]
3
[/td][td]
7654
[/td][td]
2%
[/td][td][/td][td][/td][td][/td][/tr]


[tr][td]
9​
[/td][td]
3
[/td][td]
76546
[/td][td]
40%
[/td][td][/td][td][/td][td][/td][/tr]


[tr][td]
10​
[/td][td]
3
[/td][td]
76453
[/td][td]
89%
[/td][td][/td][td][/td][td][/td][/tr]


[tr][td]
11​
[/td][td]
4
[/td][td]
8765
[/td][td]
65%
[/td][td][/td][td][/td][td][/td][/tr]


[tr][td]
12​
[/td][td]
4
[/td][td]
876554
[/td][td]
98%
[/td][td][/td][td][/td][td][/td][/tr]
[/table]


In F2 enter and copy down:

=SUMPRODUCT(($A$2:$A$12=E2)+0,$B$2:$B$12,$C$2:$C$12)/SUMIFS($C$2:$C$12,$A$2:$A$12,E2)
 
Upvote 0

Forum statistics

Threads
1,223,948
Messages
6,175,580
Members
452,653
Latest member
craigje92

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