Formula referencing time ranges

RLCornish

New Member
Joined
Feb 11, 2014
Messages
42
I need to create a formula influenced by arrival and departure times. Each individual will come and go at their allotted times. We are working within windows of time. For example, people coming between 8 a.m. and noon and departing between 11 a.m. and 3 p.m. will be on a specific schedule. There are 3 potential windows for arrivals and departures, so 9 potential schedules. The matrix is below. My end game is to populate what schedule an individual is on based on their arrival and departure being between specific ranges. The function will translate to better than 300 individuals so you can imagine we do not want to have to manually figure out which schedule for each person.

I've fiddled with IF's and can get it to work for a single line of the below matrix, and could probably nest all of it, but it would be ugly. I feel like INDEX/MATCH should be a good option, but cannot figure out how to make the "matches" work because of the time ranges. I'm stumped and would very much appreciate some help.


Below this table are the attendees actual arrival and departure times...

Earliest ArrivalLatest ArrivalEarliest DepartureLatest DepartureSchedule
8:00 AM12:00 PM11:00 AM3:00 PMA
12:01 PM4:00 PM11:00 AM3:00 PMB
4:01 PM10:00 PM11:00 AM3:00 PMC
8:00 AM12:00 PM3:01 PM6:00 PMD
12:01 PM4:00 PM3:01 PM6:00 PME
4:01 PM10:00 PM3:01 PM6:00 PMF
8:00 AM12:00 PM6:01 PM9:00 PMG
12:01 PM4:00 PM6:01 PM9:00 PMH
4:01 PM10:00 PM6:01 PM9:00 PMI

<tbody>
</tbody>


Flight Arrival TimeFlight Departure Time
8:30 AM11:10 AM
12:05 PM11:10 AM
4:15 PM11:10 AM
8:30 AM3:45 PM
12:05 PM3:45 PM
4:15 PM3:45 PM
8:30 AM7:30 PM
12:05 PM7:30 PM
4:15 PM7:30 PM
8:30 AM11:10 AM
12:05 PM11:10 AM

<colgroup><col width="121" style="width:91pt"> <col width="89" style="width:67pt"> </colgroup><tbody>
</tbody>
 

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney
A​
B​
C​
D​
E​
F​
1​
Earliest Arrival
Latest Arrival
Earliest Departure
Latest Departure
Schedule
2​
8:00 AM​
12:00 PM​
11:00 AM​
3:00 PM​
A
3​
12:01 PM​
4:00 PM​
11:00 AM​
3:00 PM​
B
4​
4:01 PM​
10:00 PM​
11:00 AM​
3:00 PM​
C
5​
8:00 AM​
12:00 PM​
3:01 PM​
6:00 PM​
D
6​
12:01 PM​
4:00 PM​
3:01 PM​
6:00 PM​
E
7​
4:01 PM​
10:00 PM​
3:01 PM​
6:00 PM​
F
8​
8:00 AM​
12:00 PM​
6:01 PM​
9:00 PM​
G
9​
12:01 PM​
4:00 PM​
6:01 PM​
9:00 PM​
H
10​
4:01 PM​
10:00 PM​
6:01 PM​
9:00 PM​
I
11​
12​
Flight Arrival Time
Flight Departure Time
Schedule
13​
8:30 AM​
11:10 AM​
AE13: {=INDEX($E$2:$E$10, MATCH(1, (A13 >= $A$2:$A$10) * (A13 <= $B$2:$B$10) * (C13 >= $C$2:$C$10) * (C13 <= $D$2:$D$10), 0))}
14​
12:05 PM​
11:10 AM​
B
15​
4:15 PM​
11:10 AM​
C
16​
8:30 AM​
3:45 PM​
D
17​
12:05 PM​
3:45 PM​
E
18​
4:15 PM​
3:45 PM​
F
19​
8:30 AM​
7:30 PM​
G
20​
12:05 PM​
7:30 PM​
H
21​
4:15 PM​
7:30 PM​
I
22​
8:30 AM​
11:10 AM​
A
23​
12:05 PM​
11:10 AM​
B
 
Upvote 0
Alternatively, you can create a function through VBA & use it in your worksheet directly as =FindSchedule( select arrival time cell, select departure time cell )


Code:
Function FindSchedule(Arrival As Date, Departure As Date) As String

Application.Volatile

    If (Arrival >= #8:00:00 AM# And Arrival <= #12:00:00 PM#) And (Departure >= #11:00:00 AM# And Departure <= #3:00:00 PM#) Then
        FindSchedule = "A"
ElseIf (Arrival >= #12:01:00 PM# And Arrival <= #4:00:00 PM#) And (Departure >= #11:00:00 AM# And Departure <= #3:00:00 PM#) Then
        FindSchedule = "B"
ElseIf (Arrival >= #4:01:00 PM# And Arrival <= #10:00:00 PM#) And (Departure >= #11:00:00 AM# And Departure <= #3:00:00 PM#) Then
        FindSchedule = "C"
        
ElseIf (Arrival >= #8:00:00 AM# And Arrival <= #12:00:00 PM#) And (Departure >= #3:01:00 PM# And Departure <= #6:00:00 PM#) Then
        FindSchedule = "D"
ElseIf (Arrival >= #12:01:00 PM# And Arrival <= #4:00:00 PM#) And (Departure >= #3:01:00 PM# And Departure <= #6:00:00 PM#) Then
        FindSchedule = "E"
ElseIf (Arrival >= #4:01:00 PM# And Arrival <= #10:00:00 PM#) And (Departure >= #3:01:00 PM# And Departure <= #6:00:00 PM#) Then
        FindSchedule = "F"
        
ElseIf (Arrival >= #8:00:00 AM# And Arrival <= #12:00:00 PM#) And (Departure >= #6:01:00 PM# And Departure <= #9:00:00 PM#) Then
        FindSchedule = "G"
ElseIf (Arrival >= #12:01:00 PM# And Arrival <= #4:00:00 PM#) And (Departure >= #6:01:00 PM# And Departure <= #9:00:00 PM#) Then
        FindSchedule = "H"
ElseIf (Arrival >= #4:01:00 PM# And Arrival <= #10:00:00 PM#) And (Departure >= #6:01:00 PM# And Departure <= #9:00:00 PM#) Then
        FindSchedule = "I"
Else: FindSchedule = "Out of timing range"
End If

End Function
 
Upvote 0
That's an interesting piece of VBA code, mse330. I have another project I'm working on where this could be very helpful. Thank you for this.
 
Upvote 0

Forum statistics

Threads
1,216,095
Messages
6,128,795
Members
449,468
Latest member
AGreen17

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