timesheets - calculate time on site

htidliam

New Member
Joined
May 31, 2022
Messages
1
Office Version
  1. 365
Platform
  1. Windows
good morning all,

I'm wondering if somebody can hep me with this one:

we have 60 field engineers, we receive daily electronic timesheets, which records travel to site, time on site, travel home etc, I've simplified the attached spreadsheet's to just show time on site to avoid confusion.

no conflictions.xls - this is where an engineer travels from site to site, filling in one job per site, this is easy for us to workout utilisation. no issue with this (attached to help understanding) you will see this engineer spent 3hr 23m in total across 6 x sites.

has conflictions.xls - this is where we are struggling, this particular engineer completed 21 jobs, however the times overlap because the site may have two jobs, which makes it look like he has worked over 27 hours.

is there any formulas we can use on the "has conflictions" spreadsheet to achieve a true value.

please take a look and thank you in advance, your help will be greatly appreciated.

link to spreadsheets (google drive)
 

Attachments

  • Capture.JPG
    Capture.JPG
    153.2 KB · Views: 16

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
This got weird. The formula is in C17 (formatted as time h:mm

In row 20 and down, is it broken up to see the calcs a bit better. Sometimes I get 1-minute errors - I think the minutes aren't working out exactly right.
MrExcelPlayground9 (version 1).xlsb
ABCDEFGH
1From DateTimeTo DateTimeTime on site
25/24/2022 9:375/24/2022 10:070:30
35/24/2022 10:005/24/2022 10:560:56
45/24/2022 11:155/24/2022 11:450:30
55/24/2022 12:045/24/2022 12:340:30
65/24/2022 12:535/24/2022 13:230:30
75/24/2022 13:425/24/2022 14:120:30
83:26
9
10From DateTimeTo DateTimeTime on site
115/24/2022 9:375/24/2022 10:070:30
125/24/2022 10:005/24/2022 10:560:56
135/24/2022 11:155/24/2022 11:450:30
145/24/2022 12:045/24/2022 12:340:30
155/24/2022 12:535/24/2022 13:230:30
165/24/2022 13:425/24/2022 14:120:30
173:20
18
19
205/24/2022 9:371000001
215/24/2022 9:381000001
225/24/2022 9:391000001
235/24/2022 9:401000001
245/24/2022 9:411000001
255/24/2022 9:421000001
265/24/2022 9:431000001
275/24/2022 9:441000001
Sheet10
Cell Formulas
RangeFormula
C2:C7,C11:C16C2=B2-A2
C8C8=SUM(C2:C7)
C17C17=LET(a,MIN(A11:B16)+SEQUENCE((MAX(A11:B16)-MIN(A11:B16))*24*60+1,1,0,1)/24/60,b,(--((a>=TRANSPOSE(A11:A16))+(a<TRANSPOSE(B11:B16))=2)),c,SUM(--(MMULT(b,SEQUENCE(ROWS(A11:A16),1,1,0))>0)),c/24/60)
A20:A295A20=MIN(A11:B16)+SEQUENCE((MAX(A11:B16)-MIN(A11:B16))*24*60+1,1,0,1)/24/60
B20:G295B20=(--((A20#>=TRANSPOSE(A11:A16))+(A20#<TRANSPOSE(B11:B16))=2))
H20:H295H20=(--(MMULT(B20#,TRANSPOSE(--(COLUMN(B20#)>0)))>0))
Dynamic array formulas.
 
Upvote 0

Forum statistics

Threads
1,214,983
Messages
6,122,592
Members
449,089
Latest member
Motoracer88

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