+ Reply to Thread
Results 1 to 4 of 4

Extracting Data Based on Criteria

Hybrid View

  1. #1
    Registered User
    Join Date
    06-15-2007
    Posts
    11

    Extracting Data Based on Criteria

    I have a workbook consisting of three different worksheets that all contain the same column headings, Project Name, Value, and Status. In a fourth worksheet in the same workbook I would like to extract the data from the any row on all of the sheets where the Status is equal to "Closed". In other words on each sheet in rows 5 - 20 I have the three columns of data. In the first worksheet two of those rows have a status of "Closed" and in the next worksheet three of them have a status of closed. I would like to create a formula that gives me all five rows containing the data of all three columns in a separate worksheet (i.e., I would like to have all of the "closed" data consolidated in one place). Thank you in advance for your cooperation.

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898
    It's a little ugly, but it works......

    Assuming your sheets are named Sheet1 - Sheet3 and your data is in column A to Column D...where Column D contains the Status....and as you implied, that the data to extract is in Rows 5:20, then try:

    =IF(ROWS($A$1:A1)<=COUNTIF(Sheet1!$D$5:$D$20,"closed"),INDEX(Sheet1!A$5:A$20,SMALL(IF(Sheet1!$D$5:$D$20="closed",ROW(Sheet1!$D$5:$D$20)-ROW($A$5)+1),ROWS($A$1:INDEX(A1:A100,ROW()-ROW(A1))))),IF(ROWS($A$1:INDEX($A$1:$A$100,ROW()-COUNTIF(Sheet1!$D$5:$D$20,"closed")-1))<=COUNTIF(Sheet2!$D$5:$D$20,"closed"),INDEX(Sheet2!A$5:A$20,SMALL(IF(Sheet2!$D$5:$D$20="closed",ROW(Sheet2!$D$5:$D$20)-ROW($A$5)+1),ROWS($A$1:INDEX($A$1:$A$100,ROW()-COUNTIF(Sheet1!$D$5:$D$20,"closed")-1)))),IF(ROWS($A$1:INDEX($A$1:$A$100,ROW()-COUNTIF(Sheet1!$D$5:$D$20,"closed")-COUNTIF(Sheet2!$D$5:$D$20,"closed")-1))<=COUNTIF(Sheet3!$D$5:$D$20,"closed"),INDEX(Sheet3!A$5:A$20,SMALL(IF(Sheet3!$D$5:$D$20="closed",ROW(Sheet3!$D$5:$D$20)-ROW($A$5)+1),ROWS($A$1:INDEX($A$1:$A$100,ROW()-COUNTIF(Sheet1!$D$5:$D$20,"closed")-COUNTIF(Sheet2!$D$5:$D$20,"closed")-1)))),"")))
    The formula has to be confirmed with CTRL+SHIFT+ENTER, not just ENTER.... you will see {} brackets appear around the formula. You can then copy the formula down and across as far as necessary....

    Note: VBA may be a better way to go...
    Last edited by NBVC; 06-16-2007 at 03:51 PM.
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Registered User
    Join Date
    06-15-2007
    Posts
    11

    Thank you

    I'll try that.

  4. #4
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898
    Ok, let me know how it works out....

    BTW: I just noticed that you only mentioned 3 columns of data...if that's the case and Column C is the one with status in it, then adjus formula by changing all D's to C's.....

    e.g.

    =IF(ROWS($A$1:A1)<=COUNTIF(Sheet1!$C$5:$C$20,"closed"),INDEX(Sheet1!A$5:A$20,SMALL(IF(Sheet1!$C$5:$C$20="closed",ROW(Sheet1!$C$5:$C$20)-ROW($A$5)+1),ROWS($A$1:INDEX(A1:A100,ROW()-ROW(A1))))),IF(ROWS($A$1:INDEX($A$1:$A$100,ROW()-COUNTIF(Sheet1!$C$5:$C$20,"closed")-1))<=COUNTIF(Sheet2!$C$5:$C$20,"closed"),INDEX(Sheet2!A$5:A$20,SMALL(IF(Sheet2!$C$5:$C$20="closed",ROW(Sheet2!$C$5:$C$20)-ROW($A$5)+1),ROWS($A$1:INDEX($A$1:$A$100,ROW()-COUNTIF(Sheet1!$C$5:$C$20,"closed")-1)))),IF(ROWS($A$1:INDEX($A$1:$A$100,ROW()-COUNTIF(Sheet1!$C$5:$C$20,"closed")-COUNTIF(Sheet2!$C$5:$C$20,"closed")-1))<=COUNTIF(Sheet3!$C$5:$C$20,"closed"),INDEX(Sheet3!A$5:A$20,SMALL(IF(Sheet3!$C$5:$C$20="closed",ROW(Sheet3!$C$5:$C$20)-ROW($A$5)+1),ROWS($A$1:INDEX($A$1:$A$100,ROW()-COUNTIF(Sheet1!$C$5:$C$20,"closed")-COUNTIF(Sheet2!$C$5:$C$20,"closed")-1)))),"")))

+ 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