Being Challenged With Time In My Formula

Ark68

Well-known Member
Joined
Mar 23, 2004
Messages
4,570
Office Version
  1. 365
  2. 2016
Platform
  1. Windows
This snippit of code checks to see if a time value (svc_off) falls with an employee's shift (crew_st and crew_et, representing the start and end times respectively as a number). From my testing thus far, things seem to be working as expected, but I run into a challenge when the shift is 4:00PM - midnight.

Code:
               If svc_off > crew_st And svc_off < crew_et Then 'can this crew's shift accomodate this service
                        temp_grm_cnt = temp_grm_cnt + 1
                        ws_thold.Cells(thold_dr, 10) = temp_grm
                        thold_dr = thold_dr + 1
                    End If
                End If

If svc_off = .75 (6:00PM), the if statement is false and the code doesn't run. I'm assuming its checking the range of .666667 (4:00P) and 0 (12:00A).
How can I overcome this? Again with the assuming, but I will likely need to add the date value to the time.

Would the best way to overcome this be to add the date value to each time and using an if then statement, add the date + 1 to the crew_et value if it is equal to zero? Sounds like it might work in this particular case, but what happens with other shifts that go into the next day?
 

Excel Facts

Whats the difference between CONCAT and CONCATENATE?
The newer CONCAT function can reference a range of cells. =CONCATENATE(A1,A2,A3,A4,A5) becomes =CONCAT(A1:A5)
See if this does what you need
VBA Code:
If svc_off > crew_st And svc_off < IIf(crew_et < crew_st, crew_et + 1, crew_et) Then 'can this crew's shift accomodate this service
If you're repeatedly using the crew_et variable then it might be an advantage to make the adjustment at an earlier point in the code for consistency.
 
Upvote 0
Solution
Hello Jasonb ... sorry for taking so long to acknowledge you suggestion. I'm just plugging away with it now. I have reached a point where I am unable to test further because of this ...
Code:
svc_off = bkg_st - TimeSerial(1, 0, 0)

bkg_st = 44024.375
I need svc_off to be a numeric value 44024.3333333. What it is returning is 2020-07-12 8:00:00 AM.
I tried using CLng
Code:
svc_off = CLng(bkg_st - TimeSerial(1, 0, 0))
but it just gave be a value 0f 44024.

Anyone?
 
Upvote 0
Try CDbl instead, CLng is only for long integers, not decimals.
 
Upvote 0
Thanks Jasonb! I forgot CDbl ... it of course was what I needed.
And your solution appears to have worked so far in my testing. I did make make the adjustment early as suggested as I will be needing it again later. Thank you!!!!
It solution was much simpler than I had expected. It makes total sense that of the end time is less than the start time that it must be carrying over into the next day.
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,334
Members
452,636
Latest member
laura12345

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