Averageifs - can't fix #div/0 error

stacyslang

New Member
Joined
Feb 22, 2013
Messages
2
I have a table with 3 worksheets, one of which has the summary data, one has validation data, and one has the individual records.


QA - Summary
QA_spreadsheet.png

QA - records
QA_validation.png

QA - Validation

As you can see - the formula on QA - summary tries to use data on QA - records to average the scores together. For some reason I keep getting #div/0. I tried breaking down the formula into a single AVERAGEIF and some of it works but some doesn't. I'd appreciate any help.

In case you can't read the formula:
=AVERAGEIFS(QA!E$2:E$59,QA!D$2:D$59,'QA - Summary'!A3, QA!B$2:B$47, "<>""", QA!A2:A59,">B1",QA!A2:A59,">='Call-Email-CSR-Date Validation'!E2",)
 
Last edited:

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
It looks like you're trying to average the CSR's score for phone calls if the date is on or after the start date and on or before the end date. This should work:

=AVERAGEIFS(QA!$E$2:$E$59,QA!$D$2:$D$59,'QA - Summary'!A3,QA!$B$2:$B$59,"<>0",QA!$A$2:$A$59,">="&'QA - Summary'!$B$1,QA!$A$2:$A$59,"<="&'Call-Email-CSR-Date Validation'!$E$2)

If you want it to display something other than #DIV/0! when someone has no qualifying scores, you can add an IFERROR statement.
=IFERROR(AVERAGEIFS(QA!$E$2:$E$59,QA!$D$2:$D$59,'QA - Summary'!A3,QA!$B$2:$B$59,"<>0",QA!$A$2:$A$59,">="&'QA - Summary'!$B$1,QA!$A$2:$A$59,"<="&'Call-Email-CSR-Date Validation'!$E$2),"no data")
 
Upvote 0

Forum statistics

Threads
1,215,549
Messages
6,125,473
Members
449,233
Latest member
Deardevil

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