SOLVED

How can i create 3 dependent drop down list with the 3rd drop down depending on 1st and 2nd list?

Copper Contributor

Here is my list of data. For Dropdown3, I will want the dropdown to be dependent on BOTH Dropdown1 and Dropdown2. Kindly note that some of the values within Order Information/Shipping Information under Proforma Invoice/Draft Shipping docs/Final Shipping docs can be the same and it can be different too . As such I will need the 3rd dropdown list to be dependent on BOTH Dropdown 1 and Dropdown2

Dropdown1Dropdown2Dropdown3
Proforma InvoiceOrder informationCustomer requirement/basic information 
Proforma InvoiceOrder informationPayment terms
Proforma InvoiceOrder informationPO number / Material information 
Proforma InvoiceOrder informationPrice
Proforma InvoiceOrder informationQuantity
Proforma InvoiceOrder informationVendor information
Proforma InvoiceShipping informationDate discrepancy
Draft shipping docsOrder informationCustomer requirement/basic information 
Draft shipping docsOrder informationPayment terms
Draft shipping docsOrder informationPO number / Material information 
Draft shipping docsOrder informationPrice
Draft shipping docsOrder informationQuantity
Draft shipping docsOrder informationVendor information
Draft shipping docsShipping informationCarton information 
Draft shipping docsShipping informationContainer information
Draft shipping docsShipping informationDate discrepancy
Final shipping docsOrder informationCustomer requirement/basic information 
Final shipping docsOrder informationPayment terms
Final shipping docsOrder informationPO number / Material information 
Final shipping docsOrder informationPrice
Final shipping docsOrder informationQuantity
Final shipping docsOrder informationVendor information
Final shipping docsShipping informationCarton information 
Final shipping docsShipping informationContainer information
Final shipping docsShipping informationDate discrepancy
Final shipping docsShipping informationEEM - GAC/VSD accuracy
11 Replies
best response confirmed by allyreckerman (Microsoft)
Solution

@CelineFoong 

See the attached sample workbook.

Select C2 on the Data Entry sheet and click Data Validation on the Data tab of the ribbon to see the formula I used. It is

 

=OFFSET(Lists!$C$1,MATCH(1,(Lists!$A$2:$A$27=A2)*(Lists!$B$2:$B$27=B2),0),0,COUNTIFS(Lists!$A$2:$A$27,A2,Lists!$B$2:$B$27,B2),1)

@Hans Vogelaar 

Appreciate your great help and reply.

I tried at my end using the formula you provided and it works :) 

 

Thank you for the great help , this formula really save alot of time in my work

 

Happy Weekend

 

Celine

@Hans Vogelaar 

 

It looks like it is exactly I have been looking for, but for some reason your Dropdown3 is not working.

Could you please let me know how to fix it?

Thanks a lot!

@ChristianDeinzer 

It looks like data validation has to be refreshed when the workbook is opened.

The attached new version is now a macro-enabled workbook; you may have to allow macros when you open it. I hope this works for you.

@Hans Vogelaar 

Thanks for your help and reply.

I am looking not to use VBA.

Please have a look on the file and see if you can help me.

https://1drv.ms/x/s!AtcEIJC2JdswgzXG9djJJgczPkYX?e=7slZzb

Thanks!!

@ChristianDeinzer 

Unfortunately, we cannot use functions such as SORT or UNIQUE directly in data validation. I don't see a solution without using VBA.

@Hans Vogelaar 

 

How do I make Drop down 2 dependant on the selection of Drop down 1 and Drop down 3 dependant on the selections of both?

 

Thank you in advance 

@Paul_UK86 

If to google "excel dependent drop down list" lot of posts just on first page, e.g. How to make dependent dropdown lists in Excel | Exceljet. You may find more suitable in your case and your Excel version.

@Sergei Baklan thanks! I couldn't get it working using any of the guides online! I think the problem was that my data has multiple words and spaces and is very complicated against basic one word just a few items in a lot of the examples. I found a way to reduce the data down and cross reference using the Define Names - labelling each section of data as the simple name so it matches. 

 

It is a very over complicated way to do it and I am sure any updates to the data will break it - but it works for now. Thanks

@Paul_UK86 

In latest Excel it was improved, it ignores duplicates and blanks automatically. But all this is better to discuss on concrete sample if you have more questions.

1 best response

Accepted Solutions
best response confirmed by allyreckerman (Microsoft)
Solution

@CelineFoong 

See the attached sample workbook.

Select C2 on the Data Entry sheet and click Data Validation on the Data tab of the ribbon to see the formula I used. It is

 

=OFFSET(Lists!$C$1,MATCH(1,(Lists!$A$2:$A$27=A2)*(Lists!$B$2:$B$27=B2),0),0,COUNTIFS(Lists!$A$2:$A$27,A2,Lists!$B$2:$B$27,B2),1)

View solution in original post