+ Reply to Thread
Results 1 to 6 of 6

Timesheet formula for calculating ordinary hours and overtime hours.

  1. #1
    Registered User
    Join Date
    12-17-2011
    Location
    Canberra
    MS-Off Ver
    Excel 2010
    Posts
    3

    Timesheet formula for calculating ordinary hours and overtime hours.

    Hi I am building a timesheet and I have become a bit stuck.

    I have already got the timesheet to automatically calculate the number of hours once the start time and end time are entered(these cells are all in hh:mm format). The column which calculates the total time is AA4.

    Then I have the following columns:
    Wages rate: Y4
    Ordinary total: AB4
    Overtime total:AD4
    (See attachment)

    After 38 hours we need to pay at the overtime rate, so I can't just multiply the total hours by their hourly rate.

    I need two formulas that will

    1. Work out ordinary hours: If the number of hours is less than or equal to 38 it will calculate the hours (up to 38) by the rate, but if it is greater than 38 it will just multiply the rate by 38 (giving maximum number of ordinary hours)

    2. Work out overtime hours: Where the hours exceed 38, I need a formula that will calculate how many hours are greater than 38 and multiple these additional hours by the rate by time and a half.

    Can someone help me I have been stuck on this for two weeks!

    Cheers
    Attached Files Attached Files

  2. #2
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Timesheet formula for calculating ordinary hours and overtime hours.

    Try these...

    AB4: =MIN(AA4, 38)
    AC4: =AB4*Y4
    AD4: =MAX(0, AA4-38)
    AE4: =AD4*(1.5*Y4)
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  3. #3
    Registered User
    Join Date
    12-17-2011
    Location
    Canberra
    MS-Off Ver
    Excel 2010
    Posts
    3

    Re: Timesheet formula for calculating ordinary hours and overtime hours.

    Thank you so much JBeaucaire!

    I just have one further problem, column AA doesn't seem to be working properly. I have tried a sum formula to total the hours from each day to the weekly total but it seems to stop at 13:30.

    Should I be using the time format, is that what is preventing this column from working?. If I switch to number format it gives me an incredibly low number (like 2.5) when I put in dummie times that total to 60+ hours.

    Once again, thank you so much- I am learning slowly!!
    Attached Files Attached Files

  4. #4
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Timesheet formula for calculating ordinary hours and overtime hours.

    D4: =(C4-B4)+(B4>C4) (copied down and to other columns)

    AA4: =SUM(D4,G4,J4,M4,P4,S4,V4)*24 (formatted as General, copied down)
    AB4: =MIN(AA4,38) (formatted as Number w/2 decimal places, copied down)
    AC4: =AB4*Y4 (formatted as Accounting w/2 decimals, copied down)
    AD4: =MAX(0, AA4-38) (formatted as Number w/2 decimal places, copied down)
    AE4: =AD4*(1.5*Y4) (formatted as Accounting w/2 decimals, copied down)

  5. #5
    Registered User
    Join Date
    12-17-2011
    Location
    Canberra
    MS-Off Ver
    Excel 2010
    Posts
    3

    Re: Timesheet formula for calculating ordinary hours and overtime hours.

    Thank you, you beauty!

    I hope you have a lovely Christmas!

  6. #6
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Timesheet formula for calculating ordinary hours and overtime hours.

    -If that takes care of your need, please click EDIT in your original post, click GO ADVANCED and set the PREFIX box to SOLVED.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Tags for this Thread

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1