AVERAGEIFS giving #DIV/0

sfran

New Member
Joined
Mar 9, 2021
Messages
28
Office Version
  1. 365
Platform
  1. Windows
Hello, I'm trying to do an average of days (column D) based on criteria in column F. Column F can be several inputs, but I only want to use it if the cell contains "Investigating", "RC Identified" or "Pending Fix Verification".

When I use the AVERAGEIFS function individually for each of these, it provides the correct response. However when I use multiple criteria, I get a #DIV/0. The formula I am using is:

=AVERAGEIFS(D:D,F:F,"Investigating",F:F,"RC Identified",F:F,"Pending Fix Verification")


Any insight would be appreciated.
 

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.
You're formula is treating the criteria as an AND rather than an OR, try it like
Excel Formula:
=SUM(SUMIFS(D:D,F:F,{"Investigating","RC Identified","Pending Fix Verification"}))/SUM(COUNTIFS(F:F,{"Investigating","RC Identified","Pending Fix Verification"}))
 
Upvote 0
That will always be the case, because the multiple criteria in AVERAGEIFS are ALWAYS treated as AND conditions, not OR conditions.
If it impossible for values in column F to equal all three values at the exact same time, so you will always get zero matches.

One way to do it ls like this:
Excel Formula:
=(SUMIF(F:F,"Investigating",D:D)+SUMIF(F:F,"RC Identified",D:D)+SUMIF(F:F,"Pending Fix Verification",D:D))/(COUNTIF(F:F,"Investigating")+COUNTIF(F:F,"RC Identified")+COUNTIF(F:F,"Pending Fix Verification"))

EDIT: Just see Fluff posted as I was working up the formula. His formula is a little shorter than mine!
 
Upvote 0
Not sure which of us your talking to, but glad we could help & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,213,487
Messages
6,113,941
Members
448,534
Latest member
benefuexx

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