Define A Time Range When Upper Limit is Midnight

Ark68

Well-known Member
Joined
Mar 23, 2004
Messages
4,562
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
The code below is supposed to do something pretty simple. Take a time value (CDate(Me.tb_ps_sttime.Value))and see if it falls with a shift (defined by a start - ty9s -and end time - ty9e).

Code:
Private Sub cb_ps_crew_Change()

    Dim ty9s As Double
    Dim ty9e As Double

    If mbEvents Then Exit Sub
    mbEvents = True
    
    ty9s = WorksheetFunction.VLookup((Me.cb_ps_crew.Value & "1"), ws_staff.Range("I5:M38"), 4, False)
    ty9e = WorksheetFunction.VLookup((Me.cb_ps_crew.Value & "1"), ws_staff.Range("I5:M38"), 5, False)
    rn = ws_data.Range("A:A").Find(Me.tb_rid.Value).row
    
    If WorksheetFunction.VLookup((Me.cb_ps_crew.Value & "1"), ws_staff.Range("I5:M38"), 2, False) = "X" Then
        MsgBox "There is no staff scheduled on this crew." & Chr(13) & "Please select another crew, or adjust the staff schedule.", vbExclamation, "STAFF DEFICIENCY"
        Me.cb_ps_crew.Value = ws_data.Range("AU" & rn)
    ElseIf CDate(Me.tb_ps_sttime.Value) < ty9s Or CDate(Me.tb_ps_sttime.Value) > ty9e And Me.cb_ps_stq.Value <> "<" Then
        MsgBox "This crew is unavailable for this service at the time requested." & Chr(13) & "Please select another crew, adjust the staff schedule or change the service time.", vbExclamation, "STAFF DEFICIENCY"
        Me.cb_ps_crew.Value = ws_data.Range("AU" & rn)
    End If
    cb_ps_crew.BackColor = RGB(255, 255, 255)
    
    mbEvents = False

End Sub

The problem I am having is something like this.

CDate(Me.tb_ps_sttime.Value) = 9:00 PM
ty9s = 4:00 PM
ty9e = midnight (0:00 AM the next day)

I need to adapt this code to ensure that it is understood that ty9e is later than ty9s.

Can anyone suggest an adaptation that will change the value of ty9e to midnight the next day when the value of ty9s = "0" (midnight)
 

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
Midnight is special. If it is the beginning of a time period, then, it is 0. If it is the end of a time period, then, it is 1.

Set a cell's format to time, enter 24:00, copy and paste by value to another cell and you'll see 1, not 0, in the pasted cell.

So, after "ty9e = WorksheetFunction.VLookup...", you may want to put an IF statement to set ty9e to 1 if it is midnight.
 
Upvote 0
Thanks so much yky for both the explanation and solution!!

So, I went with ...
Code:
 ty9e = WorksheetFunction.VLookup((Me.cb_ps_crew.Value & "1"), ws_staff.Range("I5:M38"), 5, False)
 if ty9e = 0 then ty9e = 1

That got me wondering now how times even later than midnight have to be coded, for example 1 or 2 am.
 
Last edited:
Upvote 0
That got me wondering now how times even later than midnight have to be coded, for example 1 or 2 am.
There is a more general solution. If ty9e < ty9s, then ty9e = ty9e + 1. Plus 1 puts the time into the next day. Normally, 1 am is 1/24. 1 am for the next day is 1 1/24 or 25/24.
 
Upvote 0

Forum statistics

Threads
1,213,517
Messages
6,114,089
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