Counting Unique Dates within a Date Range With One Critieria (with Photos)

DEMDEJ

New Member
Joined
Jul 8, 2020
Messages
9
Office Version
  1. 2016
Platform
  1. Windows
Hello All!

I'm trying to create a formula that counts the number of unique dates within a date range based on the type of item.

I've tried several different formulas and researched ways to do it, but each formula was so specific to the poster's specific problem, that it did not work so I decided to post mine for your help.
The full dataset is on Sheet1 (for simplicity, I've only illustrated 16 rows, but it has potential to be within the thousands):

Sheet1.JPG


The calculations are on Sheet 2:

Sheet2.JPG


In short, using the data on Sheet1, I want to know how many unique dates occurred between, say, 6/1/2020 and 6/8/2020 with the criteria being a banana. These items will change in the future so I'd like the date and items to be referenced cells.

Any assistance is greatly appreciated! Stay safe!
 

Excel Facts

Remove leading & trailing spaces
Save as CSV to remove all leading and trailing spaces. It is faster than using TRIM().
Excuse my mention of UNIQUE Dates. What I'm referring to are DISTINCT dates. My apologies!
 
Upvote 0
Post data in xl2bb

sample try
=countifs(D:D,">="&A2,D:D,"<="&B2,B:B,A6)
 
Upvote 0
Post data in xl2bb

sample try
=countifs(D:D,">="&A2,D:D,"<="&B2,B:B,A6)

Thank you, but when I try orange, it gives me a count of 4. There's only 2 distinct dates for orange within the date range 6/1/20 - 6/8/2020. How can I get 2?
 

Attachments

  • Sheet3.JPG
    Sheet3.JPG
    27.5 KB · Views: 26
Upvote 0
Ok you need the specific date to be equal to 06/01/2020 and 08/01/2020

just delete the comparative operator i.e.

=countifs(D:D,A2,D:D,B2,B:B,A6)
 
Upvote 0
Ok you need the specific date to be equal to 06/01/2020 and 08/01/2020

just delete the comparative operator i.e.

=countifs(D:D,A2,D:D,B2,B:B,A6)
Unfortunately, that does not work either
 
Upvote 0
How about:

Book1
ABCDEFG
1StartEnd
2Banana6/1/20206/1/20206/8/2020
3Banana6/2/2020
4Orange6/1/2020
5Orange6/1/2020Banana2
6Orange6/1/2020Orange2
7Orange6/8/2020Apple4
8Apple6/1/2020Grapes0
9Apple6/2/2020
10Apple6/3/2020
11Apple6/4/2020
12Grapes7/1/2020
13Grapes7/2/2020
14Grapes7/3/2020
15Grapes7/4/2020
16Grapes7/5/2020
Sheet2
Cell Formulas
RangeFormula
G5:G8G5=SUM(SIGN(FREQUENCY(IF($B$2:$B$16=F5,IF($D$2:$D$16>=$F$2,IF($D$2:$D$16<=$G$2,$D$2:$D$16))),$D$2:$D$16)))
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
i am so sorry i did completely wrong. i ignored your requirement details.

Anyways @Eric W has come to our rescue.
 
Upvote 0
How about:

Book1
ABCDEFG
1StartEnd
2Banana6/1/20206/1/20206/8/2020
3Banana6/2/2020
4Orange6/1/2020
5Orange6/1/2020Banana2
6Orange6/1/2020Orange2
7Orange6/8/2020Apple4
8Apple6/1/2020Grapes0
9Apple6/2/2020
10Apple6/3/2020
11Apple6/4/2020
12Grapes7/1/2020
13Grapes7/2/2020
14Grapes7/3/2020
15Grapes7/4/2020
16Grapes7/5/2020
Sheet2
Cell Formulas
RangeFormula
G5:G8G5=SUM(SIGN(FREQUENCY(IF($B$2:$B$16=F5,IF($D$2:$D$16>=$F$2,IF($D$2:$D$16<=$G$2,$D$2:$D$16))),$D$2:$D$16)))
Press CTRL+SHIFT+ENTER to enter array formulas.
This is absolutely perfect! Thank you Eric! You are a genius!
 
Upvote 0

Forum statistics

Threads
1,223,950
Messages
6,175,582
Members
452,653
Latest member
craigje92

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