Formulas to count including Unique Numbers

Graham C1600

Board Regular
Joined
Feb 17, 2018
Messages
96
Office Version
  1. 365
Hi,

I've tried this before but ended up going around in circles because i was not asking the right questions. Hopefully the below will clear all this up.

User IDNameLast LogonUTCModelType
1Gary01/01/2019NoADCOL
1Stephen02/01/2019NoRELCOL
1BrianNoRELCOL
2Graham05/03/2019YesRELSIM
3SteveNoRELCOL
4Clare06/05/2019YesRELSIM
4TrevYesADCOL
5Simon03/03/2018NoRELCOL
6RichNoADSIM
7Darren05/06/2019NoRELCOL
8John01/04/2018NoADSIM
8AndrewNoRELSIM
9OliverYesRELSIM

<colgroup><col><col><col><col span="3"></colgroup><tbody>
</tbody>

So work on the assumption that the User ID's is Column A and so on. So the formulas I need will be going into Column G and beyond.

1st query. How many unique User ID’s are there with the following criteria – There is text in the Last Logon field and also the UTC is=”No”. So in this example the answer would be 3. This is User ID 1,5 & 8.
2nd query. As above but I now need to see how many unique User ID’s there are with the following criteria – The Last Logon field is blank and the UTC is =”No”. The important part with this one is that all of the same User ID’s must meet this requirement. So for instance User ID 1, Brian has not logged on and his UTC is “No”. But Gary and Stephen have logged on so this User id is not to be counted. So using this method the answer would be 2. This would be Rich and Steve.
3rd query. I need to count the total amount of User ID’s where at least 1 person has data in the Last logged on field and the UTC = “No”. This is not unique and I need a total. In this case it would be 5 (Gary, Stephen, John, Darren, Simon)
4th query. I need to count the total amount of User ID’s where at least 1 person has data in their Last Logon box and the UTC =”No”. This count needs to be User ID’s that are the same for instance John has met this criteria but we also need to include Andrew in the count because he has the same User ID. So in this scenario the count would be 7 (Gary, Stephen, Brian, Simon, Darren, John, Andrew)
4th query. I need to count the total amount of User ID’s where there is no data in the Last Logon Field and the UTC=”No”. This count needs to be similar to the 2nd query in that if there is a User ID that meets this requirement and another person with the same User ID does not meet the requirement then we need to disregard these users. So in this query the answer would be 2.
5th query. I need to count the how many Unique User ID’s there are that meet the following criteria – UTC=”No” –Model =”AD” Type=”SIM”. In this case the answer is 2 (Rich & John)
6th query. I need to count the total of User ID’s that meet the following criteria – UTC=”No” Model=”REL” Type=”COL”. In this case the answer is 5 (Stephen, Steve, Brian,Simon,Darren)
7th query. I need to count the total of User ID’s that meet this criteria – UTC=”No” Model=”REL” Type=”COL” and also where there is data in the Last Logon field. So in this scenario the count would be 3 (Stephen, Simon , Darren)

Thanks in advance.
 
If the possible values in E2:E14 are only REL and AD, as shown in your data sample, all you have to do is delete the condition IF(E2:E14 = "REL" from the formulas.

M.
 
Last edited:
Upvote 0

Excel Facts

Best way to learn Power Query?
Read M is for (Data) Monkey book by Ken Puls and Miguel Escobar. It is the complete guide to Power Query.
If the possible values in E2:E14 are only REL and AD, as shown in your data sample, all you have to do is delete the condition IF(E2:E14 = "REL" from the formulas.

M.

Hi M,

Thanks for the reply.

In my actual data there are numerous values in E2:E14. I just tried to keep it as simple as possible when I was getting all the formulas to work.

Thanks
 
Upvote 0
To use an OR condition in an array formula you should add the conditions, for example

=SUM(IF(FREQUENCY(IF($D$2:$D$14="NO",IF((E2:E14="REL")+(E2:E14="AD"),IF(F2:F14="COL",MATCH(A2:A14,A2:A14,0)))),ROW(A2:A14)-ROW(A2)+1),1))
Ctrl+Shift+Enter

M.
 
Upvote 0
Maybe this..

M
1
List​
2
3​
3
6​
4

<tbody>
</tbody>


Array formula in M2 copied down
=IFERROR(INDEX(A$2:A$14,SMALL(IF(FREQUENCY(IF(ISNA(MATCH(A$2:A$14,IF((C$2:C$14<>"")+(D$2:D$14="Yes"),A$2:A$14),0)),MATCH(A$2:A$14,A$2:A$14,0)),ROW(A$2:A$14)-ROW(A$2)+1),ROW(A$2:A$14)-ROW(A$2)+1),ROWS(M$2:M2))),"")
Ctrl+Shift+Enter

M.
Hi M,

Quick query which I cannot figure out.

Everything is working fine however I've been asked to provide additional data now which I cannot get the formula to work for.

So
C$2:C$14<>"" part of the formula returns any cells from C2 to C14 that are blank. I also need to add column B2 to B14 that are also blank. I know on my original spreadsheet they had names in but now in my master spreadsheet they have different data. I've tried the following but it does not return the correct data :-
IF((B$2:B$14<>"")+(C$2:C$14<>"")+(D$2:D$14="Yes").

Any ideas what the issue is ?

Thanks
 
Upvote 0
Graham,

This thread is getting too long...
New data? I suggest you create a new thread - new data sample along with expected results.

M.
 
Upvote 0

Forum statistics

Threads
1,213,482
Messages
6,113,915
Members
448,532
Latest member
9Kimo3

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