Excel formula to use a countif if the number of days between 2 dates is within a range WITHOUT using a helper column to get the number of days first

codeliftsleep

Board Regular
Joined
Apr 14, 2017
Messages
103
Say I have about 3000 rows of data.

I want to compare two columns dates to each other and then countif its within a certain range---ie, 1 day, 2 days, 3 days, etc...

Except I don't want to create the "helper column" to get the # of days between the dates first, I want to do it on the fly for a few reasons....

Is this possible? Or am I forced to either use the helper column or do it in VBA?
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
I don't think it is quite clear what you are after.
Are you trying to calculate the difference for each row, or one sum total of all the differences added up?

Perhaps if you post a small example with data and expected results, it will be clearer.
 
Upvote 0
I don't think it is quite clear what you are after.
Are you trying to calculate the difference for each row, or one sum total of all the differences added up?

Perhaps if you post a small example with data and expected results, it will be clearer.[/QUOTE

Start Date End Date
11/17/2017 11/28/2017


I have the two columns above. I want to run the NETWORKDAYS on every cell in the column and then count them depending on how many days they are...I need various ranges like under 7 days, 7-14 days, etc
I already just added in a helper column to do it that calculates the NETWORKDAYS and then runs the countif off that column, but I didn't really want to do that. I could have done it in code, but this should be formula based.
 
Upvote 0
Start Date End Date
11/17/2017 11/28/2017
Not quite what I was looking for. Don't see any expected results there...

I need various ranges like under 7 days, 7-14 days, etc
So, you are introducing new information that wasn't mentioned in the first post, but your question is still very vague and scarce on details.
Please give us a small (like maybe 10-20 rows of data), but realistic example of your data, and show us EXACTLY what you are looking for this formula to return.
 
Upvote 0
8ZZK4
Not quite what I was looking for. Don't see any expected results there...


So, you are introducing new information that wasn't mentioned in the first post, but your question is still very vague and scarce on details.
Please give us a small (like maybe 10-20 rows of data), but realistic example of your data, and show us EXACTLY what you are looking for this formula to return.


8ZZK4
I think I have it explained pretty well in this picture I created in Excel...or at least I hope so because I don't know how else to explain it.

8ZZK4
https://imgur.com/a/8ZZK4
 
Last edited:
Upvote 0
Try something like this


A
B
C
D
1
Start Date​
End date​
2
11/17/2017​
11/28/2017​
3
11/15/2017​
11/20/2017​
4
11/20/2017​
11/22/2017​
5
11/01/2017​
11/14/2017​
6
11/18/2017​
11/26/2017​
7
11/05/2017​
11/27/2017​
8
9
0-3 Days​
4-7 Days​
8-14 Days​
15+ Days​
10
0​
4​
8​
15​
11
1​
2​
2​
1​

<tbody>
</tbody>


Put the lower value of each range (0, 4, 8, 15) in A10:D10

Formula in A11 copied across
=SUMPRODUCT(--(NETWORKDAYS(+$A$2:$A$7,+$B$2:$B$7)>=A10),--(IF(A10=15,9.99E+307,B10)>NETWORKDAYS(+$A$2:$A$7,+$B$2:$B$7)))

Hope this helps

M.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,213,517
Messages
6,114,085
Members
448,548
Latest member
harryls

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