Countif date range appears in another date range

PedroGomez9

New Member
Joined
Feb 25, 2021
Messages
6
Office Version
  1. 2016
Platform
  1. Windows
Morning all!

I'm looking to try and count the number of colleagues at my work that have been absent due to covid on a weekly basis.
I have their isolation start date in column N, their isolation end date in column O in a sheet named 'Absence Data'. Absence type is flagged as 'Covid' in column M.

On a separate sheet, 'Absence by Week', I have a list of the working weeks - week start date in column A, week end date in column B.

My issue is that often depending on the start date, a 10 day isolation can span across 3 separate weeks, but the start/end date will only be captured in 2 of those weeks and not in between. Example, a colleague starts isolation on Saturday of week 1, isolating all of week 2, and then also the first couple of days of week 3. using the formulas below, only the first and third weeks are captured.

=COUNTIFS('Absence Data'!$N:$N,">="&'Absence by Week'!$A2,'Absence Data'!$N:$N,"<="&'Absence by Week'!$B2) to capture those starting isolation in any given week, and;
=COUNTIFS('Absence Data'!M:M,"Covid",'Absence Data'!$O:$O,">="&'Absence by Week'!$A2,'Absence Data'!$O:$O,"<="&'Absence by Week'!$B2) to capture those ending isolation in any given week

Please let me know if anything isn't clear, or you need more supporting information to assist, and thank you in advance!
 

Excel Facts

Which came first: VisiCalc or Lotus 1-2-3?
Dan Bricklin and Bob Frankston debuted VisiCalc in 1979 as a Visible Calculator. Lotus 1-2-3 debuted in the early 1980's, from Mitch Kapor.
Maybe this adjusting the ranges to suit your data:

=SUMPRODUCT(--(('Absence Data'!$O$1:$O$10<A2)+(B2<'Absence Data'!$N$1:$N$10)=0),--('Absence Data'!$M$1:$M$10="Covid"))
 
Upvote 0

Forum statistics

Threads
1,214,789
Messages
6,121,590
Members
449,039
Latest member
Arbind kumar

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