+ Reply to Thread
Results 1 to 6 of 6

Help with Timesheet overtime & night calculation

Hybrid View

  1. #1
    Registered User
    Join Date
    12-18-2024
    Location
    Portugal
    MS-Off Ver
    Office 365
    Posts
    3

    Help with Timesheet overtime & night calculation

    Hi Everyone

    I'm HR Manager and I'm currently updating our internal timesheet but all formulas I found can't do what I specifically need - and I'm not sure if it's possible without macros / VBA.

    I want to be able to calculate a night shift and overtime.

    EXAMPLE:

    20:00 to 00:00 | 00:00 to 08:00

    In my country night shift is between 22:00 to 07:00 and overtime is above 8 hours daily

    Total is 12 houurs - this I've been able to create
    Overtime is 4 hours - this I've been able to create
    Night hours is 9 hours - This is what I need help with

    Example.png

    Is it possible to calculate something as IF hours above 22 and bellow 07 calculate ...

    Thank you so much!
    Attached Files Attached Files
    Last edited by mnunes17; 12-18-2024 at 09:24 AM.

  2. #2
    Forum Moderator zbor's Avatar
    Join Date
    02-10-2009
    Location
    Croatia
    MS-Off Ver
    365 ProPlus
    Posts
    16,103

    Re: Help with Timesheet overtime & night calculation

    Welcome to the forum

    Please attach a sample workbook (not a picture or pasted copy). Make sure there is just enough data to demonstrate your need. Include a BEFORE sheet and an AFTER sheet in the workbook if needed to show the process you're trying to complete or automate. Make sure your desired results are shown, mock them up manually if necessary.

    Remember to desensitize the data.

    Click on GO ADVANCED and then scroll down to Manage Attachments to open the upload window.
    Never use Merged Cells in Excel

  3. #3
    Registered User
    Join Date
    12-18-2024
    Location
    Portugal
    MS-Off Ver
    Office 365
    Posts
    3

    Re: Help with Timesheet overtime & night calculation

    Dear Zbor, thank you for the support - I've updated the post, is the file as you asked?

    I know the file is quite basic and also the formula for the hours worked - any suggestions are truly welcomed.
    Last edited by mnunes17; 12-18-2024 at 09:29 AM.

  4. #4
    Forum Expert
    Join Date
    04-14-2009
    Location
    Taiwan
    MS-Off Ver
    Excel 2016,2019,O365
    Posts
    2,976

    Re: Help with Timesheet overtime & night calculation

    I4
    =LET(
       start,B4,
       end,IF(E4="",IF(C4-B4<0,C4+1,C4),IF(E4-B4<0,E4+1,E4)),
       break,MEDIAN(7/24,start+4/24,MIN(start+4/24+F4,end))-MEDIAN(0,start+4/24,MIN(start+4/24+F4,end))+MEDIAN(1+7/24,start+4/24,MIN(start+4/24+F4,end))-MEDIAN(22/24,start+4/24,MIN(start+4/24+F4,end)),
       IF(B4="","",MEDIAN(7/24,start,end)-MEDIAN(0,start,end)+MEDIAN(1+7/24,start,end)-MEDIAN(22/24,start,end)-break)
    )
    J4
    =LET(
       end,IF(E4="",IF(C4-B4<0,C4+1,C4),IF(E4-B4<0,E4+1,E4)),
       start,end-H4,
       IF(B4="","",MIN(MEDIAN(7/24,start,end)-MEDIAN(0,start,end)+MEDIAN(1+7/24,start,end)-MEDIAN(22/24,start,end),8/24))
    )
    both copy down.
    Attached Files Attached Files
    Last edited by windknife; 12-18-2024 at 12:29 PM.

  5. #5
    Registered User
    Join Date
    12-18-2024
    Location
    Portugal
    MS-Off Ver
    Office 365
    Posts
    3

    Re: Help with Timesheet overtime & night calculation

    Thank you Windknife!

    does the formula bellow would for
    Attachment 885173 -I attached the file as well

    =LET(start1,B4,end1,IF(AND(C4<>"",C4<B4),C4+1,C4),start2,D4,end2,IF(AND(E4<>"",E4<D4),E4+1,E4),break1Start,start1+4/24,break1End,MIN(break1Start+F4/24,end1),break2Start,start2+4/24,break2End,MIN(break2Start+F4/24,end2),break1,IF(AND(start1<>"",end1<>""),MAX(0,MEDIAN(7/24,break1Start,break1End)-MEDIAN(0,break1Start,break1End)+MEDIAN(1+7/24,break1Start,break1End)-MEDIAN(22/24,break1Start,break1End)),0),break2,IF(AND(start2<>"",end2<>""),MAX(0,MEDIAN(7/24,break2Start,break2End)-MEDIAN(0,break2Start,break2End)+MEDIAN(1+7/24,break2Start,break2End)-MEDIAN(22/24,break2Start,break2End)),0),totalTime1,IF(AND(start1<>"",end1<>""),MAX(0,MEDIAN(7/24,start1,end1)-MEDIAN(0,start1,end1)+MEDIAN(1+7/24,start1,end1)-MEDIAN(22/24,start1,end1)-break1),0),totalTime2,IF(AND(start2<>"",end2<>""),MAX(0,MEDIAN(7/24,start2,end2)-MEDIAN(0,start2,end2)+MEDIAN(1+7/24,start2,end2)-MEDIAN(22/24,start2,end2)-break2),0),IF(B4="","",totalTime1+totalTime2))
    Attached Files Attached Files

  6. #6
    Forum Expert
    Join Date
    04-14-2009
    Location
    Taiwan
    MS-Off Ver
    Excel 2016,2019,O365
    Posts
    2,976

    Re: Help with Timesheet overtime & night calculation

    I don't sure how to process this.
    One guess,
    I4
    =LET(
       start,B4,
       end,IF(C4-B4<0,C4+1,C4),
       break,MEDIAN(7/24,start+4/24,start+4/24+F4)-MEDIAN(0,start+4/24,start+4/24+F4)+MEDIAN(1+7/24,start+4/24,start+4/24+F4)-MEDIAN(22/24,start+4/24,start+4/24+F4),
       night,IF(B4="",0,MEDIAN(7/24,start,end)-MEDIAN(0,start,end)+MEDIAN(1+7/24,start,end)-MEDIAN(22/24,start,end)-break),
       startx,D4,
       endx,IF(E4-D4<0,E4+1,D4),
       breakx,MEDIAN(7/24,startx+4/24,startx+4/24+F4)-MEDIAN(0,startx+4/24,startx+4/24+F4)+MEDIAN(1+7/24,startx+4/24,startx+4/24+F4)-MEDIAN(22/24,startx+4/24,startx+4/24+F4),
       nightx,IF(D4="",0,MEDIAN(7/24,startx,endx)-MEDIAN(0,startx,endx)+MEDIAN(1+7/24,startx,endx)-MEDIAN(22/24,startx,endx)-breakx),
       IF(B4="","",night+nightx)
    )
    J4
    =LET(
       end,IF(E4="",IF(C4-B4<0,C4+1,C4),IF(E4-B4<0,E4+1,E4)),
       start,end-H4,
       IF(B4="","",MIN(MEDIAN(7/24,start,end)-MEDIAN(0,start,end)+MEDIAN(1+7/24,start,end)-MEDIAN(22/24,start,end),8/24))
    )
    both copied down.

+ 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. Night Hours Timesheet Calculation
    By EmmaTwks in forum Excel General
    Replies: 4
    Last Post: 07-05-2019, 09:19 AM
  2. Replies: 3
    Last Post: 09-13-2017, 10:08 AM
  3. Timesheet, overtime and double overtime calculation
    By breegunn in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 05-10-2016, 07:17 PM
  4. [SOLVED] Timesheet with overtime calculation between certain hours, days only
    By ExcelNoviceHexham in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 05-02-2013, 12:21 PM
  5. Timesheet calculation for overtime and double overtime
    By eortega in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 03-29-2013, 03:28 PM
  6. [SOLVED] Timesheet Overtime Calculation
    By missionvalley1 in forum Excel General
    Replies: 8
    Last Post: 04-09-2012, 10:35 AM
  7. Timesheet / Overtime rate calculation
    By mobiay in forum Excel General
    Replies: 3
    Last Post: 03-19-2008, 04:42 PM

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