Get amount of time inside and outside of two overlapping time periods

brux2dc

New Member
Joined
Dec 6, 2020
Messages
2
Office Version
  1. 365
  2. 2019
Platform
  1. Windows
  2. Web
I have hit a wall figuring out how to best get this done...

Based on this:

5. Employees Normal Work Hours8:00:00 AMto4:45:00 PM
DateStartStopTotal During Working HoursTotal Outside Working Hours
12/1/196:30:00 PM9:30:00 PMNEED THIS VALUENEED THIS VALUE
12/2/197:00:00 AM12:00:00 PMNEED THIS VALUENEED THIS VALUE
12/3/199:00:00 AM6:00:00 PMNEED THIS VALUENEED THIS VALUE
12/5/1921:00:00 PM1:00:00 AMNEED THIS VALUENEED THIS VALUE
12/6/1909:00:00 AM01:00:00 PMNEED THIS VALUENEED THIS VALUE

With the working hours as entered what is the number of hours in the Total during working hours and the total outside working hours for each of the Start and Stop pairs? The Working hours is variable as is the Start and Stop times. One huge wrinkle is that sometimes the stop time will roll over midnight. The hours should be presented as an integer, but not critical as I can do that part. It is the logic I am truly seeking, and correct formulas to use.

I don't have any code to share as I would start down a path and quickly see it was grossly wrong in logic.

I appreciate any help with this...
 

Excel Facts

What is the shortcut key for Format Selection?
Ctrl+1 (the number one) will open the Format dialog for whatever is selected.
Here is a way using Power Query. I made 2 named ranges sHour for the start of normal hours and eHour for the end.

Book1
ABCDEFGHIJK
15. Employees Normal Work Hours8:00:00 AMto4:45:00 PM
2
3DateStartStopTotal During Working HoursTotal Outside Working HoursDateStartStopTotal Outside Working HoursTotal Durng Working Hours
412/1/20196:30:00 PM9:30:00 PMNEED THIS VALUENEED THIS VALUE12/1/2019 0:006:30:00 PM9:30:00 PM30
512/2/20197:00:00 AM12:00:00 PMNEED THIS VALUENEED THIS VALUE12/2/2019 0:007:00:00 AM12:00:00 PM14
612/3/20199:00:00 AM6:00:00 PMNEED THIS VALUENEED THIS VALUE12/3/2019 0:009:00:00 AM6:00:00 PM1.257.75
712/5/201921:00:00 PM1:00:00 AMNEED THIS VALUENEED THIS VALUE12/5/2019 0:009:00:00 PM1:00:00 AM40
812/6/20199:00:00 AM1:00:00 PMNEED THIS VALUENEED THIS VALUE12/6/2019 0:009:00:00 AM1:00:00 PM04
Sheet4


Power Query:
let
    Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    sHour = Time.From(Excel.CurrentWorkbook(){[Name="sHour"]}[Content]{0}[Column1]),
    eHour = Time.From(Excel.CurrentWorkbook(){[Name="eHour"]}[Content]{0}[Column1]),
    WH = List.Times(sHour,Number.From(eHour-sHour)*24*4+1,#duration(0,0,15,0)),
    Types = Table.TransformColumnTypes(Source,{{"Date", type datetime}, {"Start", type time}, {"Stop", type time}}),
    AllHours = Table.AddColumn(Types, "Custom", each if [Start]<[Stop] then List.Times([Start],Number.From([Stop]-[Start])*24*4+1,#duration(0,0,15,0)) else List.Times([Start],Number.From([Start]-[Stop])+16,#duration(0,0,15,0))),
    Outside = Table.AddColumn(AllHours, "Outside WH", each List.Difference([Custom],WH)),
    OutsideTotal = Table.AddColumn(Outside, "Total Outside Working Hours", each if List.Count([Custom]) = List.Count([Outside WH]) then (List.Count([Outside WH])-1) /4 else List.Count([Outside WH])/4),
    During = Table.AddColumn(OutsideTotal, "DWH", each List.Difference([Custom], [Outside WH])),
    DuringTotal = Table.AddColumn(During, "Total Durng Working Hours", each if List.Count([DWH]) = 0 then 0 else (List.Count([DWH])-1)/4),
    Select = Table.SelectColumns(DuringTotal,{"Date", "Start", "Stop", "Total Outside Working Hours", "Total Durng Working Hours"})
in
    Select
 
Upvote 0
I really appreciate the answer.

Unfortunately, I don't know how to use power query in Excel (just PowerBI). The way I presented the data in the question was for clarity. The real data is on a form that has those start and stop pairs scattered, all using the shift start stop as reference. The goal is to determine the number of hours the travel occurred inside the sift and outside the shift. I already setup the Usual Work Day flag which will be used to determine if the math needs to be done for inside shift hours.

Is there a way to do this using a traditional formula, or dynamically creating lookups or ???

5. Employees Normal Work Hours8:00:00 AMto4:45:00 PMand Days2through6
DEPART OFFICIAL DUTY STATION
EventDateUsual Work-Day (y/n)DepartureArrivalTotal During ShiftTotal Outside Shift
6. Arrival at Airport/Train Station11/10/2020Yxxxxxxxxxxxxxxxxxxx6:30:00 PM
7. Wait Time11/10/2020Y6:30:00 PM9:30:00 PM3
8. Departure11/10/2020Y9:30:00 PMxxxxxxxxxxx
a. Arrival
b. Wait time +
c. Departure
d. Arrival
e. Wait time +
f. Departure
9. Final Arrive Time11/10/2020Yxxxxxxxxxxxxxxxxx11:30:00 PM2
10. Arrival at final destination (hotel, work site etc)11/10/2020Y12:30:00 AM1
11. TOTAL HOURS (Rounded to newest 1/4 hour)6

Thanks.
 
Upvote 0

Forum statistics

Threads
1,213,483
Messages
6,113,919
Members
448,533
Latest member
thietbibeboiwasaco

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