Return multiple lookup results in different cells

kacker17

New Member
Joined
Jun 5, 2019
Messages
4
Hello,

I'm trying to essentially do something similar to a vlookup, but instead of it just returning a single result, I want to see all results. I would like to have each result show in a different column.

Here's what I have in mind:

Basic Data Set

CategoryItem
FruitBanana
FruitApple
FruitPeach
FruitRaspberry
FruitGrape
FruitOrange
FruitGrapefruit
VeggieCelery
VeggieTomato
VeggieCauliflower
VeggiePotato
VeggieBrussel Sprouts
VeggieBrocoli
DrinkSoda
DrinkWater
DrinkOJ
DrinkMilk

<colgroup><col width="64" span="2" style="width:48pt"> </colgroup><tbody>
</tbody>

I would like it to display the values in this format:

Value 1Value 2Value 3Value 4Value 5Value 6Value 7
FruitBananaApplePeachRaspberryGrapeOrangeGrapefruit
VeggieCeleryTomatoCauliflowerPotatoBrussel SproutsBrocoli
DrinkSodaWaterOJMilk

<colgroup><col span="3"><col><col><col><col span="2"></colgroup><tbody>
</tbody>

I have found a variety of solutions online incorporating everything from array formulas using Index and Small functions and a non array formula using Index and Aggregate. I CANNOT get any of these solutions to work for me. I have been at this for HOURS and am super frustrated.

If anyone has a solution it would REALLY help me out a ton.

Thanks,

Kristie
 

Excel Facts

Return population for a City
If you have a list of cities in A2:A100, use Data, Geography. Then =A2.Population and copy down.
Something like this.


Excel 2013/2016
ABCDEFGHIJK
1DATACATEGORY
2FruitBanana
3FruitApple
4FruitPeach
5FruitRaspberryFruitBananaApplePeachRaspberryGrapeOrangeGrapefruit
6FruitGrapeVeggieCeleryTomatoCauliflowerPotatoBrussel SproutsBrocoli
7FruitOrangeDrinkSodaWaterOJMilk
8FruitGrapefruit
9VeggieCelery
10VeggieTomato
11VeggieCauliflower
12VeggiePotato
13VeggieBrussel Sprouts
14VeggieBrocoli
15DrinkSoda
16DrinkWater
17DrinkOJ
18DrinkMilk
Sheet1
Cell Formulas
RangeFormula
E5{=IFERROR(INDEX($B$2:$B$18,SMALL(IF($D5=$A$2:$A$18,ROW($A$2:$A$18)- MIN(ROW($A$2:$A$18))+1,""),COLUMN()-4)), "")}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Last edited:
Upvote 0
@ Sam(?)
Two comments:
1. MIN(ROW($A$2:$A$18)) can be written more simply as ROW($A$2)
2. Your formula is not robust against column Insertion/deletion. Try inserting or deleting any columns to the left of your formulas.

@ Kristie
Here is my version using AGGREGATE and Sam's layout.
The formula in E5 is copied across as far as you might ever need and down.

Excel Workbook
ABCDEFGHIJKL
1CategoryItem
2FruitBanana
3FruitApple
4FruitPeach
5FruitRaspberryFruitBananaApplePeachRaspberryGrapeOrangeGrapefruit
6FruitGrapeVeggieCeleryTomatoCauliflowerPotatoBrussel SproutsBrocoli
7FruitOrangeDrinkSodaWaterOJMilk
8FruitGrapefruit
9VeggieCelery
10VeggieTomato
11VeggieCauliflower
12VeggiePotato
13VeggieBrussel Sprouts
14VeggieBrocoli
15DrinkSoda
16DrinkWater
17DrinkOJ
18DrinkMilk
19
Lookup All
 
Last edited:
Upvote 0
@ Sam(?)
Two comments:
1. MIN(ROW($A$2:$A$18)) can be written more simply as ROW($A$2)
2. Your formula is not robust against column Insertion/deletion. Try inserting or deleting any columns to the left of your formulas.
Excel tables to the web >> Excel Jeanie HTML 4

Hi Peter,

Thank you for pointing out that, I applied it and found effective.

Code:
{=IFERROR(INDEX($B$2:$B$18,SMALL(IF($D5=$A$2:$A$18,ROW($A$2:$A$18)- (ROW($A$2))+1,""),COLUMN()-4)), "")}
 
Upvote 0
I applied it and found effective.

Code:
{=IFERROR(INDEX($B$2:$B$18,SMALL(IF($D5=$A$2:$A$18,ROW($A$2:$A$18)- (ROW($A$2))+1,""),COLUMN()-4)), "")}
You applied point 1., but the point 2 issue is still present. ;)
 
Upvote 0
You both are BRILLIANT!!!!! This ACTUALLY WORKED for me!!!!!!! Thank you so much for your very quick responses! Absolutely made my day!!!!!!
 
Upvote 0
You both are BRILLIANT!!!!! This ACTUALLY WORKED for me!!!!!!! Thank you so much for your very quick responses! Absolutely made my day!!!!!!
You are very welcome. :)

I'm not sure which suggestion you used but if you used the formula from post 2 or 4, make sure that you note my point 2 in post 3. The robust form of that formula for E5 would be
{=IFERROR(INDEX($B$2:$B$18,SMALL(IF($D5=$A$2:$A$18,ROW($A$2:$A$18)- ROW($A$2)+1,""),COLUMNS($E5:E5))),"")}

If you have AGGREGATE though I would use that simply because you then don't have to remember to do the Ctrl+Shift+Enter any time you edit the formula. :cool:
 
Upvote 0
The robust form of that formula for E5 would be
{=IFERROR(INDEX($B$2:$B$18,SMALL(IF($D5=$A$2:$A$18,ROW($A$2:$A$18)- ROW($A$2)+1,""),COLUMNS($E5:E5))),"")}

I got you. Thanks Peter.

@ Kacker17, Thanks
 
Upvote 0

Forum statistics

Threads
1,214,823
Messages
6,121,779
Members
449,049
Latest member
greyangel23

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top