Help with a drivers milage / time sheet

Paul at GTS

Board Regular
Joined
May 17, 2004
Messages
56
Office Version
  1. 365
Platform
  1. Windows
Hi everyone.

Need help please.

We have a spread sheet for monitoring drivers mileage and work times as sample below.

Date Driver Start Work Finish Work Start Milage Finish Milage Time Work Milage Total Time Total Milage
1/9 Ted 06:00 13:00 100 150 7:00 50 7:00 50
1/9 Bill 09:00 10:00 20 30 1:00 10 1:00 10
1/9 Fred 06:00 12:00 500 600 3:00 100 3:00 100
2/9 Bill 06:00 10:00 155 205 4:00 50 5:00 60
2/9 Fred 09:00 13:00 610 670 4:00 60 7:00 160
3/9 Ted 10:00 15:00 165 265 5:00 100 12:00 150
3/9 Bill 06:00 10:00 220 300 4:00 80 9:00 140
3/9 Fred 12:00 18:00 700 800 6:00 100 15:00 160

Columns Date to Finish milage are retrieved from our vehical tracking system and then daily work times and milages are calculated by spread sheet.

The last two colums we have to do manually as we can not get the sheet to find the next occurance of driver and then add the total for the current day on to the months running total.

It needs to be a "Lookup" due to driver not being in every day so a standard formular becomes incorrect when a driver has a day off - see 2/9 Ted had a day off so no records recived from Tracking system.

The difference between the start and finish milages for the drivers is due to private milage which is not recorded by tracking system.

So what we would like is a way of calculating the last two columns.

Thanks
 

Excel Facts

Excel Joke
Why can't spreadsheets drive cars? They crash too often!
Assuming :
  • the date is in column A
  • the driver is in column B
  • the calculated time (for a given day) is in column G
  • the calculated work milage (for a given day) is in column H
  • the header row is row 1 and the first row of data is row 2

(This is where they were when I copied them into a blank worksheet...)

This formula in column I should give you a running total of time per driver :

Code:
=SUMIFS($G:$G, $B:$B, $B2, $A:$A, "<="&$A2)

(Starting at I2 and dragged down)

And similarly in column J for a running total of milage per driver :

Code:
=SUMIFS($H:$H, $B:$B, $B2, $A:$A, "<="&$A2)

(Starting at J2 and dragged down)

Or better yet, make it a table and then the formulas will propagate down naturally as you add further rows
 
Last edited:
Upvote 0
AOB,

Cant belive how easy it was. Thanks for your help. We were massivly over complicating the issue !

You mention about making it a table - I'm not aware of facility could you educate me furthur,

Thanks again

Paul
 
Upvote 0
You'll find it (in Excel 2013 anyway) under the Insert tab in the ribbon; there should be a Tables tab

If you select your existing data range and then click Insert > Table, Excel will convert the existing "flat" range into a table

A formula added to a cell in the first row data is then automatically reproduced throughout that column

Your formulas can then refer to the table column names rather than column addresses :

Code:
=SUMIFS([Time], [Driver], [@Driver], [Date], "<="&[@Date])
=SUMIFS([Work Milage], [Driver], [@Driver], [Date],"<="&[@Date])

Which may be easier to interpret / read (note [Column] refers to the entire column under that name while [@Column] refers just to the corresponding cell in that row of the table)

As you add rows to the table, the formulas automatically fill down with them

(There is a setting in File > Options > Proofing > AutoCorrect Options... > AutoFormat As You Type which will automatically incorporate data added directly below a table, into that table)

You will then also have effectively a dynamic named range (Formulas > Name Manager) which you can refer to throughout your workbook if necessary.

Here's a handy article which will give you better detail - they may or may not be of benefit to you but worth playing around with
 
Last edited:
Upvote 0

Forum statistics

Threads
1,216,750
Messages
6,132,500
Members
449,730
Latest member
SeanHT

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