SUMPRODUCT to get an average

Geoff Taylor

Active Member
Joined
Dec 11, 2006
Messages
257
Hi
This formula works fine...
=SUMPRODUCT(--(Data!$N$6:$N$33805=Sheet1!$A13),--(Data!$J$6:$J$33805=Sheet1!$B$8),--(Data!$M$6:$M$33805=Sheet1!$B$7),--(Data!$L$6:$L$33805))

It gives me a total value for all rows that meet the 3 criteria elements. Lovely. Now I would like to find the average of these values and I can't seem to get the syntax correct. Help please.

Thanks
 

Excel Facts

Ambidextrous Undo
Undo last command with Ctrl+Z or Alt+Backspace. If you use the Undo icon in the QAT, open the drop-down arrow to undo up to 100 steps.

Misca

Well-known Member
Joined
Aug 12, 2009
Messages
1,733
Try:
=SUMPRODUCT(--(Data!$N$6:$N$33805=Sheet1!$A13),--(Data!$J$6:$J$33805=Sheet1!$B$8),--(Data!$M$6:$M$33805=Sheet1!$B$7),--(Data!$L$6:$L$33805))/SUMPRODUCT(--(Data!$N$6:$N$33805=Sheet1!$A13),--(Data!$J$6:$J$33805=Sheet1!$B$8),--(Data!$M$6:$M$33805=Sheet1!$B$7))

Actually, you should be able to leave out the last double negative from your original formula: The double negative is used to turn TRUEs and FALSEs to 1s and 0s. The last column should return numeric values anyway or the formula wouldn't make any sense.
 
Last edited:

barry houdini

MrExcel MVP
Joined
Mar 23, 2005
Messages
20,825
You could use this array formula

=AVERAGE(IF(Data!$N$6:$N$33805=Sheet1!$A13,IF(Data!$J$6:$J$33805=Sheet1!$B$8,IF(Data!$M$6:$M$33805=Sheet1!$B$7, Data!$L$6:$L$33805))))

confirmed with CTRL+SHIFT+ENTER

[or in Excel 2007 or later you could use AVERAGEIFS function]
 

scottylad2

Well-known Member
Joined
Feb 2, 2009
Messages
1,919
=SUMPRODUCT(--(Data!$N$6:$N$33805=Sheet1!$A13),--(Data!$J$6:$J$33805=Sheet1!$B$8),--(Data!$M$6:$M$33805=Sheet1!$B$7),--(Data!$L$6:$L$33805))/ countif same criteria
 
Master Excel Bundle

Excel contains over 450 functions, with more added every year. That’s a huge number, so where should you start? Right here with this bundle.

Forum statistics

Threads
1,164,530
Messages
5,837,904
Members
430,520
Latest member
VenkateshRajaganesan

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