+ Reply to Thread
Results 1 to 8 of 8

Formula for calculating working hours (normal, overtime, -lunch)

  1. #1
    Registered User
    Join Date
    03-21-2017
    Location
    Tallinn, Estonia
    MS-Off Ver
    2013
    Posts
    4

    Formula for calculating working hours (normal, overtime, -lunch)

    Hello,

    i'm having difficulty with a formula or even several formulas to calculate normal worked hours, overtime and total.
    Normal working hours are 8 hours from 08:00 till 16:30, lunch is 30 minutes.

    I would like to avoid having to make an additional column for lunch time, so ideally the "hours" part of the timesheet should look like this.
    Capture.PNG


    So in this case normal hours are 08:00-16:30, which include 30 minutes lunch (non-paid), 16:30-19:00 - 2.5 hrs of overtime


    My initial formula for Normal hours was: IF(((G12-F12)*24)>8,8,(G12-F12)*24) but I just don't understand how to incorporate lunch here
    Formula for overtime was like this: IF((G12-F12)*24>8, (G12-F12)*24-8, 0)

    Also, the formula has to flexible, because the "normal" hours amount can vary depending on the project.

    I would really appreciate help in creating correct formulas.
    thanks in advance!

  2. #2
    Forum Expert
    Join Date
    05-20-2015
    Location
    Chicago, Illinois
    MS-Off Ver
    2016
    Posts
    2,103

    Re: Formula for calculating working hours (normal, overtime, -lunch)

    Quote Originally Posted by Dariaaleksandrovna View Post
    Also, the formula has to flexible
    Welcome to the board! I'm not quite sure what sort of flexibility you're looking for, but based on your initial formulas, I came up with the following minor adjustments:

    Normal: =IF(((G12-F12)*24)>8.5,8,(G12-F12)*24)

    Overtime: =IF((G12-F12)*24>8.5, (G12-F12)*24-8.5, 0)

    This seems to work with a few sample times, but some modifications might need to be made if the lunch deduction automatically kicks in after a certain number of hours. My formulas above treat lunch as something that only applies if the person worked 8.5 or more hours.

  3. #3
    Registered User
    Join Date
    03-21-2017
    Location
    Tallinn, Estonia
    MS-Off Ver
    2013
    Posts
    4

    Re: Formula for calculating working hours (normal, overtime, -lunch)

    Hello,

    thank you for your reply and help!
    Yes, the adjustment for my formula you suggested only works if the person worked more than 8 hours. If the person did not work overtime, i.e. he worked from 8 till 16:30 the amount of normal hours is calculated as 8.5, if I use your suggested adjustment. However, the amount should be 8, so i'm still wondering how to adjust the formula. Would you be so kind as to help me with this? There is not way I can figure it out myself.

  4. #4
    Registered User
    Join Date
    03-12-2017
    Location
    United Kingdom
    MS-Off Ver
    2016
    Posts
    19

    Re: Formula for calculating working hours (normal, overtime, -lunch)

    Hi Daria,

    Normal: =IF(((G12-F12)*24)>=8.5,8,(G12-F12)*24)
    Overtime: =IF((G12-F12)*24>8.5, (G12-F12)*24-8.5, 0)

    Try that.

    Ben

  5. #5
    Registered User
    Join Date
    03-21-2017
    Location
    Tallinn, Estonia
    MS-Off Ver
    2013
    Posts
    4

    Re: Formula for calculating working hours (normal, overtime, -lunch)

    hi, Ben,

    thank you very much! Now it is working a bit better, but there is an issue for situations when the person worked less than 8 hours. If I use your suggestion in a situation when a person worked from 8:00 till 15:00, the normal amount of hours shows 7, whereas it should be 6.5.

  6. #6
    Forum Expert
    Join Date
    05-20-2015
    Location
    Chicago, Illinois
    MS-Off Ver
    2016
    Posts
    2,103

    Re: Formula for calculating working hours (normal, overtime, -lunch)

    After how many hours should lunch automatically be deducted? If the employee worked 2 hours, is there a lunch deduction, or does the lunch deduction kick in at 4 hours? 5 hours?

  7. #7
    Registered User
    Join Date
    03-21-2017
    Location
    Tallinn, Estonia
    MS-Off Ver
    2013
    Posts
    4

    Re: Formula for calculating working hours (normal, overtime, -lunch)

    The lunch is from 12:00-12:30, so if the person works from 08:00 till 12:00, then lunch is not deducted

  8. #8
    Forum Expert
    Join Date
    05-20-2015
    Location
    Chicago, Illinois
    MS-Off Ver
    2016
    Posts
    2,103

    Re: Formula for calculating working hours (normal, overtime, -lunch)

    Helpful detail! Experiment with the following, see if it holds up:

    In H12: =MIN(8,24*MAX(MIN(TIME(12,0,0),G12)-F12,0)+24*MAX(G12-MAX(TIME(12,30,0),F12),0))

    In I12: =24*MAX(MIN(TIME(12,0,0),G12)-F12,0)+24*MAX(G12-MAX(TIME(12,30,0),F12),0)-H12

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. [SOLVED] Overtime formula not calculating a minimum set hours
    By blinhart in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 03-15-2016, 10:57 AM
  2. formula to track overtime,normal hours, total time
    By thenry in forum Excel General
    Replies: 5
    Last Post: 09-30-2015, 12:38 AM
  3. Replies: 7
    Last Post: 10-07-2014, 10:00 PM
  4. Replies: 2
    Last Post: 01-17-2014, 02:22 PM
  5. Replies: 8
    Last Post: 06-11-2013, 05:34 PM
  6. Timesheet formula for calculating ordinary hours and overtime hours.
    By zoen in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 12-18-2011, 04:23 AM
  7. need help w/formula for calculating overtime hours
    By jv749297 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 01-17-2005, 04:06 PM

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