Identifying Overlapping Times

breynolds0431

Active Member
Joined
Feb 15, 2013
Messages
303
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
Not sure why the below is so wide. But, I'm needing to identify overlapping times from the below example. I think the Overlap Minutes would be more difficult, so if anyone has an accurate formula to identify a way to flag the overlap rows, that would work too. I have a formula to check each row and if the time on that row overlaps with the time on the row above it, but it would be more accurate if the overlap could be evaluated across the entire table.

RECORD NOStart TimeEnd TimeOverlap FlagOverlap Minutes
148​
8:48 AM​
9:03 AM​
149​
10:37 AM​
10:52 AM​
150​
10:43 AM​
10:58 AM​
151​
11:11 AM​
11:26 AM​
152​
11:21 AM​
11:36 AM​
153​
12:28 PM​
12:58 PM​
154​
12:42 PM​
12:57 PM​
155​
1:09 PM​
1:24 PM​
156​
1:27 PM​
1:57 PM​
157​
1:46 PM​
2:01 PM​
158​
4:01 PM​
4:16 PM​
159​
8:17 PM​
8:32 PM​
 

Excel Facts

Formula for Yesterday
Name Manager, New Name. Yesterday =TODAY()-1. OK. Then, use =YESTERDAY in any cell. Tomorrow could be =TODAY()+1.
Not sure why the below is so wide. But, I'm needing to identify overlapping times from the below example. I think the Overlap Minutes would be more difficult, so if anyone has an accurate formula to identify a way to flag the overlap rows, that would work too. I have a formula to check each row and if the time on that row overlaps with the time on the row above it, but it would be more accurate if the overlap could be evaluated across the entire table.

RECORD NOStart TimeEnd TimeOverlap FlagOverlap Minutes
148​
8:48 AM​
9:03 AM​
149​
10:37 AM​
10:52 AM​
150​
10:43 AM​
10:58 AM​
151​
11:11 AM​
11:26 AM​
152​
11:21 AM​
11:36 AM​
153​
12:28 PM​
12:58 PM​
154​
12:42 PM​
12:57 PM​
155​
1:09 PM​
1:24 PM​
156​
1:27 PM​
1:57 PM​
157​
1:46 PM​
2:01 PM​
158​
4:01 PM​
4:16 PM​
159​
8:17 PM​
8:32 PM​
Two things -
# First you haven't mentioned what version of Excel you are using - That you can update in your profile
# Second, if you can upload your data sample using XL2BB utility, it will help understand what exactly you need
 
Upvote 0
Not sure why the below is so wide.
More detail to what Sanjay has said..
1. Check out XL2BB
2. Update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)


Is this what you are looking for?

22 08 09.xlsm
BCD
1Start TimeEnd TimeOverlap Flag
28:48 AM9:03 AM 
310:37 AM10:52 AMOverlap
410:43 AM10:58 AMOverlap
511:11 AM11:26 AMOverlap
611:21 AM11:36 AMOverlap
712:28 PM12:58 PMOverlap
812:42 PM12:57 PMOverlap
91:09 PM1:24 PM 
101:27 PM1:57 PMOverlap
111:46 PM2:01 PMOverlap
124:01 PM4:16 PM 
138:17 PM8:32 PM 
Overlap
Cell Formulas
RangeFormula
D2:D13D2=IF(SUMPRODUCT((B$2:B$13<=C2)*(C$2:C$13>=B2))>1,"Overlap","")
 
Upvote 0
Solution
More detail to what Sanjay has said..
1. Check out XL2BB
2. Update your Account details (or click your user name at the top right of the forum) so helpers always know what Excel version(s) & platform(s) you are using as the best solution often varies by version. (Don’t forget to scroll down & ‘Save’)


Is this what you are looking for?

22 08 09.xlsm
BCD
1Start TimeEnd TimeOverlap Flag
28:48 AM9:03 AM 
310:37 AM10:52 AMOverlap
410:43 AM10:58 AMOverlap
511:11 AM11:26 AMOverlap
611:21 AM11:36 AMOverlap
712:28 PM12:58 PMOverlap
812:42 PM12:57 PMOverlap
91:09 PM1:24 PM 
101:27 PM1:57 PMOverlap
111:46 PM2:01 PMOverlap
124:01 PM4:16 PM 
138:17 PM8:32 PM 
Overlap
Cell Formulas
RangeFormula
D2:D13D2=IF(SUMPRODUCT((B$2:B$13<=C2)*(C$2:C$13>=B2))>1,"Overlap","")
Thank you, Peter. That was the solution. I came across that before when I was searching. However, my Start Time column was formatted as text and didn't flag anything correctly.

I have updated my account, but cannot add XL2BB.

Thanks, again.
 
Upvote 0
I have updated my account
Thanks for that. (y)

my Start Time column was formatted as text and didn't flag anything correctly.
If the values are Text then you can just re-order the comparisons slightly. Below, I have col B as Text and Col C as Numerical (Time)

22 08 09.xlsm
ABCD
1RECORD NOStart TimeEnd TimeOverlap Flag
21488:48 AM9:03 AM 
314910:37 AM10:52 AMOverlap
415010:43 AM10:58 AMOverlap
515111:11 AM11:26 AMOverlap
615211:21 AM11:36 AMOverlap
715312:28 PM12:58 PMOverlap
815412:42 PM12:57 PMOverlap
91551:09 PM1:24 PM 
101561:27 PM1:57 PMOverlap
111571:46 PM2:01 PMOverlap
121584:01 PM4:16 PM 
131598:17 PM8:32 PM 
Overlap (2)
Cell Formulas
RangeFormula
D2:D13D2=IF(SUMPRODUCT((B$2:B$13-C2<=0)*(C$2:C$13-B2>=0))>1,"Overlap","")
 
Upvote 0
Thanks for that. (y)


If the values are Text then you can just re-order the comparisons slightly. Below, I have col B as Text and Col C as Numerical (Time)

22 08 09.xlsm
ABCD
1RECORD NOStart TimeEnd TimeOverlap Flag
21488:48 AM9:03 AM 
314910:37 AM10:52 AMOverlap
415010:43 AM10:58 AMOverlap
515111:11 AM11:26 AMOverlap
615211:21 AM11:36 AMOverlap
715312:28 PM12:58 PMOverlap
815412:42 PM12:57 PMOverlap
91551:09 PM1:24 PM 
101561:27 PM1:57 PMOverlap
111571:46 PM2:01 PMOverlap
121584:01 PM4:16 PM 
131598:17 PM8:32 PM 
Overlap (2)
Cell Formulas
RangeFormula
D2:D13D2=IF(SUMPRODUCT((B$2:B$13-C2<=0)*(C$2:C$13-B2>=0))>1,"Overlap","")

Thanks, Peter. I was able to just convert the column of Text times using Text To Columns. So, your original solution worked perfectly.
 
Upvote 0

Forum statistics

Threads
1,214,392
Messages
6,119,254
Members
448,879
Latest member
oksanana

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