+ Reply to Thread
Results 1 to 10 of 10

Calculate SLA target dates while keeping non-working days and hours in a work day relevant

Hybrid View

cubmar Calculate SLA target dates... 10-17-2012, 02:20 AM
daddylonglegs Re: Calculate SLA target... 10-17-2012, 06:13 AM
cubmar Re: Calculate SLA target... 10-17-2012, 06:23 AM
cubmar Re: Calculate SLA target... 10-17-2012, 06:47 AM
daddylonglegs Re: Calculate SLA target... 10-17-2012, 07:20 AM
cubmar Re: Calculate SLA target... 10-17-2012, 07:38 AM
daddylonglegs Re: Calculate SLA target... 10-17-2012, 08:58 AM
cubmar Re: Calculate SLA target... 10-17-2012, 05:54 PM
Cutter Re: Calculate SLA target... 10-17-2012, 08:59 PM
cubmar Re: Calculate SLA target... 10-17-2012, 10:33 PM
  1. #1
    Registered User
    Join Date
    06-25-2012
    Location
    Melbourne
    MS-Off Ver
    Excel 2007
    Posts
    22

    Calculate SLA target dates while keeping non-working days and hours in a work day relevant

    The following thread gave excellent formula for calculating the time accurately between two dates including the start/end of the working day, public holidays, weekends etc.

    http://www.excelforum.com/excel-gene...asure-sla.html

    I used it to construct the following formula:
    =NETWORKDAYS(H2,K2,_NWD)-1)*(_end_of_day-_start_of_day)+IF(NETWORKDAYS(K2,K2,_NWD),MAX(_start_of_day,MOD(K2,1)),_end_of_day)-MEDIAN(NETWORKDAYS(H2,H2,_NWD)*MOD(H2,1),_start_of_day:_end_of_day)

    This gives me accurate hours/minutes between two date/times.

    However, now I have a further requirement.

    The above tells me how long was actually taken from ticket CREATION (H2) to closed date (K2). But I need to calculate the DUE DATE (by when the ticket should have been closed to be within SLA).

    So given the CREATION (H2) and the target number of hours (eg 48), what is the DUE DATE for the closure?

    Just adding 48 to the CREATION DATE will not consider the non-working days (defined in _NWD) or the working hours (defined between _start_of_day and _end_of_day).


    Has anyone tried to achieve similar with any success, please?

    Thanks

  2. #2
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    Microsoft 365
    Posts
    14,699

    Re: Calculate SLA target dates while keeping non-working days and hours in a work day rele

    This is a solution I posted elsewhere:

    If you have your start date/time in A1 then hours to add in B1 (in time format e.g. 36:00 for 36 hours) then this formula in C1 will give end date/time

    =WORKDAY(A1,CEILING((B1+MOD(A1,1)-D$2)/(E$2-D$2),1)-1)+MOD(A1,1)+B1-CEILING(MOD(A1,1)+B1-D$2,E$2-D$2)+E$2-D$2

    where D2 and E2 shows the start and end times of the working day, e.g. 08:00 in D2 and 17:00 in E2
    Audere est facere

  3. #3
    Registered User
    Join Date
    06-25-2012
    Location
    Melbourne
    MS-Off Ver
    Excel 2007
    Posts
    22

    Re: Calculate SLA target dates while keeping non-working days and hours in a work day rele

    Thank you Daddylonglegs.

    I am sure that will be very close to what I want but how can I incorporate the non-working days and the start/end day times (0900-1730) ?

    Thanks

  4. #4
    Registered User
    Join Date
    06-25-2012
    Location
    Melbourne
    MS-Off Ver
    Excel 2007
    Posts
    22

    Re: Calculate SLA target dates while keeping non-working days and hours in a work day rele

    Sorry, I noticed the D2/E2 being start/end of day. Thanks for that.

    It uses WORKDAY, so like NETWORKDAYS I can use a defined range (_NWD).

    However,unless I am mistaken,it fails with this example (DD/MM/YYYY format):

    A1=6/11/2012 16:33
    B1=1:00
    C1=formula but using _NWD which shows 6/11/2012 asda Non working day
    D2=9:00
    E2=17:30

    The answer I see is 7/11/2012 9:03.

    I would say the correct answer is 7/11/2012 10:00 since 6/11/2012 is a non working day and hence the clock starts the next working day at 0900. One hour on is 10am.

  5. #5
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    Microsoft 365
    Posts
    14,699

    Re: Calculate SLA target dates while keeping non-working days and hours in a work day rele

    Yes, you are correct - the formula I suggested only works if the date/time in A1 is within working hours - to make it work for any date/time in A1 try this version

    Formula: copy to clipboard
    =WORKDAY(A1-1,CEILING((B1+MEDIAN(NETWORKDAYS(A1,A1,holidays)*MOD(A1,1),D$2,E$2)-D$2)/(E$2-D$2),1),holidays)+MEDIAN(NETWORKDAYS(A1,A1,holidays)*MOD(A1,1),D$2,E$2)+B1-CEILING(MEDIAN(NETWORKDAYS(A1,A1,holidays)*MOD(A1,1),D$2,E$2)+B1-D$2,E$2-D$2)+E$2-D$2


    Note: in your original formula is K2 always within working hours? If not then I think you could get incorrect results if K2 is after _end_of_day on a working day

  6. #6
    Registered User
    Join Date
    06-25-2012
    Location
    Melbourne
    MS-Off Ver
    Excel 2007
    Posts
    22

    Re: Calculate SLA target dates while keeping non-working days and hours in a work day rele

    That fixed it - THANK YOU!!

    Now the result is 7/11/2012 10:00



    Indeed K2 can be out of working hours and even a non-working day.

    I think it works ok. EG:
    H2=02/09/2012 18:29
    K2=03/09/2012 18:29
    Correct duration: 0900-17:30= 8hr 30min
    Calculated duration: 9:29

    I think this may be wrong !!!


    or

    H2=03/09/2012 17:29
    K2=03/09/2012 18:29
    Correct duration: 1 minute (since even though it was longer, from an SLA perspective, it was completed before the clock started again at 0900 the next day so is considered as if it were 5.30pm)
    Calculated duration: 1:00


    So looks like you highlighted a bug in the formula. This really gets quite messy!

  7. #7
    Forum Expert daddylonglegs's Avatar
    Join Date
    01-14-2006
    Location
    England
    MS-Off Ver
    Microsoft 365
    Posts
    14,699

    Re: Calculate SLA target dates while keeping non-working days and hours in a work day rele

    You can fix that by replacing MAX function with MEDIAN like this

    =(NETWORKDAYS(H2,K2,_NWD)-1)*(_end_of_day-_start_of_day)+IF(NETWORKDAYS(K2,K2,_NWD),MEDIAN(_start_of_day,_end_of_day,MOD(K2,1)),_end_of_day)-MEDIAN(NETWORKDAYS(H2,H2,_NWD)*MOD(H2,1),_start_of_day,_end_of_day)

  8. #8
    Registered User
    Join Date
    06-25-2012
    Location
    Melbourne
    MS-Off Ver
    Excel 2007
    Posts
    22

    Re: Calculate SLA target dates while keeping non-working days and hours in a work day rele

    Many thanks - that works really well.

    I have to admit, I do not understand HOW the formula works but I am jolly glad it does!

  9. #9
    Forum Expert Cutter's Avatar
    Join Date
    05-24-2004
    Location
    Ontario,Canada
    MS-Off Ver
    Excel 2010
    Posts
    6,451

    Re: Calculate SLA target dates while keeping non-working days and hours in a work day rele

    @ cubmar

    Based on your last post it seems that you are satisfied with the solution(s) you've received but you haven't marked your thread as SOLVED. I'll do that for you now but please keep in mind for your future threads that Rule #9 requires you to do that yourself. If your problem has not been solved you can use Thread Tools (located above your first post) and choose "Mark this thread as unsolved".
    Thanks.

    Also, as a relatively new member of the forum, you may not be aware that you can thank those who have helped you by clicking the small star icon located in the lower left corner of the post in which the help was given. By doing so you can add to the reputation(s) of those who helped.

  10. #10
    Registered User
    Join Date
    06-25-2012
    Location
    Melbourne
    MS-Off Ver
    Excel 2007
    Posts
    22

    Re: Calculate SLA target dates while keeping non-working days and hours in a work day rele

    Thank you cutter - noted.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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