Count unique agent names based on the criteria

jaymisra

New Member
Joined
Nov 26, 2023
Messages
7
Office Version
  1. 365
Platform
  1. Windows
Hi Guys,

I am struggling to get the unique agent counts for the data set I have. Need your help

The table contains week number, agent name and survey outcome. I want to know unique count of agents who have error free outcome. As you can see from the data an agent can have possible outcomes as error free, critical error, non critical error. As you can see both Zara and Laura has error free responses so the count ll be 2. What will be formula to achieve that. Thanks
 

Attachments

  • Screenshot_2023-11-26-21-18-13-80_96b26121e545231a3c569311a54cda96.jpg
    Screenshot_2023-11-26-21-18-13-80_96b26121e545231a3c569311a54cda96.jpg
    173.7 KB · Views: 15
I would wait and see if it's possible with the formula I know there is a slight creativity required to achieve the desired outcome but sure if it's not possible then will need to go down the VBA route
 
Upvote 0

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Without VBA, I think a solution with a helper column would be better:

Book1
ABCDE
1WeekAgentResponseHelper column3
246Joeerror free1
346Joeerror free 
446Zaraerror free1
546Lauraerror free 
646LauraCritical error 
746Zaraerror free 
846Joeerror free 
946Joeerror free 
1046Zaraerror free 
1146Lauraerror free 
1246Johnerror free1
1346AlexCritical error 
Sheet1
Cell Formulas
RangeFormula
E1E1=SUM(D2:D13)
D2:D13D2=IF(C2="error free",IF(COUNTIF($B$2:B2,B2)=1,IF(COUNTIFS($B$2:$B$13,B2,$C$2:$C$13,"<>error free")=0,1,""),""),"")
 
Upvote 0
Thanks I think while I was playing around I have found a solution which is working as expected

=SUM(IF(COUNTIFS($B$2:$B$13, UNIQUE(FILTER($B$2:$B$13, $C$2:$C$13 = "error free")), $C$2:$C$13, "<>error free") = 0, 1, 0))
 
Upvote 0

Forum statistics

Threads
1,223,099
Messages
6,170,107
Members
452,302
Latest member
TaMere

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