+ Reply to Thread
Results 1 to 5 of 5

vlookup that returns first value then subsequent values.

  1. #1
    Forum Contributor
    Join Date
    02-14-2008
    Location
    Manchester, England
    MS-Off Ver
    2007
    Posts
    110

    vlookup that returns first value then subsequent values.

    Hello

    I have a spreadsheet with which I've got a VLOOKUP. I'd like this to work so that that it also returns the first row first but then each subsequent row where the word No appears in column E.

    I've used =IF(E2="No",C2,"") but with this however it leaves big blanks in my data making it untidy. I'd like each row to be populated.

    Can anyone help?

    Thanks

  2. #2
    Forum Guru :) Sixthsense :)'s Avatar
    Join Date
    01-01-2012
    Location
    India>Tamilnadu>Chennai
    MS-Off Ver
    2003 To 2010
    Posts
    12,770

    Re: vlookup that returns first value then subsequent values.

    Attach a sample workbook. Make sure there is just enough data to make it clear what is needed. Include a BEFORE sheet and an AFTER sheet in the workbook if needed to show the process you're trying to complete or automate. Make sure your desired results are demonstrated, mock them up manually if needed. Remember to desensitize the data.

    Click on GO ADVANCED and use the paperclip icon to open the upload window.

    View Pic


    If your problem is solved, then please mark the thread as SOLVED>>Above your first post>>Thread Tools>>
    Mark your thread as Solved


    If the suggestion helps you, then Click *below to Add Reputation

  3. #3
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: vlookup that returns first value then subsequent values.

    1) The formula I'm going to give you cannot be applied to an entire column. I will show a starting range of 15 rows. You can expand all the references to 100 rows or 50 rows, however many you'll think you'll need.

    2) This is an ARRAY formula, so it is entered a little differently than normal formulas. An array formula runs the same formula over and over for each row in the range, which is why you need to limit the number of rows evaluated to a reasonable number. If you reference 100 rows, it's like entering 100 formulas in EACH cell. OK?

    3) In the first cell where you want your list to appear, enter this starting array formula:

    =INDEX($C$1:$C$15, SMALL(IF($E$1:$E$15="No", ROW($A$1:$A$15), ""), ROW(A1)))

    ...confirmed by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. You will know the array is active when you see curly braces { } appear around your formula. If you do not CTRL+SHIFT+ENTER you will get an error or a clearly incorrect answer. Press F2 on that cell and try again.

    4) Now copy that first cell downward until errors appear.... there's your list.

    5) Here's an expanded formula that will not show the errors:
    =IF(ROW(A1)>COUNTIF($E$1:$E$15,"No"), "", INDEX($C$1:$C$15, SMALL(IF($E$1:$E$15="No", ROW($A$1:$A$15), ""), ROW(A1))))

    6) I know your data starts at row2, but leave the "ranges" referenced starting at row1, else we have to add more plumbing to the formula that just makes it harder to read.
    Last edited by JBeaucaire; 01-13-2015 at 06:22 AM.
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

  4. #4
    Forum Expert Ace_XL's Avatar
    Join Date
    06-04-2012
    Location
    UAE
    MS-Off Ver
    2016
    Posts
    6,074

    Re: vlookup that returns first value then subsequent values.

    Non-array solution perhaps..

    =IF(ROWS(A$1:A1)>COUNTIF($E$2:$E$100,"No"),"",INDEX($C$2:$C$100,SMALL(INDEX(($E$2:$E$100="No")*(ROW($E$2:$E$100)-ROW($E$2)+1),),COUNTA($E$2:$E$100)-COUNTIF($E$2:$E$100,"No")+ROWS(A$1:A1))))

    Make sure your range in Col E does not have any blanks though
    Life's a spreadsheet, Excel!
    Say thanks, Click *

  5. #5
    Forum Contributor
    Join Date
    02-14-2008
    Location
    Manchester, England
    MS-Off Ver
    2007
    Posts
    110

    Re: vlookup that returns first value then subsequent values.

    Thanks very much. Your reply works a treat.

+ 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] Sum of values from VLOOKUP returns
    By excel_newser in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 10-07-2014, 02:22 PM
  2. VLOOKUP that returns first value then consequent values
    By Dan27 in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 09-03-2014, 12:44 PM
  3. [SOLVED] Vlookup returns correct values but adds them as 0
    By Comatose in forum Excel Formulas & Functions
    Replies: 13
    Last Post: 04-07-2014, 06:09 AM
  4. VLOOKUP that returns multiple values from a prior column
    By C.Houston in forum Excel General
    Replies: 1
    Last Post: 07-26-2012, 12:44 PM
  5. VLOOKUP returns wrong values
    By surfol in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 05-26-2011, 03:26 PM

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