+ Reply to Thread
Results 1 to 6 of 6

AVERAGEIF with String Parsing

  1. #1
    Registered User
    Join Date
    07-14-2011
    Location
    CA
    MS-Off Ver
    Excel 2003
    Posts
    3

    AVERAGEIF with String Parsing

    First time poster to Excel Forum, so I greatly appreciate your help.

    I've been tasked with calculating the average duration of a task across multiple markets. The hard part is the data needed to complete the calculation is included in a cell with two other pieces of information. Trust me, I'd rather break the data into separate columns, but my manager won't let me.

    So the task columns can be formatted in one of two ways:
    • Complete task = "c" {Date task was completed} (Duration)
    • Activate task = {Expected completion date}

    Here's an example of the data (attachment might be easier to read):

    Market Task_1 Task_2
    A c 06/01/11 (42) c 6/1/11 (42)
    B 07/25/11 c 06/21/11 (4)
    C c 06/01/11 (42) c 06/01/11 (5)
    D c 06/05/11 (4) 08/24/11


    I thought I was close to completing the calculation using AVERAGEIF and MID, but I can't seem to get a working function. Any ideas?


    Thanks,

    James
    Attached Files Attached Files
    Last edited by sdoah206; 07-14-2011 at 12:48 PM.

  2. #2
    Valued Forum Contributor Miraun's Avatar
    Join Date
    04-03-2009
    Location
    New England
    MS-Off Ver
    2003, 2007, 2010, 2013
    Posts
    554

    Re: AVERAGEIF with String Parsing

    Hey James;

    I'm having a little bit of difficulty understanding exactly what you're looking for based upon the information provided.

    Which values are you looking to average? For Task 2, would it be the average of 42, 4, and 5, as those are the ones marked as completed? Or are you also looking to calculate the number of workdays from the estimated completion date until the current date?

    Are the dates important at all?

    C2 was dated as 6/1/11 where the other dates were listed as 8 digit strings, so I would have expected to see this as 06/01/11, similarly to cell C4... is that a common problem within the worksheet?

    If your boss doesn't like the idea of separating out the data into separate columns, are you looking to do the entire parsing through and adding up in a single cell? Can you add additional columns?
    Going for Guru! Click the Star to the bottom left of this post if I helped!

  3. #3
    Registered User
    Join Date
    07-14-2011
    Location
    CA
    MS-Off Ver
    Excel 2003
    Posts
    3

    Re: AVERAGEIF with String Parsing

    Thanks for the response. Let me see if I can clarify.

    I'm looking to average the duration for completed tasks only. So as you indicate below for task_2, it would be the average of 42, 4, 5.

    I'm not concerned about calculating the number of work days from estimated completion to the current date.

    The formatting of the dates is not important. They should all be 8 digits, so my apologies for the inconsistent example. Then again, I have a feeling users will not be consistent in how the dates are entered.

    My boss wants the calculation completed in one field as there are about 30-40 columns of tasks already.

  4. #4
    Valued Forum Contributor Miraun's Avatar
    Join Date
    04-03-2009
    Location
    New England
    MS-Off Ver
    2003, 2007, 2010, 2013
    Posts
    554

    Re: AVERAGEIF with String Parsing

    Well, as an interim response, I've accomplished the if statements to obtain the numbers... but for some reason, I'm having problems when I integrate them into array statements. As long as the dates are formatted as 00/00/00, the following will work:

    =IF(LEFT(C3,1)="c",IF(ISERROR(MID(C3,13,2)/1)=FALSE,MID(C3,13,2),MID(C3,13,1)),0)

    Unfortunately, I'm leaving for the day, hopefully another forum member can leverage that equation towards making a sum and count array function.

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

    Re: AVERAGEIF with String Parsing

    Assuming duration is always in brackets you can use this array formula

    =AVERAGE(IF(LEFT(C2:C10)="C",-MID(C2:C10,FIND("(",C2:C10),10)))

    confirmed with CTRL+SHIFT+ENTER
    Audere est facere

  6. #6
    Registered User
    Join Date
    07-14-2011
    Location
    CA
    MS-Off Ver
    Excel 2003
    Posts
    3

    Thumbs up Re: AVERAGEIF with String Parsing

    Worked like a charm... Thanks to both of you for your help.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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