Forum Discussion
Arlene1070
Aug 18, 2019Copper Contributor
Excel overlapping day of week and times
Hi there,
Where I am currently working we have spreadsheets listing course lectures and seminars. As some courses/seminars cannot conflict with others, I need to find a way to identify which courses/seminars conflict. A sample spreadsheet is below.
The day and time cannot conflict with another day/time that is the same or has overlapping times.
I need a column at the end to identify all the exact and overlapping courses and seminars, not just by the times but by the day as well. I have been able to come up with a calculation to find overlapping times and another to find the same days/times however I am lost at how to create one calculation to do both. I am using Office 16.
Subj | Num | DU | CType | Sec | Days | Time |
LING | 1F25 | 1 | LEC | 1 | M | 1500-1700 |
LING | 1F25 | 1 | SEM 1 | 1 | T | 1600-1700 |
LING | 1F25 | 1 | SEM 2 | 1 | W | 1500-1600 |
LING | 1F25 | 1 | SEM 3 | 1 | F | 1600-1700 |
LING | 1F25 | 1 | SEM 4 | 1 | F | 1000-1100 |
LING | 1F25 | 1 | SEM 5 | 1 | F | 900 -1000 |
LING | 1F25 | 1 | SEM 6 | 1 | W | 1600-1700 |
LING | 1F25 | 1 | SEM 7 | 1 | R | 1400-1500 |
LING | 5P01 | 3 | LEC | 1 | R | 1100-1400 |
LING | 5P02 | 3 | LEC | 1 | T | 1100-1400 |
LING | 5P03 | 2 | LEC | 1 | T | 1200-1500 |
LING | 5P04 | 3 | LEC | 1 | W | 1100-1400 |
LING | 5P05 | 2 | LEC | 1 | M | 1400-1700 |
LING | 5P07 | 2 | LEC | 1 | R | 1400-1500 |
LING | 5P08 | 3 | LEC | 1 | M | 1400-1700 |
LING | 5P85 | 2 | LEC | 1 | W | 1100-1400 |
Any help would be greatly appreciated.
Arlene 1070
Hello Arlene1070 ,
in order to use the time values in formulas, you will need to split them into two different columns, one for start, one for finish. When you've done that, can you post a small sample file here and manually mock up the desired result? That would be a lot easier than having to re-type data from your screenshot for testing.
- Arlene1070Copper Contributor
Thank you so much for replying Ingeborg!
This is my first time on a forum so I really have no idea how this all works and greatly appreciate you responding. I am not sure when you say post a small sample file “here”, if you mean in this email or online so I am replying both to this email as well as online on the Microsoft site. I did not add a screenshot into my post, I copied the Excel file into the post. When I look at my post it shows as a table, not a screen shot. I will try again so you can work with the data easily.
Here is the revised table. I would like the last column to indicate all the lectures and seminars that fall on the exact same day/time and also the ones where the times overlap on the same day. In my sample, where times overlap on the same day or the lecture/seminar is at the exact same time/day as another, these are marked as TRUE.
I don’t need it to be TRUE or FALSE. It can be indicated by a 1 or whatever, as long as the ones that conflict are indicated somehow.
LING 1F25 SEM 7 and LING 5P07 LEC both fall on Thursdays (R) from 1400-1700.
LING 1F25 LEC on Mondays from 1500-1700 overlaps with 5P05 and 5P08 which fall on Mondays from 1400-1700.
Subj Num DU CType Sec Days Start Time Finish Time Conflict LING 1F25 1 LEC 1 M 1500 1700 TRUE LING 1F25 1 SEM 1 1 T 1600 1700 FALSE LING 1F25 1 SEM 2 1 W 1500 1600 FALSE LING 1F25 1 SEM 3 1 F 1600 1700 FALSE LING 1F25 1 SEM 4 1 F 1000 1100 FALSE LING 1F25 1 SEM 5 1 F 900 1000 FALSE LING 1F25 1 SEM 6 1 W 1600 1700 FALSE LING 1F25 1 SEM 7 1 R 1400 1500 TRUE LING 5P01 3 LEC 1 R 1100 1400 FALSE LING 5P02 3 LEC 1 T 1100 1400 FALSE LING 5P03 2 LEC 1 T 1200 1500 FALSE LING 5P04 3 LEC 1 W 1100 1400 FALSE LING 5P05 2 LEC 1 M 1400 1700 TRUE LING 5P07 2 LEC 1 R 1400 1500 TRUE LING 5P08 3 LEC 1 M 1400 1700 TRUE LING 5P85 2 LEC 1 W 1100 1400 FALSE You may attach your file clicking on this icon at the left bottom of the Reply window
To show the conflicts you may use
=(COUNTIFS($G$5:$G$20,$G5,$H$5:$H$20,"<"&$I5,$I$5:$I$20,">"&$H5)>1)
and, if you are on Office365 subscription or on Excel 2019, use TEXTJOIN to show conflicting courses
=SUBSTITUTE(TEXTJOIN(";",TRUE,IF(($G$5:$G$20=$G5)*($H$5:$H$20<$I5)*($I$5:$I$20>$H5),$B$5:$B$20&" "&$C$5:$C$20&" "&$E$5:$E$20,"")),$B5&" "&$C5&" "&$E5,"")
The only, you show in your example what 5P04 and 5P85 are not in conflict, but both of them are scheduled on Wed from 1100 to 1400. Same for 5P02 and 5P04.
Please check attached.