+ Reply to Thread
Results 1 to 12 of 12

Response time in hours and minutes excluding weekends and holidays

Hybrid View

  1. #1
    Registered User
    Join Date
    07-02-2018
    Location
    Spokane, WA
    MS-Off Ver
    2016
    Posts
    6

    Response time in hours and minutes excluding weekends and holidays

    I am struggling to develop a formula to calculate response time for technical support calls at our company. Below are a few examples from my data set and the current formula I am using.

    Incoming date/time Response date/time Total [h]:mm:ss
    1/02/18 07:54:00 1/05/18 08:32:00 27:38:00
    1/02/18 08:36:00 1/02/18 08:39:00 0:03:00
    1/02/18 08:58:00 1/02/18 09:05:00 0:07:00
    1/02/18 09:08:00 1/03/18 10:22:00 10:14:00
    1/02/18 09:12:00 1/02/18 10:19:00 1:07:00
    1/02/18 09:22:00 1/02/18 09:31:00 0:09:00


    Formula - Current

    R = incoming date and time for call
    S = response date and time for call
    W = work time end
    V = work time start

    =(NETWORKDAYS(R2,S2)-1)*($W$2-$V$2)+(MOD(S2,1)-MOD(R2,1))

    The problem I am running into is calls can come in outside of the normal business hours set in W and V (8am-5pm) and on the weekends. Our support engineers sometimes show up early and respond to calls before 8am or stay late and respond to calls after 5pm. I want to calculate our response time for normal business hours, so if a call comes in on the weekend, the incoming time should be calculated for Monday at 8am start and end no matter what time it is for the response date/time. My current formula errors (with a negative) for the following scenario


    Incoming date/time Response date/time
    1/13/18 11:49:00 1/15/18 10:51:00
    1/23/18 17:00:00 1/24/18 07:52:00
    1/27/18 09:43:00 1/29/18 09:15:00
    1/31/18 17:36:00 2/01/18 08:15:00
    2/01/18 19:11:00 2/02/18 08:39:00
    2/02/18 15:35:00 2/03/18 14:00:00
    2/04/18 20:54:00 2/05/18 08:29:00
    2/04/18 21:09:00 2/05/18 08:30:00
    2/05/18 18:56:00 2/06/18 08:14:00
    2/28/18 22:53:00 3/01/18 08:26:00
    3/03/18 12:28:00 3/05/18 07:55:00
    3/06/18 17:30:00 3/07/18 07:57:00
    3/06/18 21:58:00 3/07/18 08:13:00
    3/07/18 17:33:00 3/08/18 07:59:00
    3/13/18 17:42:00 3/14/18 08:02:00
    3/13/18 21:54:00 3/14/18 10:07:00
    3/23/18 19:16:00 3/26/18 08:48:00
    3/26/18 21:56:00 3/27/18 08:30:00
    3/28/18 22:10:00 3/29/18 09:08:00
    4/04/18 17:43:00 4/05/18 08:00:00
    4/04/18 17:49:00 4/05/18 08:06:00
    4/04/18 18:43:00 4/05/18 08:48:00
    4/10/18 23:44:00 4/11/18 08:54:00
    4/11/18 19:57:00 4/12/18 07:44:00
    4/11/18 21:02:00 4/12/18 07:44:00
    4/11/18 23:25:00 4/12/18 07:46:00
    4/13/18 13:33:00 4/16/18 00:00:00
    4/16/18 10:37:00 4/16/18 00:00:00
    4/20/18 17:23:00 4/23/18 07:42:00
    4/20/18 19:46:00 4/23/18 07:55:00
    4/21/18 22:39:00 4/24/18 10:17:00
    4/25/18 21:58:00 4/26/18 09:55:00
    4/28/18 16:57:00 4/30/18 11:33:00
    4/30/18 23:18:00 5/01/18 10:32:00
    5/03/18 17:09:00 5/04/18 08:03:00
    5/10/18 16:57:00 5/11/18 07:38:00
    5/12/18 14:41:00 5/14/18 07:56:00
    5/31/18 20:04:00 6/01/18 08:20:00
    5/31/18 21:18:00 6/01/18 08:31:00
    6/04/18 12:01:00 6/04/18 12:00:00
    6/07/18 17:49:00 6/08/18 08:10:00
    6/11/18 18:14:00 6/12/18 08:26:00
    6/12/18 23:51:00 6/13/18 08:03:00
    6/24/18 21:35:00 6/25/18 07:53:00
    6/24/18 22:00:00 6/25/18 08:08:00
    6/24/18 22:14:00 6/25/18 08:09:00

    Any advice would be much appreciated on this!

    EDIT: I have added the Excel workbook I am working on with examples of correct and incorrect values.
    Attached Files Attached Files
    Last edited by ACBenson86; 07-18-2018 at 02:18 PM.

  2. #2
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (both in England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2507 (Windows 11 Home 24H2 64-bit)
    Posts
    91,792

    Re: Response time in hours and minutes excluding weekends and holidays

    Welcome to the forum! Here's the first bit of advice:

    Will you please attach a sample Excel workbook? We are not able to work with or manipulate a picture of one and nobody wants to have to recreate your data from scratch.

    1. Make sure that your sample data are REPRESENTATIVE of your real data. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    2. Make sure that your desired results are also shown (mock up the results manually).

    3. Make sure that all confidential data is removed or replaced with dummy data first (e.g. names, addresses, E-mails, etc.).

    4. Try to avoid using merged cells as they cause lots of problems.

    Unfortunately the attachment icon doesn't work at the moment, so to attach an Excel file you have to do the following: just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.

    Please pay particular attention to point 2 (above): without an idea of your intended outcomes, it is often very difficult to offer appropriate advice.
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help. It's a universal courtesy.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    NB:
    as a Moderator, I never accept friendship requests.
    Forum Rules (updated August 2023): please read them here.

  3. #3
    Registered User
    Join Date
    07-02-2018
    Location
    Spokane, WA
    MS-Off Ver
    2016
    Posts
    6

    Re: Response time in hours and minutes excluding weekends and holidays

    Quote Originally Posted by AliGW View Post
    Welcome to the forum! Here's the first bit of advice:

    Will you please attach a sample Excel workbook? We are not able to work with or manipulate a picture of one and nobody wants to have to recreate your data from scratch.

    1. Make sure that your sample data are REPRESENTATIVE of your real data. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    2. Make sure that your desired results are also shown (mock up the results manually).

    3. Make sure that all confidential data is removed or replaced with dummy data first (e.g. names, addresses, E-mails, etc.).

    4. Try to avoid using merged cells as they cause lots of problems.

    Unfortunately the attachment icon doesn't work at the moment, so to attach an Excel file you have to do the following: just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.

    Please pay particular attention to point 2 (above): without an idea of your intended outcomes, it is often very difficult to offer appropriate advice.
    Thanks for the intro and guideline overview. I'm sure if I would have read the forum rules, It wouldn't have been necessary

  4. #4
    Forum Expert 63falcondude's Avatar
    Join Date
    08-22-2016
    Location
    USA
    MS-Off Ver
    365
    Posts
    6,266

    Re: Response time in hours and minutes excluding weekends and holidays

    Try this in T2:

    =(NETWORKDAYS(R2,S2)-1)*(W$2-V$2)+IF(NETWORKDAYS(S2,S2),MEDIAN(MOD(S2,1),W$2,V$2),W$2)-MEDIAN(NETWORKDAYS(R2,R2)*MOD(R2,1),W$2,V$2)

    Source: https://www.extendoffice.com/documen...-weekends.html

  5. #5
    Registered User
    Join Date
    07-02-2018
    Location
    Spokane, WA
    MS-Off Ver
    2016
    Posts
    6

    Re: Response time in hours and minutes excluding weekends and holidays

    63falcondude,

    Thanks for the response. This is very close to what I already have and actually made some values that were correct incorrect, including the example in Row 5 of the spreadsheet I attached.

  6. #6
    Forum Expert dflak's Avatar
    Join Date
    11-24-2015
    Location
    North Carolina
    MS-Off Ver
    365
    Posts
    7,957

    Re: Response time in hours and minutes excluding weekends and holidays

    See if one of these helps - I think you want the second one NetWorkHours.

    Function WorkHours(StartDate As Date, NumHours As Double, ShiftStart As Date, ShiftEnd As Date, _
        Optional Holidays As Range) As Date
    Application.Volatile
    Dim StartDay As Date            ' Start of the workday
    Dim EndDay As Date              ' End of the workday
    Dim EndHours As Date            ' Ending time of project
    Dim EndDate As Date             ' Ending date of project
    Dim DayHours As Double          ' Number of hours in the workday
    Dim BeginTime As Date           ' Beginning of task or shift
    
    ' Initialize variables
    EndDate = StartDate + NumHours / 24
    EndDay = Int(StartDate) + ShiftEnd
    BeginTime = StartDate - Int(StartDate)
    
    ' While the end date still exceeds the end of day for a workday
    While EndDate > EndDay
        ' increment EndDay
        EndDay = EndDay + 1
        ' Process only for workdays
        If IsWorkday(EndDay, Range("Holidays")) = True Then
            'decrement the hours
            NumHours = NumHours - 24 * (ShiftEnd - BeginTime)
            BeginTime = ShiftStart  ' Begin time becomes shift start after the first day
            ' Compute new enddate
            EndDate = Int(EndDay) + ShiftStart + NumHours / 24
        Else
            ' increment the end date for weekends and holidays without processing
            EndDate = EndDate + 1
        End If
    Wend
    
    WorkHours = EndDate
    End Function
    
    Function IsWorkday(MyDate As Date, Optional Holidays As Range) As Boolean
    Dim cl As Range             ' Pointer to holiday range
    Dim bRtn As Boolean         ' Return value (default = True unless proven otherwise)
    Dim WkDay As Long
    
    bRtn = True
    
    ' Check to see if the date is on the holiday list
    If Not Holidays Is Nothing Then
        For Each cl In Holidays
            If Int(MyDate) = cl.Value Then
                bRtn = False
                Exit For
         End If
        Next
    End If
    
    ' Check to see if the day is a weekend
    WkDay = Weekday(MyDate, vbMonday)
    
    If WkDay > 5 Then
        bRtn = False
    End If
    
    IsWorkday = bRtn
           
    End Function
    OR

    Function NetWorkHours(Shift_Start As Date, Shift_End As Date, Start_Time As Date, End_Time As Date, _
        Optional Holidays As Range) As Double
    Dim NumHrs As Double
    Dim ShiftHrs As Double
    Dim DayDiff As Long
    Dim DayLoop As Long
    Dim DayHoliday As Boolean
    
    ShiftHrs = Shift_End - Shift_Start
    NumHrs = 0
    
    ' Figure out the number of hours
    If Time_Fraction(Start_Time) <= Time_Fraction(End_Time) Then
        NumHrs = Time_Fraction(End_Time) - Time_Fraction(Start_Time)
    Else
        NumHrs = (Time_Fraction(Shift_End) - Time_Fraction(Start_Time)) + _
        (Time_Fraction(End_Time) - Time_Fraction(Shift_Start))
    End If
    
    ' Determine the number of extra days to add
    DayDiff = Int(End_Time - Start_Time)
    For DayLoop = 1 To DayDiff
        ' check to see if day is a weekend or holiday
        If Holidays Is Nothing Then
            DayHoliday = False
        Else
            DayHoliday = Is_Holiday(Int(Start_Time) + DayLoop)
        End If
        If Weekday(Int(Start_Time) + DayLoop, 2) < 6 And DayHoliday = False Then
            NumHrs = NumHrs + ShiftHrs
        End If
    Next DayLoop
    
    NetWorkHours = 24 * NumHrs
    
    End Function
    One spreadsheet to rule them all. One spreadsheet to find them. One spreadsheet to bring them all and at corporate, bind them.

    A picture is worth a thousand words, but a sample spreadsheet is more likely to be worked on.

  7. #7
    Registered User
    Join Date
    07-02-2018
    Location
    Spokane, WA
    MS-Off Ver
    2016
    Posts
    6

    Re: Response time in hours and minutes excluding weekends and holidays

    Quote Originally Posted by dflak View Post
    See if one of these helps - I think you want the second one NetWorkHours.

    Function WorkHours(StartDate As Date, NumHours As Double, ShiftStart As Date, ShiftEnd As Date, _
        Optional Holidays As Range) As Date
    Application.Volatile
    Dim StartDay As Date            ' Start of the workday
    Dim EndDay As Date              ' End of the workday
    Dim EndHours As Date            ' Ending time of project
    Dim EndDate As Date             ' Ending date of project
    Dim DayHours As Double          ' Number of hours in the workday
    Dim BeginTime As Date           ' Beginning of task or shift
    
    ' Initialize variables
    EndDate = StartDate + NumHours / 24
    EndDay = Int(StartDate) + ShiftEnd
    BeginTime = StartDate - Int(StartDate)
    
    ' While the end date still exceeds the end of day for a workday
    While EndDate > EndDay
        ' increment EndDay
        EndDay = EndDay + 1
        ' Process only for workdays
        If IsWorkday(EndDay, Range("Holidays")) = True Then
            'decrement the hours
            NumHours = NumHours - 24 * (ShiftEnd - BeginTime)
            BeginTime = ShiftStart  ' Begin time becomes shift start after the first day
            ' Compute new enddate
            EndDate = Int(EndDay) + ShiftStart + NumHours / 24
        Else
            ' increment the end date for weekends and holidays without processing
            EndDate = EndDate + 1
        End If
    Wend
    
    WorkHours = EndDate
    End Function
    
    Function IsWorkday(MyDate As Date, Optional Holidays As Range) As Boolean
    Dim cl As Range             ' Pointer to holiday range
    Dim bRtn As Boolean         ' Return value (default = True unless proven otherwise)
    Dim WkDay As Long
    
    bRtn = True
    
    ' Check to see if the date is on the holiday list
    If Not Holidays Is Nothing Then
        For Each cl In Holidays
            If Int(MyDate) = cl.Value Then
                bRtn = False
                Exit For
         End If
        Next
    End If
    
    ' Check to see if the day is a weekend
    WkDay = Weekday(MyDate, vbMonday)
    
    If WkDay > 5 Then
        bRtn = False
    End If
    
    IsWorkday = bRtn
           
    End Function
    OR

    Function NetWorkHours(Shift_Start As Date, Shift_End As Date, Start_Time As Date, End_Time As Date, _
        Optional Holidays As Range) As Double
    Dim NumHrs As Double
    Dim ShiftHrs As Double
    Dim DayDiff As Long
    Dim DayLoop As Long
    Dim DayHoliday As Boolean
    
    ShiftHrs = Shift_End - Shift_Start
    NumHrs = 0
    
    ' Figure out the number of hours
    If Time_Fraction(Start_Time) <= Time_Fraction(End_Time) Then
        NumHrs = Time_Fraction(End_Time) - Time_Fraction(Start_Time)
    Else
        NumHrs = (Time_Fraction(Shift_End) - Time_Fraction(Start_Time)) + _
        (Time_Fraction(End_Time) - Time_Fraction(Shift_Start))
    End If
    
    ' Determine the number of extra days to add
    DayDiff = Int(End_Time - Start_Time)
    For DayLoop = 1 To DayDiff
        ' check to see if day is a weekend or holiday
        If Holidays Is Nothing Then
            DayHoliday = False
        Else
            DayHoliday = Is_Holiday(Int(Start_Time) + DayLoop)
        End If
        If Weekday(Int(Start_Time) + DayLoop, 2) < 6 And DayHoliday = False Then
            NumHrs = NumHrs + ShiftHrs
        End If
    Next DayLoop
    
    NetWorkHours = 24 * NumHrs
    
    End Function
    I'm familiar with macros in Excel, but definitely not proficient...is there something in this that I need to change in order to reference the cells I have in my spreadsheet for incoming/response date and times?

  8. #8
    Forum Expert dflak's Avatar
    Join Date
    11-24-2015
    Location
    North Carolina
    MS-Off Ver
    365
    Posts
    7,957

    Re: Response time in hours and minutes excluding weekends and holidays

    Here is a sample. Note, I don't take into consideration lunch breaks. Also revised code

    Function NetWorkHours(Shift_Start As Date, Shift_End As Date, Start_Time As Date, End_Time As Date, _
        Optional Holidays As Range) As Double
    Dim NumHrs As Double
    Dim ShiftHrs As Double
    Dim DayDiff As Long
    Dim DayLoop As Long
    Dim DayHoliday As Boolean
    
    ShiftHrs = Shift_End - Shift_Start
    NumHrs = 0
    
    ' Figure out the number of hours
    If Time_Fraction(Start_Time) <= Time_Fraction(End_Time) Then
        NumHrs = Time_Fraction(End_Time) - Time_Fraction(Start_Time)
    Else
        NumHrs = (Time_Fraction(Shift_End) - Time_Fraction(Start_Time)) + _
        (Time_Fraction(End_Time) - Time_Fraction(Shift_Start))
    End If
    
    ' Determine the number of extra days to add
    DayDiff = Int(End_Time - Start_Time)
    For DayLoop = 1 To DayDiff
        ' check to see if day is a weekend or holiday
        If Holidays Is Nothing Then
            DayHoliday = False
        Else
            DayHoliday = Is_Holiday(Int(Start_Time) + DayLoop, Holidays)
        End If
        If Weekday(Int(Start_Time) + DayLoop, 2) < 6 And DayHoliday = False Then
            NumHrs = NumHrs + ShiftHrs
        End If
    Next DayLoop
    
    NetWorkHours = 24 * NumHrs
    
    End Function
    
    Function Is_Holiday(MyDate As Date, Holidays As Range) As Boolean
    Dim cl As Range                         ' Pointer to Holiday list
    
    ' Set to true if date is on the list of holidays
    For Each cl In Holidays
        If MyDate = cl.Value Then
            Is_Holiday = True
            Exit Function
        End If
    Next cl
    
    Is_Holiday = False
    End Function
    
    Function Time_Fraction(MyTime As Date) As Double
    Time_Fraction = TimeSerial(Hour(MyTime), Minute(MyTime), Second(MyTime))
    End Function
    Attached Files Attached Files

  9. #9
    Registered User
    Join Date
    07-02-2018
    Location
    Spokane, WA
    MS-Off Ver
    2016
    Posts
    6

    Re: Response time in hours and minutes excluding weekends and holidays

    Quote Originally Posted by dflak View Post
    Here is a sample. Note, I don't take into consideration lunch breaks. Also revised code

    Function NetWorkHours(Shift_Start As Date, Shift_End As Date, Start_Time As Date, End_Time As Date, _
        Optional Holidays As Range) As Double
    Dim NumHrs As Double
    Dim ShiftHrs As Double
    Dim DayDiff As Long
    Dim DayLoop As Long
    Dim DayHoliday As Boolean
    
    ShiftHrs = Shift_End - Shift_Start
    NumHrs = 0
    
    ' Figure out the number of hours
    If Time_Fraction(Start_Time) <= Time_Fraction(End_Time) Then
        NumHrs = Time_Fraction(End_Time) - Time_Fraction(Start_Time)
    Else
        NumHrs = (Time_Fraction(Shift_End) - Time_Fraction(Start_Time)) + _
        (Time_Fraction(End_Time) - Time_Fraction(Shift_Start))
    End If
    
    ' Determine the number of extra days to add
    DayDiff = Int(End_Time - Start_Time)
    For DayLoop = 1 To DayDiff
        ' check to see if day is a weekend or holiday
        If Holidays Is Nothing Then
            DayHoliday = False
        Else
            DayHoliday = Is_Holiday(Int(Start_Time) + DayLoop, Holidays)
        End If
        If Weekday(Int(Start_Time) + DayLoop, 2) < 6 And DayHoliday = False Then
            NumHrs = NumHrs + ShiftHrs
        End If
    Next DayLoop
    
    NetWorkHours = 24 * NumHrs
    
    End Function
    
    Function Is_Holiday(MyDate As Date, Holidays As Range) As Boolean
    Dim cl As Range                         ' Pointer to Holiday list
    
    ' Set to true if date is on the list of holidays
    For Each cl In Holidays
        If MyDate = cl.Value Then
            Is_Holiday = True
            Exit Function
        End If
    Next cl
    
    Is_Holiday = False
    End Function
    
    Function Time_Fraction(MyTime As Date) As Double
    Time_Fraction = TimeSerial(Hour(MyTime), Minute(MyTime), Second(MyTime))
    End Function
    Looks like this gives me the same values, but I do like how you did this and will likely be easier to account for specific examples like call coming in before/after business hours and employee responding before/after business hours. I appreciate your assistance...will hopefully report back good news and maybe updated code.

  10. #10
    Forum Expert dflak's Avatar
    Join Date
    11-24-2015
    Location
    North Carolina
    MS-Off Ver
    365
    Posts
    7,957

    Re: Response time in hours and minutes excluding weekends and holidays

    These are user-defined functions and will work either in code or a formulas on the worksheet.

    To use NetWorkHours, you must feed it the following parameters:
    • Shift Start and Shift End (E.g 08:00, 17:00)
    • Task Start and Task End (including date) - E.g. 7/18/2018 12:45, 7/19/2018 09:30
    • Range of Holiday Dates (Optional)

    In the example above it will compute the time between 12:45 to 17:00 and then add on the time between 8:00 and 9:30.

  11. #11
    Registered User
    Join Date
    07-02-2018
    Location
    Spokane, WA
    MS-Off Ver
    2016
    Posts
    6

    Re: Response time in hours and minutes excluding weekends and holidays

    I keep getting a value that is used in the formula is of the wrong data type. I even tried inputting the the formula with direct values ie =NetWorkHours("7/18/2018 12:45","7/19/2018 9:30","08:00","17:00","12/1/2018")

  12. #12
    Forum Expert dflak's Avatar
    Join Date
    11-24-2015
    Location
    North Carolina
    MS-Off Ver
    365
    Posts
    7,957

    Re: Response time in hours and minutes excluding weekends and holidays

    Posts crossed - see the example.

+ 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] How To Calculate Net Work Hours Between Two Dates Excluding Weekends Or Holidays?
    By pavankumarbangaru in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 04-23-2018, 11:52 AM
  2. Replies: 9
    Last Post: 07-04-2016, 11:42 PM
  3. Replies: 0
    Last Post: 01-30-2014, 01:22 AM
  4. [SOLVED] Working Hours - excluding weekends, holidays
    By CJENKSY in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 12-05-2013, 02:12 AM
  5. [SOLVED] Elapsed Days Hours Minutes Excluding Weekends and Holidays
    By moshjosh in forum Excel General
    Replies: 7
    Last Post: 12-10-2012, 08:39 AM
  6. Replies: 4
    Last Post: 08-10-2012, 11:41 AM
  7. Replies: 7
    Last Post: 01-11-2011, 06:26 AM

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