index Match with drop down

dsami0122

New Member
Joined
Mar 31, 2016
Messages
40
Office Version
  1. 365
Platform
  1. Windows
I have a file I am using a drop down list for a classification. What I want to be able to do is dependant on what is selected from the drop down it populates from a list of data. So if I select Admin it will return all the names of the admins from the data file.
 

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.
If you have Excel 2010 or later try the formula in D3 and drag down the column as needed.
If you have Excel 365 then the formula in F3.
Change data to match your data.

Book2
ABCDEF
1NameListAdmin
2Name1Admin
3Name2Cust. ServiceName1Name1
4Name3AdminName3Name3
5Name4SalesName7Name7
6Name5Mgr 
7Name6Mgr 
8Name7Admin 
9Name8Sales
Sheet1
Cell Formulas
RangeFormula
F3:F5F3=FILTER($A$2:$A$9,$B$2:$B$9=$E$1,"")
D3:D8D3=IFERROR(INDEX($A$2:$A$9,AGGREGATE(15,6,(ROW($A$2:$A$9)-ROW($A$2)+1)/($B$2:$B$9=$E$1),ROWS($E$3:E3))),"")
Dynamic array formulas.
 
Upvote 0
You're welcome. Thanks for the feedback. You may want to add the version of Excel you are using to your account info.
 
Upvote 0
One question Im using this formula
D3:D8D3=IFERROR(INDEX($A$2:$A$9,AGGREGATE(15,6,(ROW($A$2:$A$9)-ROW($A$2)+1)/($B$2:$B$9=$E$1),ROWS($E$3:E3))),"")

What does this do ROWS($E$3:E3))),"") at the end I want to make sure I am grabbing the right data
 
Upvote 0
The AGGREGATE function use the SMALL function to find each of the rows that match the data from your drop down. The ROWS($E$3:E3) returns 1,2,3 etc. as the formula is dragged down. So, the formula finds the 1st match then second match etc. to return the multiple names.
In the example above
(ROW($A$2:$A$9)-ROW($A$2)+1)/($B$2:$B$9=$E$1)
returns
{1;#DIV/0!;3;#DIV/0!;#DIV/0!;#DIV/0!;7;#DIV/0!} - so rows 1,3 and 7 match the rows with Admin.

The formula then returns rows 1,3 and 7 to the INDEX function.
 
Upvote 0

Forum statistics

Threads
1,213,550
Messages
6,114,265
Members
448,558
Latest member
aivin

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