Dynamic dropdowns are a handy way to get your users to make choices based on what they’ve previously chosen, while steering them away from making invalid choices. Today we’re going to look at one that easily handles multiple levels, and we’ll take a look at what could go wrong. Let’s see one in action, shall we?
Right, what’s on the (dropdown) menu?

*BING!*

Cool…check it out…as you can see from the above, the user gets prompted with “Choose…” whenever a subsequent choice must be made.
Ok, what kind of fruit should I have? Hmmm, let me see….eeny, meeny, miny, STRAWBERRIES!!!…MO!

Ok, so what delights does Sub Category 2 have in store for me?

Earliglow? Never heard of it. Sounds delicious…I’ll have those, please.
There, all done. Pretty nifty eh…users only get to see valid choices depending on what they chose last. So users simply can’t screw up! Or can they?
[Evil user, determined to prove me wrong]: Wait a minute…I just remembered that mother expects me to eat my vegetables first, before I move on to dessert. So I better change that initial selection:
*BING!*

What the…Strawberries are vegetables???
Damn…changing upstream dropdowns later on means those downstream choices can be flat out wrong! So how can we make this bulletproof?
Macros to the rescue
Yep, we’ll use some code to clear out any ‘downstream’ choices if anything ‘upstream’ changes. Let’s go back to that original strawberry fest:

Now watch what happens when our user subsequently decides they better vege out first:
Ahh…look at that: the code realized that all those downstream choices are no longer valid. So it deleted them, and prompted the user to choose again. There. Now that IS bulletproof.
So let’s see…hmmm…for an appetizer, I’ll have baby carrots:

And I already decided on Strawberries for pudding…

But what about my main course. Ah, yes, of course…

MEAT! Yummy. BURP!
What’s the recipe?
My approach draws on Roger Govier’s excellent sample file on the Contextures website. Be sure to check out that link to see Roger’s in-depth discussion of the formula magic behind this puppy…It’s genius.
In my Dynamic-Dependent-dropdowns-20140214, you’ll see that all the different categories used by the dropdowns are hosted in an Excel Table, that has the initial categories down the left hand side, and subsequent categories across the top:

So how do these categories get used by the data validation dropdowns? Roger’s approach uses two dynamic named ranges to feed the data validation lists, one called MainList and one called SubList:

Here’s the MainList formula:
=INDEX(Table1[[Choose…]],1):INDEX(Table1[[Choose…]],COUNTA(Table1[[Choose…]]))
…and here’s the SubList formula:
=IF(OR(Sheet1!B8="Choose…",Sheet1!B8=""),"",INDEX(Table1,1,MATCH(Sheet1!B8,Table1[#Headers],0)):INDEX(
Table1,COUNTA(INDEX(Table1,,MATCH(Sheet1!B8,Table1[#Headers],0))),MATCH(Sheet1!B8,Table1[#Headers],0)))
The SubList formula has a relative reference in it: whatever cell you use it in, it retrieves the value of the cell to the immediate left, and then it scans the column headers of our validations table (Table1) looking for the heading that matches that value. Once it’s found it, it simply uses the items listed underneath that heading.
Because this formula is relative, before you enter it into the Name Manager, you will need to first select cell C8, because the above relative formula refers to B8 – the cell to the left. (Note that it doesn’t matter what is in C8 or where your actual dropdown are…rather it’s just that the above formula happens to refer to B8, and because we want our formula to always reference the cell on the immediate left, then we’ve got to select the cell to the immediate right before we enter this relative formula into the Name Manager.
Also note that my version of Roger’s approach uses Excel Tables and the associated Structured References that Table functionality allows. My table is called Table1. Your validation lists MUST be held within an Excel Table (which requires Excel 2007 or greater) and you MUST change the Table1 references in the above formula to match the name of your table.
Excel Tables – known as ListObjects to VBA developers – were introduced in Excel 2007, and are a very powerful and simple way to store things like lists, chart data, and PivotTable data…especially if you might need to add more data to your spreadsheet at a later date, and want to avoid having to repoint all your formulas to include the additional data. If you’re not familiar with Excel Tables – or you don’t know what that Table1[#Headers] guff above means – then I strongly suggest you check out Chandoo’s Introduction to Structural References and this great video he did with MrExcel.
The way these two formulas work is very clever. That MainList named range only gets used by dropdowns in that very first ‘Main Category’ column:

…and all other ‘downstream’ dropdowns – no matter what level they are – are fed by the SubList named range:

The beauty of Roger’s approach is that it can handle any number of cascading levels, provided all the category names are unique. All you need to do is simply add the new subcategories to the right hand side of our validations table (Table1).
Let’s look at an example. If you look at the below screenshot, you’ll see that users can choose from a number of different kinds of meat:

Let’s add a further level that would give meat eaters some further choices relating to how their meat is prepared.
To set this up, all we need to do is take the individual items from that ‘Meat’ column and add each one as a new column header:

Then we simply list the new options for each type of meat below the relevant header:

Now here’s the magic: as soon as we add another column to our input table and set it up with data validation – which I did simply by clicking on the bottom right corner of the cell with the word ‘Human’ and dragging it across – then Excel picks up on the fact that there’s a sub-subcategory, and serves it up to us. *BING!* Order up!

Add code, and stir-fry for 10 milliseconds
As mentioned earlier, in addition to Roger’s great method, I’ve written some code that clears out any downstream entries in the event that an upstream entry is changed. It’s in the sample workbook already, all set to go. But here’s the actual code, for you VBA nerds. (Special thanks to Gabor Madacs for some enhancement suggestions)
Option Explicit
Const CHOOSE = "Choose…"
Private Sub Worksheet_Change(ByVal Target As Range)
On Error GoTo ErrorHandler
Dim targetCell As Range
Dim nextCell As Range
Dim oldCalc As Excel.XlCalculation
If Not Intersect(Target, [DataEntryTable]) Is Nothing Then
If [Radio_Choice] = 1 Then
With Application
.EnableEvents = False
.ScreenUpdating = False
oldCalc = .Calculation
.Calculation = xlCalculationManual
End With
For Each targetCell In Target
'Clear any cells that use 'SubList' to the right of targetCell in the current table.
If targetCell.Column < (targetCell.ListObject.ListColumns.Count + targetCell.ListObject.Range.Column - 1) Then 'there are table cells to the right
For Each nextCell In targetCell.Offset(, 1).Resize(, targetCell.ListObject.ListColumns.Count + targetCell.ListObject.Range.Column - targetCell.Column - 1)
If HasValidationFormula(nextCell) Then
If nextCell.Validation.Formula1 = "=SubList" Then nextCell.Value = ""
End If
Next nextCell
End If
'Perform different action depeding on whether we're dealing with a 'MainList' dropdown
' or a 'SubList' dropdown
If HasValidationFormula(targetCell) Then
Select Case targetCell.Validation.Formula1
Case "=MainList"
If targetCell.Value = "" Then
targetCell.Value = CHOOSE
ElseIf targetCell.Value = CHOOSE Then
'Do nothing.
Else
targetCell.Offset(, 1).Value = CHOOSE
End If
Case "=SubList"
If targetCell.Value = "" Then
targetCell.Value = CHOOSE
ElseIf targetCell.Offset(, -1).Value = CHOOSE Then
targetCell.Value = ""
ElseIf targetCell.Value = CHOOSE Then
'Do nothing
Else
Set nextCell = targetCell.Offset(, 1)
If HasValidationFormula(nextCell) Then
If nextCell.Validation.Formula1 = "=SubList" Then nextCell.Value = CHOOSE
End If
End If
End Select
End If
Next targetCell
With Application
.EnableEvents = True
.ScreenUpdating = True
.Calculation = oldCalc
End With
End If
End If
Exit Sub
ErrorHandler:
With Application
.EnableEvents = True
.ScreenUpdating = True
If oldCalc <> 0 Then .Calculation = oldCalc
End With
MsgBox Err.Description, vbCritical, Name & ".Worksheet_Change()"
End Sub
Private Function HasValidationFormula(cell As Range) As Boolean
On Error GoTo ValidationNotExistsError
If cell.Validation.Formula1 <> "" Then
HasValidationFormula = True
Else
HasValidationFormula = False
End If
Exit Function
ValidationNotExistsError:
HasValidationFormula = False
End Function
Hungry for more?
Here’s some related Posts at Chandoo.org:
Download the file
To see how this is done, download this file and enable macros:
Dynamic-Dependent-dropdowns-20140214
About the Author.
Jeff Weir – a local of Galactic North up there in Windy Wellington, New Zealand – is more volatile than INDIRECT and more random than RAND. In fact, his state of mind can be pretty much summed up by this:
=NOT(EVEN(PROPER(OR(RIGHT(TODAY())))))
That’s right, pure #VALUE!
Find out more at http:www.heavydutydecisions.co.nz
















40 Responses to “Looking up when the data won’t co-operate (case study)”
Nice Trick.. Clever use of cell references
Here is a formula I tried to create:
=SUMPRODUCT(((NOT(ISERROR(SEARCH(L5,B4:H14))))*1),(B5:H15))
It takes care of Caveat #1 (can handle text), but Caveat #2 remains.
In situations like this, I will often use VBA to restructure the data (2 columns: dates and values) on to a new worksheet. I can then use this 'clean' source for data analysis (formula or pivot table).
=SUMPRODUCT(((NOT(ISERROR(SEARCH(L5,B4:H14))))*1),(B5:H15)) and complex formulae in general are all very well but when you come back to them in a few weeks / months time, it is not at all easy to see what they do and what the limitations are.
Hi Chandoo,
I had used this type of cell ref. various times while calculating average.
But for the situation here try below formula . Note this is an array formula and must be confirmed with Ctrl+Shift+Enter.
=SMALL(IF(MMULT((L5=B4:H14)*IF(ISNUMBER(B5:H15),B5:H15),{1;1;1;1;1;1;1}),MMULT((L5=B4:H14)*IF(ISNUMBER(B5:H15),B5:H15),{1;1;1;1;1;1;1})),1)
Regards,
Hi, I think Using SEARCH in here will create a problem say there is a text like SUN and another text SUNLIGHT both result will be added by SUMPRODUCT.
Regards,
Array option.
=SUM(IF(MOD(ROW(B4:B14),2)=MOD(ROW(B4),2),IF(B4:H14=L5,B5:H15)))
Regards
@Elias,
Nice approach.
Although not requested - the formula I suggested closes all possibilities.
Criteria: _____ Value to retrieve:
Date__________ Numeric
Date__________Textual
Textual________Numeric
Textual________Textual
While your formula copes with only the 3 first combinations.
Michael (Micky) Avidan
“Microsoft® Answer” – Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
@Michael,
Sorry but I don’t understand your point. I believe the challenge was to return the summary of a given date. What is your really volatile formula doing that mine is not?
Regards
@Elias,
I didn't say that the challenge differs from what you just mentioned/aimed to nor that your formula doesn't provide the requested result.
Please read my previous comment again and focus on the last combination (TEXT / TEXT).
I, myself, always try to provide a global Formula that is capable to handle all sorts of data.
Michael (Micky) Avidan
“Microsoft® Answer” – Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
@Michael,
I see your point, but you are missing the below points if you are trying to cover all sorts of data.
What happened if the lookup value does not exist?
Do you want the first, second, summary, concatenation of the values if the look value is repeated?
See they are too many possibilities to be cover with just one formula.
Regards
1) The range: B4:H15 was named: RNG.
2) The following Array Formula was "retrieved from my sleeve" and I hope it can be shorten.
3) The formula seems to take care of BOTH(!) caveats.
-------------------------------------------------------------------------------
=OFFSET(INDIRECT(ADDRESS(SMALL(IF(RNG=L5,ROW(RNG),""),1),MOD(SMALL(IF(RNG=L5,(ROW(RNG))+COLUMN(RNG)/10),1),1)*10)),1,)
-------------------------------------------------------------------------------
Michael (Micky) Avidan
“Microsoft® Answer” – Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
@Michael,
Check what happened with your result if you type 41927 in D5.
Regards
Correct. Didn't predict that.
Will find time to work something out.
Michael (Micky) Avidan
“Microsoft® Answer” – Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
@Elias,
Let's hope the following Array Formula "closes all open doors".
Again - it has nothing to do with your formula which works fine as long as the 3 first mentioned combinations are concerned.
-------------------------------------------------------------------------------
=INDEX(RNG,LARGE(IF(RNG=L5,MOD(ROW(RNG)-1,2)*(ROW(RNG)),""),1)-2,(MOD(SMALL(IF(RNG=L5,(ROW(RNG))+COLUMN(RNG)/10),1),1)*10)-1)
-------------------------------------------------------------------------------
Michael (Micky) Avidan
“Microsoft® Answer” – Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
Ok, if you insist. The following will cover all the scenarios you listed. However, I’ll never recommend/use such of formula.
Defined names:
rDat = $B$4:$H$15
rRow =ROW(rDat)-MIN(ROW(rDat))+1
rCol =COLUMN(rDat)-MIN(COLUMN(rDat))+1
rInc =MOD(rRow,2)=MOD(MIN(rRow),2)
L6=INDEX(rDat,MAX(IF(rInc,IF(rDat=L5,rRow)))+1,MAX(IF(rInc,IF(rDat=L5,rCol))))
Array Enter
Regards
@Michael,
unfortunately, your array formula still seems to return wrong results (eg 3-Nov).
If data are organized like in the example, ie. looks like a calendar, the INDEX formula seems quite simple:
=INDEX($B$4:$H$15,ROUNDDOWN((L5-B4)/7,0)*2+2,MOD((L5-B4),7)+1)
Yours is effectively the same as what I just came up with, and I believe this is the optimal answer to this particular problem.
My solution, before I saw yours:
=OFFSET(B5,QUOTIENT(L5-B4,7)*2,MOD(L5-B4,7))
OFFSET will work for an arbitrary list size, but INDEX might be easier to read.
QUOTIENT does the round and division in a single step.
If there's an improvement over Elias's solution then I for one can't see it.
Perhaps a non-CSE version which would also mean that only two references (B4:H14 and B5:H15), as opposed to three (B4, B4:B14 and and B5:H15), would require manually amending should the data range change, i.e.:
=SUMPRODUCT((ISEVEN(ROW(B4:H14)-MIN(ROW(B4:H14)))*(B4:H14=L5)*B5:H15))
I suppose we could make it a single, uniform range reference:
=SUMPRODUCT((ISEVEN(ROW(B4:H14)-MIN(ROW(B4:H14)))*(B4:H14=L5)*OFFSET(B4:H14,1,,,)))
which might be more appropriate should we e.g. wish to use a Defined Name for our range, i.e.:
=SUMPRODUCT((ISEVEN(ROW(Rng)-MIN(ROW(Rng)))*(Rng=L5)*OFFSET(Rng,1,,,)))
though whether that compensates for the extra, volatile function call is something to be debated.
Regards
I have tried something and then my Excel workbooks got shut down. Maybe that was too much?
Anyway here is what I've tried:
=SUMPRODUCT(INDEX(B5:H15;IF(ISEVEN(ROW(B5:H15));ROW(B5:B15)-ROW(B5)+1);{1\2\3\4\5\6\7}))
Guess that was wrong? Would this approach work anyway?
Looking forward to learn something from you Excel Experts.
Sorry, I haven't took notice of XOR LX's answer. I guess that's kind of what I was looking for.
@Michael Avidan
As it stands that is not a very rigorous construction.
You say "I, myself, always try to provide a global Formula that is capable to handle all sorts of data", which is a wonderful philosophy, but isn't it at least as important that we ensure that our formulas are independent of the row and column references of the data range in question, so that, should that range change, we do not have to re-work our solution?
What happens with your formula, for example, if RNG is instead re-located one row down, from B4:H15 to B5:H16?
When a formula is reliant upon the addition/subtraction of certain constants within the formula, which themselves are necessarily dependent upon the specific rows/columns in which the data lies at any given time (e.g. the -1 in MOD(ROW(RNG)-1,2)), then that formula is not a very flexible one.
Hence the reason for my choice of a slightly longer construction:
ROW(B4:H14)-MIN(ROW(B4:H14))
which ensures that this part of the calculation is not dependent upon the precise location of the data range within the worksheet, and so will give correct answers even if that range is re-located.
Regards
{=OFFSET(B4,MAX((B4:H15=L5)*ISODD(ROW(1:12))*ROW(1:12)),MAX((B4:H15=L5)*ISODD(ROW(1:12))*COLUMN(A:G))-1)}
Non-array formula:
=INDEX(B4:H15,SUMPRODUCT((B4:H15=L5)*(ROW(B4:H15)-ROW(B4)+1)*ISODD(ROW(B4:H15)-ROW(B4)+1))+1,SUMPRODUCT((B4:H15=L5)*(COLUMN(B4:H15)-COLUMN(B4)+1)*ISODD(ROW(B4:H15)-ROW(B4)+1)))
Using one range (B4:H15), one reference (B4), one lookup value (L5) and no INDIRECT or OFFSET.
My trial with defined names:
DateRange
=$B$4:$H$4,$B$6:$H$6,$B$8:$H$8,$B$10:$H$10,$B$12:$H$12,$B$14:$H$14
Position
=RANK('lookup problem'!$L$5,DateRange,1)
L6
=OFFSET(B4,ROUNDUP(Position/7,0)*2- 1,IF(MOD(Position,7)=0,6,MOD(Position,7)-1))
I'd probably just run with something like:
=SUMPRODUCT((B4:H14=L5)*(MOD(ROW(B4:H14),2)=MOD(ROW(B4),2))*B5:H15)
...which is basically the same as Elias' but without the IFs
The opposite of elegant but it works...
=INDEX(B4:H15,IFERROR(MATCH(L5,B4:B14,0),0)+IFERROR(MATCH(L5,C4:C14,0),0)+IFERROR(MATCH(L5,D4:D14,0),0)+IFERROR(MATCH(L5,E4:E14,0),0)+IFERROR(MATCH(L5,F4:F14,0),0)+IFERROR(MATCH(L5,G4:G14,0),0)+IFERROR(MATCH(L5,H4:H14,0),0)+1,IFERROR(MATCH(L5,B4:H4,0),0)+IFERROR(MATCH(L5,B6:H6,0),0)+IFERROR(MATCH(L5,B8:H8,0),0)+IFERROR(MATCH(L5,B10:H10,0),0)+IFERROR(MATCH(L5,B12:H12,0),0)+IFERROR(MATCH(L5,B14:H14,0),0))
=INDEX(B4:H15,
IFERROR(MATCH(L5,B4:B14,0),0)+
IFERROR(MATCH(L5,C4:C14,0),0)+
IFERROR(MATCH(L5,D4:D14,0),0)+
IFERROR(MATCH(L5,E4:E14,0),0)+
IFERROR(MATCH(L5,F4:F14,0),0)+
IFERROR(MATCH(L5,G4:G14,0),0)+
IFERROR(MATCH(L5,H4:H14,0),0)+1,
IFERROR(MATCH(L5,B4:H4,0),0)+
IFERROR(MATCH(L5,B6:H6,0),0)+
IFERROR(MATCH(L5,B8:H8,0),0)+
IFERROR(MATCH(L5,B10:H10,0),0)+
IFERROR(MATCH(L5,B12:H12,0),0)+
IFERROR(MATCH(L5,B14:H14,0),0))
Named Range
rownum = SUMPRODUCT(('lookup problem'!$B$4:$H$14='lookup problem'!$L$5)*ROW('lookup problem'!$B$4:$H$14)*ISEVEN(ROW('lookup problem'!$B$4:$H$14)))
Formula
=OFFSET($A$1,rownum,MATCH(L5,INDIRECT("$B"&rownum&":$H"&rownum),0))
How about SUM(IF(B4:H14=L5,B5:H15)) with array..it should work
Sorry, Chandoo, you can't find stuff this way in every possible scenario.
What if 2014-10-01 sales would equal 41.927 ? Which is serial number for 2014-10-15 ? SUMIF would fail to retrive correct answer. And your example data suggest that such number is possible in your table.
It's better not to search through dates and numbers at the same time.
If I'd solve a problem like this, it'd reformat table first so I get one column with dates and the other with numbers.
In this case, formula to form date column would be:
=INDIRECT(ADDRESS((INT((ROW()-4)/COUNT($B$4:$H$4))+1)*2+2;MOD(ROW()-4;COUNT($B$4:$H$4))+2;4;1))
and numbers would be the same formula with sight adjustment (+3 instead of +2 at the end of first argument):
=INDIRECT(ADDRESS((INT((ROW()-4)/COUNT($B$4:$H$4))+1)*2+3;MOD(ROW()-4;COUNT($B$4:$H$4))+2;4;1))
And now you got two columns that you can safely use for searching!
Oops, sorry, you actually mentioned that it doesn't work if number=date! I missed that part 🙁
={OFFSET(A1,SUM((B4:H14=L5)*ROW((B4:H14))),SUM((B4:H14=L5)*COLUMN((B4:H14)))-1)}
Works for all data... the solution I got for indirect looks little lengthy
I want to count last 20 records of a person, whose marks is greater than 2 and grade "manager". ....
Assume A1 has got names (James, John...etc...)
A2 "Manager"
A3 "2"
Someone please reply
I want to count last 20 records of a person, whose marks is greater than "2" and grade "Manager"
Assume A1 "geroge" A2 "Michael" A3 "George" etc...name can found anywhere in the rows
B1 "Manager" B2" clerk"
C1 "2" C2, "4"
please reply
Simplest I can come up with. No limitations for either 1 or 2. This does assume dates are an ordered list with 7 per row, and 2 rows per set. Assuming this is always true this will work for an arbitrary long list of dates.
=OFFSET(B5,QUOTIENT($L$5-$B$4,7)*2,MOD($L$5-$B$4,7))
@Marc,
Nice approach - however, as there are no "Negative Dates" - try:
=OFFSET(B5,INT(L5-B4)/7)*2,MOD(L5-B4,7))
——————————————————————————-
Michael (Micky) Avidan
“Microsoft® Answer” – Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
=OFFSET(B4,ROUNDUP((L5-41911+1)/7,0)*2-1,MOD(L5-41911,7))
B4 has been used as reference cell for OFFSET().
FOR ROWS:
ROUNDUP(....,0) gives the integer value of a division. In case of presence of a remainder, ROUNDUP will add 1 to the Quotient.
As opposed to ROUNDUP(), the INT() or QUOTIENT() functions eliminate the remainder.
41911 = 01-Sept-2014, the first date in the data.
*2 has been used because there are 2 columns per set of data.
/7 has been used because there are 7 columns per set of data.
For columns
MOD(L5-41911,7))
Vijaykumar Shetye,
Panaji, Goa, India
This is how i did it
{=INDEX(B4:H15, MAX((L5=B4:H15)*ROW(B4:H15))-2, MAX((L5=B4:H15)*COLUMN(B4:H15))-1 )}
Here's my solution:
=INDEX(B4:H15,MATCH(1,MMULT(--(B4:H15=L5),TRANSPOSE(COLUMN(B4:H15)^0)),0)+1,MATCH(1,MMULT(TRANSPOSE(--(B4:H15=L5)),ROW(B4:H15)^0),0))
Sorry, forgot to mention Ctrl Shift Enter is needed.