+ Reply to Thread
Results 1 to 5 of 5

Calculate the difference in hours in a range

  1. #1
    Registered User
    Join Date
    08-31-2020
    Location
    Forli,Italy
    MS-Off Ver
    2016
    Posts
    2

    Calculate the difference in hours in a range

    I have a situation like this:
    In one cell, I split the time ranges over several lines, for example
    07: 15-10: 27
    10: 35-11: 00
    11: 15-12: 27
    13: 15-13: 27
    14: 15-18: 27
    19: 15-20: 27
    21: 15-23: 39
    I know it would be more logical to have an hourly range divided over several lines, unfortunately I can't do otherwise ... I tried this formula:

    RIGHT(REPLACE(TRIM(MID(REPLACE($G8;CHAR(10);REPT(" ";LEN($G8)));(0)*LEN($G8)+1;LEN($G8)));".";":");5)-LEFT(REPLACE(TRIM(MID(REPLACE($G8;CHAR(10);REPT(" ";LEN($G8)));(0)*LEN($G8)+1;LEN($G8)));".";":");5)+(RIGHT(REPLACE(TRIM(MID(REPLACE($G8;CHAR(10);REPT(" ";LEN($G8)));(1)*LEN($G8)+1;LEN($G8)));".";":");5)-LEFT(REPLACE(TRIM(MID(REPLACE($G8;CHAR(10);REPT(" ";LEN($G8)));(1)*LEN($G8)+1;LEN($G8)));".";":");5))

    But this formula only calculates the first row(To the eye the calculation is also wrong) and doesn't consider the others, is there a way, a formula to do this, calculate the time differences and then add the total, without having to write code in Visual Basic?
    Attached Files Attached Files
    Last edited by marduk87RP; 08-31-2020 at 09:19 AM.

  2. #2
    Forum Expert
    Join Date
    02-11-2014
    Location
    New York
    MS-Off Ver
    Excel 365 (Windows)
    Posts
    5,938

    Re: Calculate the difference in hours in a range

    Array enter (enter using Ctrl-Shift-Enter)

    =SUM(IFERROR(TIMEVALUE(MID(G8,1+(ROW($A$1:$A$12)-1)*12+6,5)),0)-IFERROR(TIMEVALUE(MID(G8,1+(ROW($A$1:$A$12)-1)*12,5)),0))

    If you want hours (for your multiplication) use:

    =SUM(IFERROR(TIMEVALUE(MID(G8,1+(ROW($A$1:$A$12)-1)*12+6,5)),0)-IFERROR(TIMEVALUE(MID(G8,1+(ROW($A$1:$A$12)-1)*12,5)),0))*24

    also array-entered.

    If you could have more than 12 rows of time differences in one cell, change the $A$12 to $A$-something larger.
    Bernie Deitrick
    Excel MVP 2000-2010

  3. #3
    Registered User
    Join Date
    08-31-2020
    Location
    Forli,Italy
    MS-Off Ver
    2016
    Posts
    2

    Re: Calculate the difference in hours in a range

    I try this formula but tells me the formula contains an error

  4. #4
    Forum Expert Tsjallie's Avatar
    Join Date
    09-15-2012
    Location
    NL
    MS-Off Ver
    2010, 2013, 2016
    Posts
    2,077

    Re: Calculate the difference in hours in a range

    This should work and be flexible.
    Formula: copy to clipboard
    Please Login or Register  to view this content.

    Note that it is an array formula. Close with [Ctrl]+[Shift]+[Enter]

    Explaination:
    It's about this part of the formula:

    Formula: copy to clipboard
    Please Login or Register  to view this content.


    Text is G8 where Clean() strips off any unprintable characters like CR and/or LF.

    StartPos is calculated by
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    for the right time and
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    for the left time
    The StartPos is different for each line and needs to be calculated by x*11+7 and x*11+1. Where x = {0,1,2,3,4,5,6}
    The function ROW(1:7)-1 gives you the array x. However you need to construct that function with INDIRECT() as ROW() doesn't directly take variable values.
    The number of elements in the array x is determined by the number of lines in the cell. That is calculated by counting the number of "-" in the cell.

    Once this way times are isolated they are converted to their time values and these are subtracted to get the elapsed times.

    IFERROR is there because an empty cell in column G would give an error.
    Attached Files Attached Files
    Cheers!
    Tsjallie




    --------
    If your problem is solved, pls mark the thread SOLVED (see Thread Tools in the menu above). Thank you!

    If you think design is an expensive waste of time, try doing without ...

  5. #5
    Forum Expert
    Join Date
    02-11-2014
    Location
    New York
    MS-Off Ver
    Excel 365 (Windows)
    Posts
    5,938

    Re: Calculate the difference in hours in a range

    Here's a working file with my formula.... The error is likely due to region and your separator not being a comma..... Opening the file should work for you. If not, try these array formulas:

    =SUM(IFERROR(TIMEVALUE(MID(G8;1+(ROW($A$1:$A$12)-1)*12+6;5));0)-IFERROR(TIMEVALUE(MID(G8;1+(ROW($A$1:$A$12)-1)*12;5));0))

    If you want hours (for your multiplication) use:

    =SUM(IFERROR(TIMEVALUE(MID(G8;1+(ROW($A$1:$A$12)-1)*12+6;5));0)-IFERROR(TIMEVALUE(MID(G8;1+(ROW($A$1:$A$12)-1)*12;5));0))*24
    Attached Files Attached Files
    Last edited by Bernie Deitrick; 08-31-2020 at 12:57 PM.

+ 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 the difference between two dates&time within certain hours
    By Qhamzarul15 in forum Excel Formulas & Functions
    Replies: 17
    Last Post: 01-12-2020, 03:41 PM
  2. Formula to calculate difference of hours based on condiitons
    By saxena_mk in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 04-14-2019, 11:35 AM
  3. Calculate hours difference excl weekends
    By DubX in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 12-18-2012, 09:21 AM
  4. Calculate the difference in hours between two dates?
    By Jonblomberg in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 12-14-2011, 09:42 AM
  5. [SOLVED] Calculate difference in time spanning a day, during office hours o
    By frozenfusion in forum Excel General
    Replies: 1
    Last Post: 08-26-2005, 06:05 AM
  6. [SOLVED] calculate difference in time to hours
    By Chris in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 01-18-2005, 03:06 PM
  7. [SOLVED] How do I calculate difference in days & hours between two dates e.
    By probi2 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 01-12-2005, 12:06 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