+ Reply to Thread
Results 1 to 8 of 8

Single reference with multiple return values

  1. #1
    Registered User
    Join Date
    03-02-2020
    Location
    Mexico
    MS-Off Ver
    MS 365
    Posts
    62

    Single reference with multiple return values

    Experts, I have huge excel data with format same as below (without *).

    fruits **type** location *status
    apple*** a abc1 good
    *******b abc2 good
    *******c abc3 bad
    *******d abc4 bad
    banana a abc6 good
    *******b abc7 good
    *******c abc8 bad
    *******d abc9 bad

    Now, Is there any function that when I find the value of fruits it will give me the type, location, and status?..Please see attached excel file for easy reference..

    Thank you very much..
    Attached Files Attached Files
    Last edited by kingripper; 11-28-2020 at 08:16 AM.

  2. #2
    Forum Guru Bo_Ry's Avatar
    Join Date
    09-10-2018
    Location
    Thailand
    MS-Off Ver
    MS 365
    Posts
    7,211

    Re: Single reference with multiple return values

    Please try at L4

    =IFERROR(INDEX(B$3:B$33,AGGREGATE(15,6,ROW(B$3:B$33)/(LOOKUP(ROW($A$3:$A$33),ROW($A$3:$A$33)/(($A$3:$A$33>"")+($B$3:$B$33="")),$A$3:$A$33)=$K$4),ROWS(L$4:L4))-ROW(B$2)),"")
    Attached Files Attached Files

  3. #3
    Registered User
    Join Date
    03-02-2020
    Location
    Mexico
    MS-Off Ver
    MS 365
    Posts
    62

    Re: Single reference with multiple return values

    Thank you very much Sir, the formula works smoothly..
    However, when I review my data files, there are empty rows (1-4 rows) in between the data that should be returned.. Please see sample (1) attached..

    Many Thanks
    Attached Files Attached Files

  4. #4
    Registered User
    Join Date
    03-02-2020
    Location
    Mexico
    MS-Off Ver
    MS 365
    Posts
    62

    Re: Single reference with multiple return values

    Quote Originally Posted by Bo_Ry View Post
    Please try at L4

    =IFERROR(INDEX(B$3:B$33,AGGREGATE(15,6,ROW(B$3:B$33)/(LOOKUP(ROW($A$3:$A$33),ROW($A$3:$A$33)/(($A$3:$A$33>"")+($B$3:$B$33="")),$A$3:$A$33)=$K$4),ROWS(L$4:L4))-ROW(B$2)),"")

    Sir, how will the formula changed if there are empty rows in between the value to be returned?..thank you so much...

  5. #5
    Forum Guru Bo_Ry's Avatar
    Join Date
    09-10-2018
    Location
    Thailand
    MS-Off Ver
    MS 365
    Posts
    7,211

    Re: Single reference with multiple return values

    Try

    =IFERROR(INDEX(B$3:B$42&"",AGGREGATE(15,6,ROW(B$3:B$42)/(LOOKUP(ROW($A$3:$A$42),ROW($A$3:$A$42)/($A$3:$A$42>""),$A$3:$A$42)=$K$4)/($B$3:$B$42<>""),ROWS(L$4:L4))-ROW(B$2)),"")
    Attached Files Attached Files

  6. #6
    Registered User
    Join Date
    03-02-2020
    Location
    Mexico
    MS-Off Ver
    MS 365
    Posts
    62

    Re: Single reference with multiple return values

    many thanks.. it works.. moreover, when I try to insert another value to be returned (date) it is not recognizing as date but a number. Tried to use format cells on the returned value but not working.. I hope there is a way I can format it as date?..Thanks again
    Last edited by AliGW; 11-28-2020 at 05:26 AM. Reason: PLEASE don't quote unnecessarily!

  7. #7
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,426

    Re: Single reference with multiple return values

    You could try this, and then the date column can be formatted using short date:

    =IFERROR(IFERROR(--INDEX(B$3:B$42&"",AGGREGATE(15,6,ROW(B$3:B$42)/(LOOKUP(ROW($A$3:$A$42),ROW($A$3:$A$42)/($A$3:$A$42>""),$A$3:$A$42)=$K$4)/($B$3:$B$42<>""),ROWS(L$4:L4))-ROW(B$2)),INDEX(B$3:B$42&"",AGGREGATE(15,6,ROW(B$3:B$42)/(LOOKUP(ROW($A$3:$A$42),ROW($A$3:$A$42)/($A$3:$A$42>""),$A$3:$A$42)=$K$4)/($B$3:$B$42<>""),ROWS(L$4:L4))-ROW(B$2))),"")

    Excel 2016 (Windows) 32 bit
    K
    L
    M
    N
    1
    expected result
    2
    3
    find value
    value return
    4
    mango a abc17
    28/11/2020
    5
    b abc18 good
    6
    c abc19 bad
    7
    d abc20 bad
    8
    c abc21 bad
    9
    d abc22 bad
    10
    c abc23 bad
    Sheet: Sheet4
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  8. #8
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,426

    Re: Single reference with multiple return values

    If that takes care of your original question, please select Thread Tools from the menu link above and mark this thread as SOLVED.

    Also, 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.

+ 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. Replies: 1
    Last Post: 05-12-2020, 08:42 AM
  2. Replies: 3
    Last Post: 03-10-2017, 07:56 PM
  3. [SOLVED] Return multiple rows tied to reference in single row
    By ncjackso in forum Excel General
    Replies: 7
    Last Post: 05-14-2015, 11:03 AM
  4. [SOLVED] How to return multiple values to a single cell based on multiple criteria
    By lwallace in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 08-20-2014, 06:32 AM
  5. Replies: 4
    Last Post: 05-12-2014, 07:10 PM
  6. Return any values from partial text in single reference column
    By baba_jb in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 05-30-2013, 01:03 AM
  7. [SOLVED] Return Multiple Values based on a single reference point
    By qfalker in forum Excel Programming / VBA / Macros
    Replies: 8
    Last Post: 06-20-2012, 01:00 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