Please urgently help with this sample

Amuserad

New Member
Joined
Sep 25, 2020
Messages
3
Office Version
  1. 365
  2. 2013
  3. 2010
Platform
  1. Windows
Hi,

I would like to seek your help. In the attached example, I have two sheets - sheet 1 and sheet 2.

Sheet 2 - contains the types and variety of fruits and vegetables available in my shop
Sheet 1 - is a selection where I can select the type (either fruit or vegetable) and the list is expected to list all the fruits or vegetables available

I tried to use VLOOKUP formula to fetch the values but it is only fetching the last value and displaying in the list. I would like to list all the items.

Can please help me with this to provide me a simple formula to list all the items. Thank you very much.

View attachment 26810

1606445289211.png


1606445314944.png


1606445345778.png

1606445393403.png
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
I think it cannot be done with VLookup because it will capture first encounter only. Here is how it is done

The 1st picture shows the result and the 2nd picture how the formula look like.
The D2 is the drop down selection to choose Fruits or Vegetables

Notice the curl bracket in Formula bar. The formula need to be entered as array formula. So, instead of just press Enter, you need to use Ctrl+Shift+Enter to enter the formula.
 

Attachments

  • Pic1.jpg
    Pic1.jpg
    44.5 KB · Views: 6
  • Pic2.jpg
    Pic2.jpg
    122.8 KB · Views: 6
Upvote 0
With Excel 365 if your version has the FILTER function then:

Sheet1
Book2
AB
1Fruits
2
3List
4Mango
5Banana
6Apple
Sheet1
Cell Formulas
RangeFormula
A4:A6A4=FILTER(Sheet2!$C$2:$C$7,Sheet2!$B$2:$B$7=$B$1,"")
Dynamic array formulas.


Sheet2
Book2
ABC
1
2FruitsMango
3FruitsBanana
4FruitsApple
5VegBrocoli
6VegPotatoes
7VegOnion
Sheet2
 
Upvote 0
How about using data validation list like below????
smp-min (1).gif


SHEET1>>>>
Book1
AB
1ProductsItems
2VegetablesBrocoli
3
Sheet1
Cells with Data Validation
CellAllowCriteria
A2,E2List=Products
B2,F2List=INDIRECT(A2)


SHEET2>>>>
Book1
ABCDE
1FruitsMangoBrocoli
2VegetablesBananaCailiflower
3ApplePotatoes
4OrangeOnion
5Kiwi
Sheet2
 
Upvote 0
@Amuserad
While we do allow Cross-Posting on this site, we do ask that you please mention you are doing so and provide links in each of the threads pointing to the other thread (see rule 13 here along with the explanation: Forum Rules). This way, other members can see what has already been done in regards to a question, and do not waste time working on a question that may already be answered elsewhere.
 
Upvote 0

Forum statistics

Threads
1,214,641
Messages
6,120,693
Members
448,979
Latest member
DET4492

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