Count unique values with condition

rlobera

New Member
Joined
Mar 9, 2017
Messages
38
Office Version
  1. 2019
Platform
  1. MacOS
Hi everyone, hope you can help me with this issue.

I have a sheet that looks like this

[TABLE="class: grid, width: 500, align: center"]
<tbody>[TR]
[TD]Subscriber_ID[/TD]
[TD]Date[/TD]
[/TR]
[TR]
[TD]101[/TD]
[TD]09/01/18[/TD]
[/TR]
[TR]
[TD]101[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]202[/TD]
[TD]08/13/18[/TD]
[/TR]
[TR]
[TD]203[/TD]
[TD]09/04/18[/TD]
[/TR]
[TR]
[TD]204[/TD]
[TD][/TD]
[/TR]
[TR]
[TD]205[/TD]
[TD]09/08/18[/TD]
[/TR]
[TR]
[TD]205[/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

I need to count records from September in the "Date" column and only when it's not repeated in the "Subscriber_ID" column. In this case, the correct answer will be 1, because is the only one that matches the condition. As you may see, subscriber_ID 203 it the only record that it's not repeated and also that the date falls within September. Subscribers 101 and 205 should not be considered since both are repeated, in spite of having a date that matches.
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
Hi,

Try this

Ctrl+Shift+Enter NOT just Enter

D2 =INDEX(A2:A8,MATCH(1,IF(MONTH(B2:B8)=9,IF(1/COUNTIF(A2:A8,A2:A8)=1,1)),0))

[TABLE="width: 380"]
<colgroup><col><col><col span="3"></colgroup><tbody>[TR]
[TD][/TD]
[TD]A[/TD]
[TD]B[/TD]
[TD]C[/TD]
[TD]D[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]Subscriber_ID[/TD]
[TD]Date[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]101[/TD]
[TD]01/09/18[/TD]
[TD][/TD]
[TD]203[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]101[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]202[/TD]
[TD]13/08/18[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]203[/TD]
[TD]04/09/18[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]204[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]205[/TD]
[TD]08/09/18[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]8[/TD]
[TD]205[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
Control+shift+enter, not just enter:

=SUM(IF(FREQUENCY(A2:A8,A2:A8)=1,IF(B2:B8-DAY(B2:B8)+1=D1,1)))

where D1 is 2018-09-01.
 
Upvote 0
Control+shift+enter, not just enter:

=SUM(IF(FREQUENCY(A2:A8,A2:A8)=1,IF(B2:B8-DAY(B2:B8)+1=D1,1)))

where D1 is 2018-09-01.

Looks like it worked. Want to better understand the part of the formula where you're using the DAY function. I already know about arrays and the FREQUENCY function.

Also, what the formula would look like if I add a column with another field that also has to match?
 
Upvote 0
Hi,

Try this

Ctrl+Shift+Enter NOT just Enter

D2 =INDEX(A2:A8,MATCH(1,IF(MONTH(B2:B8)=9,IF(1/COUNTIF(A2:A8,A2:A8)=1,1)),0))

[TABLE="width: 380"]
<tbody>[TR]
[TD][/TD]
[TD]A[/TD]
[TD]B[/TD]
[TD]C[/TD]
[TD]D[/TD]
[/TR]
[TR]
[TD]1[/TD]
[TD]Subscriber_ID[/TD]
[TD]Date[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]2[/TD]
[TD]101[/TD]
[TD]01/09/18[/TD]
[TD][/TD]
[TD]203[/TD]
[/TR]
[TR]
[TD]3[/TD]
[TD]101[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]4[/TD]
[TD]202[/TD]
[TD]13/08/18[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]5[/TD]
[TD]203[/TD]
[TD]04/09/18[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]6[/TD]
[TD]204[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]7[/TD]
[TD]205[/TD]
[TD]08/09/18[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]8[/TD]
[TD]205[/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

Not exactly what I was looking for since I want to count records that meet the criteria, not a formula that returns the value that matches.
 
Upvote 0
To count try this :)

=COUNT(IF(MONTH(B2:B8)=9,IF(1/COUNTIF(A2:A8,A2:A8)=1,1)))
 
Last edited:
Upvote 0
To count try this :)

=COUNT(IF(MONTH(B2:B8)=9,IF(1/COUNTIF(A2:A8,A2:A8)=1,1)))

You did it, now it worked! Thank you!

As I already asked to Aladin Akyurek, what the formula would look like if I add a column with another field that also has to match a condition?
 
Upvote 0
Looks like it worked. Want to better understand the part of the formula where you're using the DAY function. I already know about arrays and the FREQUENCY function.

Also, what the formula would look like if I add a column with another field that also has to match?

The FREQUENCY formula works faster and is more flexible.

Any given date can be turned into a first day date, using the DAY function:

=TODAY()-DAY(TODAY())+1

takes off the day part of today and adds 1 to the result. Thus:

10/6/2018 >> 10/0/2018 >> 10/1/2018

In the formula we have we are interested only in the October 2018 dates: That is, every October 2018 dates.


Anther condition: Example...

{=SUM(IF(FREQUENCY(A2:A8,A2:A8)=1,IF(B2:B8-DAY(B2:B8)+1=D1,IF(C2:C8="jon",1))))}
 
Upvote 0
The FREQUENCY formula works faster and is more flexible.

Any given date can be turned into a first day date, using the DAY function:

=TODAY()-DAY(TODAY())+1

takes off the day part of today and adds 1 to the result. Thus:

10/6/2018 >> 10/0/2018 >> 10/1/2018

In the formula we have we are interested only in the October 2018 dates: That is, every October 2018 dates.


Anther condition: Example...

{=SUM(IF(FREQUENCY(A2:A8,A2:A8)=1,IF(B2:B8-DAY(B2:B8)+1=D1,IF(C2:C8="jon",1))))}

It worked great, thanks a lot!
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,240
Members
452,621
Latest member
Laura_PinksBTHFT

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