Shift and distance calculation

RSnap3232

New Member
Joined
Nov 20, 2020
Messages
24
Office Version
  1. 2016
  2. 2013
Platform
  1. Windows
hello All.

So I have a spread sheet where it has everyones start times (Date and Time, Column I and J) and the finish time (Date and Time, Column K and L) and the distance they have travelled in column N.

I have it so the spreadsheet splits up their shifts between our two shift groups 7am to 7pm (day shift) then 7pm to 7am (night shift) however some of these shifts are staggered therefore a day shift worker can end up working into the night shift, is there a way I can calculate the distance between the two shift groups depending on their start and finish time then working out how much of the distance they travelled in that shift is day then the rest night?

ie they start at 4pm and finish at 2am the next day therefore 30% of the distance they travelled is day time and 70% would be night time shift

The shift I currently use is versions of;
=SUMIFS('week 4'!$N:$N,'week 4'!$I:$I,C4,'week 4'!$J:$J,">=07:00",'week 4'!$J:$J,"<=19:00")
 

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

maabadi

Well-known Member
Joined
Oct 22, 2012
Messages
1,836
Office Version
  1. 2019
  2. 2016
Platform
  1. Windows
Please upload your example file & Desired Results with XL2BB ADDIN (Preferable) OR upload it at free uploading site e.g. www.dropbox.com or googledrive or onedrive and insert link here.
 

RSnap3232

New Member
Joined
Nov 20, 2020
Messages
24
Office Version
  1. 2016
  2. 2013
Platform
  1. Windows
Please upload your example file & Desired Results with XL2BB ADDIN (Preferable) OR upload it at free uploading site e.g. www.dropbox.com or googledrive or onedrive and insert link here.
I am working off a work laptop at the moment so there are alot of restrictions with regards to uploading and sharing and unable to use anything like this at the moment
 

maabadi

Well-known Member
Joined
Oct 22, 2012
Messages
1,836
Office Version
  1. 2019
  2. 2016
Platform
  1. Windows
Try this:
Example Sheet.xlsx
ABCHIJKLMNOPQR
1Day ShiftNight Shift
22/5/20218:00:002/5/202114:00:004006:00:000:00:00
32/5/202111:00:002/5/202117:00:004206:00:000:00:00
42/5/20212/5/202114:00:002/5/202120:00:004405:00:001:00:00
52/5/202117:00:002/5/202123:00:004602:00:004:00:00
62/5/202120:00:002/6/20212:00:004800:00:006:00:00
72/5/202123:00:002/6/20215:00:005000:00:006:00:00
82/6/20212:00:002/6/20218:00:005201:00:005:00:00
92/6/20215:00:002/6/202111:00:005404:00:002:00:00
102/6/20218:00:002/6/202114:00:005606:00:000:00:00
112/6/202111:00:002/6/202117:00:005806:00:000:00:00
12
13Total Day Distance
141340
15
Sheet1
Cell Formulas
RangeFormula
P2:P11P2=IF(IF((J2>=7/24)*(L2<19/24),L2-J2,IF((J2>=7/24)*(L2>=19/24),19/24-J2,IF((J2<7/24)*(L2>7/24),L2-7/24,0)))<0,0,IF((J2>=7/24)*(L2<19/24),L2-J2,IF((J2>=7/24)*(L2>=19/24),19/24-J2,IF((J2<7/24)*(L2>7/24),L2-7/24,0))))
Q2:Q11Q2=K2+L2-I2-J2-P2
J14J14=SUMPRODUCT(($N$2:$N$11)*($I$2:$I$11=$C$4)*($P$2:$P$11/($P$2:$P$11+$Q$2:$Q$11)))
 

Watch MrExcel Video

Forum statistics

Threads
1,130,124
Messages
5,640,249
Members
417,131
Latest member
Seanr19871

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
Top