3 or More Dependent Data Validation, with VBA, easy to set up

Akuini

Well-known Member
Joined
Feb 1, 2016
Messages
5,067
Office Version
  1. 365
Platform
  1. Windows
I want to share a macro to set up multi dependent data validation with vba. Some versions of dependent data validation use formulas to set them up, usually with indirect functions. For 2 or 3 dependent data validation & small data set, it's pretty easy to set it up, but for more than 3, it might be difficult to maintain as it requires lots of tables & lots of helper columns. This version uses vba, you only need 1 table, 1 helper column & 1 named range. The code is a bit complicated but easy to set up and maintain.

This is an example of 3 dependent data validation, with VBA. You can easily set up more than 3 dependent data validations as needed.
Notes:
1. You only need 1 table as data validation source, 1 helper column, 1 named range & 1 simple formula in data validation (ie =xName).
2. The columns where data validation reside may or may not be contiguous.
3. The list in the table may have duplicate, empty & unsorted, but the code will make the list in data validation unique, sorted & non-empty. The list is also dynamic, you can add more data as needed.
4. In the range with data validation, changing or deleting cell contents will delete cells in the next column with data validation.
5. But one caveat of using macro is when macro changes/writes something on sheet it will delete Undo Stack, so at that time you can't use UNDO. In this case it happens every time you put the cursor in a cell with data validation.

The File:

dhee - multiple data validation non adjacent column 2.jpg


The code:
VBA Code:
Option Explicit
'=================================================================================================
'=============== ADJUST THE CODE IN THIS PART: ===================================

'sheet's name where the list for data validation is located. [in the example: sheet "sheet2"]
Private Const sList As String = "sheet2"

'table's name where the list for data validation is located. [in the example: "Table1"]
Private Const sTable As String = "Table1"

'sDT & sDV must be in correct order (in this example 'STATE > CITY > REP).
'You can add number of columns as needed.
'Column number on the table "Table1": 'STATE > CITY > REP
Private Const sDT As String = "1,2,4"

'Column where data validation is located 'STATE > CITY > REP
Private Const sDV As String = "B:B,D:D,G:G"

'the helper column, first cell
Private Const xH As String = "H1"

'the name range as the source of data validation
Private Const xN As String = "xName"
'==================================================================================================
'==================================================================================================
Private xOld As String

Private Sub Worksheet_SelectionChange(ByVal Target As Range)

If Target.Cells.CountLarge > 1 Then Exit Sub
    
If Not Intersect(Target, Range(sDV)) Is Nothing Then
    If isValid(Target) Then     'if activecell has data validation type 3
       If Target.Validation.Formula1 = "=" & xN Then 'its formula is "=xName"
       
       Dim d As Object, va, flag As Boolean, z, q, vb, x
       Dim i As Long, y As Long, w As Long
       
       Application.CutCopyMode = False 'prevent paste to the range with the DV
       xOld = Target.Value
       Set d = CreateObject("scripting.dictionary"):  d.CompareMode = vbTextCompare
       'columns with data validation:  sDV = "B:B,D:D,G:G"
       z = Application.Transpose(Application.Transpose(Split(sDV, ","))) ''create 1D array, variant/string type, Lbound = 1
       
       For i = 1 To UBound(z)
           If Target.Column = Range(z(i)).Column Then w = i: Exit For
       Next
  
       'reset xName to blank
'       ThisWorkbook.Names(xN).RefersTo = Sheets(sList).Range(xH)
       Sheets(sList).Range(xH).Name = xN  'blank cell

       If w > 1 Then 'if previous col with DV is empty then exit sub (with xName is blank)
           If ActiveSheet.Cells(Target.Row, z(w - 1)) = "" Then Exit Sub
       End If

          
           'Column number on the source table: sDT = "1,2,4"
            q = Evaluate("{" & sDT & "}") 'create 1D array, variant/double type, Lbound = 1
      
        'populate data from Table1,
        '"Application.Max(q)" is to limit the column range as needed for populating the list.
        va = Sheets(sList).ListObjects(sTable).DataBodyRange.Resize(, Application.Max(q)).Value
   
       For i = 1 To UBound(va, 1)
           flag = True
           
           If w = 1 Then 'if target is in first data validation column
               d(va(i, q(w))) = Empty
           Else
               'apply criteria from all previous column
               For y = 1 To w - 1
                   If UCase(va(i, q(y))) <> UCase(ActiveSheet.Cells(Target.Row, z(y))) Then flag = False: Exit For
               Next
               'if all criteria are met
               If flag = True Then d(va(i, q(w))) = Empty
           End If
       Next

            If d.Exists("") Then d.Remove ""
            If d.Count > 0 Then
                Dim c As Range
                Application.EnableEvents = False
                Application.ScreenUpdating = False
                    'populate d.keys to helper column & sort it
                    With Sheets(sList)
                        .Columns(.Range(xH).Column).ClearContents
                        Set c = .Range(xH).Resize(d.Count, 1).Offset(1)
                        c = Application.Transpose(Array(d.Keys))
                        c.Sort Key1:=c.Cells(1), Order1:=xlAscending, Header:=xlNo
                    End With
                   'populating range to xName
                    c.Name = xN
        
                Application.ScreenUpdating = True
                Application.EnableEvents = True
            End If
        End If
    End If
End If

End Sub

Private Sub Worksheet_Change(ByVal Target As Range)
If Target.Cells.CountLarge > 1 Then Exit Sub
    
If Not Intersect(Target, Range(sDV)) Is Nothing Then
    
    If isValid(Target) Then     'if activecell has data validation type 3
       If Target.Validation.Formula1 = "=" & xN Then 'if its formula is "=xName"
            If xOld <> Target.Value Then
            
                Dim i As Long, w As Long, z
            
                Application.EnableEvents = False
                'columns with data validation:  "B:B,D:D,G:G"
                z = Application.Transpose(Application.Transpose(Split(sDV, ",")))
                
                For i = 1 To UBound(z)
                    If Target.Column = Range(z(i)).Column Then w = i: Exit For
                Next
                     
                    'if it's not the last column with DV then clear all next column with DV
                    If w < UBound(z) Then
                        For i = w + 1 To UBound(z)
                            ActiveSheet.Cells(Target.Row, Range(z(i)).Column) = ""
                        Next
                    End If
                Application.EnableEvents = True
            End If
        End If
    End If
End If
    
End Sub

Sub toEnableEvent()
Application.EnableEvents = True
End Sub

Function isValid(f As Range) As Boolean
    Dim v
    On Error Resume Next
        v = f.Validation.Type
    On Error GoTo 0
    isValid = v = 3
End Function
 
Here's an example of 3 level dependent data-validation without VBA but using the new function in Excel 365.
The functions used are: SORT, UNIQUE, FILTER, XLOOKUP & TEXTSPLIT
Note: in the formula I'm using "|" as the separator, so if your data actually has "|" in it then change it to different unique character.

Put your data in an actual table as shown in the example.
This data validation is dynamic, you can add more data, but you need to provide extra columns as needed on the right of each helper table. These extra columns are needed if you plan to add new companies & cities. In this example the extra columns are column N:O & X:Y. To add new data, drag down the blue corner at the bottom of the table.

Base on this example you can amend the formula to set up more than 3 level dependent data-validation.

The idea to set up 2 level dependent data-validation came from this tutorial from Mynda Treacy from My Online Training Hub, credit to her:
Easy Dynamic Dependent Data Validation Two Ways
and I amended the formula in order to set up 3 level dependent data-validation, by adding TEXTSPLIT function.

Akuini - 3 level dependent data validation Excel 365.xlsx
ABCDEFGHI
1DATA
2COMPANYCITYCONTACT
3DATA VALIDATIONGEHoustonRolando
4COMPANYCITYCONTACTFordNYStephen
5ABCHoustonRolandGEChicagoHunter
6FordBostonBlazeGEChicagoRoland
7ABCChicagoRodney
8FordBostonMaze
9ABCHoustonRoland
10GEChicagoLochlan
11ABCNYParker
12FordBostonBlaze
13FordBostonAnson
14ABCNYSutton
15
Sheet1
Cells with Data Validation
CellAllowCriteria
A5:A12List=$K$4#
B5:B12List=XLOOKUP($A5,$K$4:$O$4,$K$5:$O$5)#
C5:C12List=XLOOKUP($A5&"|"&$B5,$Q$4:$X$4,$Q$7:$X$7)#


Akuini - 3 level dependent data validation Excel 365.xlsx
KLMNOPQRSTUVWXY
1
2HELPER TABLE, starting at K4
3
4ABCFordGEABC|ChicagoABC|HoustonABC|NYFord|BostonFord|NYGE|ChicagoGE|Houston
5ChicagoBostonChicago  ABCABCABCFordFordGEGE  
6HoustonNYHoustonChicagoHoustonNYBostonNYChicagoHouston
7NYRodneyRolandParkerAnsonStephenHunterRolando  
8SuttonBlazeLochlan
9MazeRoland
10
11
Sheet1
Cell Formulas
RangeFormula
K4:M4K4=TRANSPOSE(SORT(UNIQUE(Table1[COMPANY])))
Q4:W4Q4=TRANSPOSE(SORT(UNIQUE(CONCATENATE(Table1[COMPANY]&"|"&Table1[CITY]),FALSE,FALSE)))
K5:K7,N5:O5,L5:M6K5=SORT(UNIQUE(FILTER(Table1[CITY],Table1[COMPANY]=K4,"")))
X5:Y5,Q5:W6Q5=IFERROR(TEXTSPLIT(Q4,,"|",1),"")
Q7:R7,U7,W7:X7,V7:V9,T7:T9,S7:S8Q7=SORT(UNIQUE(FILTER(Table1[CONTACT],(Table1[COMPANY]=Q5)*(Table1[CITY]=Q6),"")))
Y7Y7=SORT(UNIQUE(FILTER(Table1[COMPANY],(Table1[CITY]=Y5)*(Table1[CONTACT]=Y6),"")))
Dynamic array formulas.


The workbook:
 
  • Like
Reactions: AOB
Upvote 0
@Akuini , I would like to add a 4th dependent drop-down (e.g., Contract #). I tried modifying the formulas but I cannot get it to recognize the new column in Table1.
 
Upvote 0

Excel Facts

Shade all formula cells
To shade all formula cells: Home, Find & Select, Formulas to select all formulas. Then apply a light fill color.
I would like to add a 4th dependent drop-down (e.g., Contract #). I tried modifying the formulas but I cannot get it to recognize the new column in Table1.
Formula in which post are you referring to?
 
Upvote 0
The one that was posted on Oct 26, 2021..."I want to share a macro to set up multi dependent data validation with vba..."
Could you upload a sample workbook (without sensitive data) to a sharing site like dropbox.com or google drive?
And then share the link here.
It's easier if I have a sample workbook to test.
 
Upvote 0
I want to share a macro to set up multi dependent data validation with vba. Some versions of dependent data validation use formulas to set them up, usually with indirect functions. For 2 or 3 dependent data validation & small data set, it's pretty easy to set it up, but for more than 3, it might be difficult to maintain as it requires lots of tables & lots of helper columns. This version uses vba, you only need 1 table, 1 helper column & 1 named range. The code is a bit complicated but easy to set up and maintain.

This is an example of 3 dependent data validation, with VBA. You can easily set up more than 3 dependent data validations as needed.
Notes:
1. You only need 1 table as data validation source, 1 helper column, 1 named range & 1 simple formula in data validation (ie =xName).
2. The columns where data validation reside may or may not be contiguous.
3. The list in the table may have duplicate, empty & unsorted, but the code will make the list in data validation unique, sorted & non-empty. The list is also dynamic, you can add more data as needed.
4. In the range with data validation, changing or deleting cell contents will delete cells in the next column with data validation.
5. But one caveat of using macro is when macro changes/writes something on sheet it will delete Undo Stack, so at that time you can't use UNDO. In this case it happens every time you put the cursor in a cell with data validation.

The File:

View attachment 49864

The code:
VBA Code:
Option Explicit
'=================================================================================================
'=============== ADJUST THE CODE IN THIS PART: ===================================

'sheet's name where the list for data validation is located. [in the example: sheet "sheet2"]
Private Const sList As String = "sheet2"

'table's name where the list for data validation is located. [in the example: "Table1"]
Private Const sTable As String = "Table1"

'sDT & sDV must be in correct order (in this example 'STATE > CITY > REP).
'You can add number of columns as needed.
'Column number on the table "Table1": 'STATE > CITY > REP
Private Const sDT As String = "1,2,4"

'Column where data validation is located 'STATE > CITY > REP
Private Const sDV As String = "B:B,D:D,G:G"

'the helper column, first cell
Private Const xH As String = "H1"

'the name range as the source of data validation
Private Const xN As String = "xName"
'==================================================================================================
'==================================================================================================
Private xOld As String

Private Sub Worksheet_SelectionChange(ByVal Target As Range)

If Target.Cells.CountLarge > 1 Then Exit Sub
   
If Not Intersect(Target, Range(sDV)) Is Nothing Then
    If isValid(Target) Then     'if activecell has data validation type 3
       If Target.Validation.Formula1 = "=" & xN Then 'its formula is "=xName"
      
       Dim d As Object, va, flag As Boolean, z, q, vb, x
       Dim i As Long, y As Long, w As Long
      
       Application.CutCopyMode = False 'prevent paste to the range with the DV
       xOld = Target.Value
       Set d = CreateObject("scripting.dictionary"):  d.CompareMode = vbTextCompare
       'columns with data validation:  sDV = "B:B,D:D,G:G"
       z = Application.Transpose(Application.Transpose(Split(sDV, ","))) ''create 1D array, variant/string type, Lbound = 1
      
       For i = 1 To UBound(z)
           If Target.Column = Range(z(i)).Column Then w = i: Exit For
       Next
 
       'reset xName to blank
'       ThisWorkbook.Names(xN).RefersTo = Sheets(sList).Range(xH)
       Sheets(sList).Range(xH).Name = xN  'blank cell

       If w > 1 Then 'if previous col with DV is empty then exit sub (with xName is blank)
           If ActiveSheet.Cells(Target.Row, z(w - 1)) = "" Then Exit Sub
       End If

         
           'Column number on the source table: sDT = "1,2,4"
            q = Evaluate("{" & sDT & "}") 'create 1D array, variant/double type, Lbound = 1
     
        'populate data from Table1,
        '"Application.Max(q)" is to limit the column range as needed for populating the list.
        va = Sheets(sList).ListObjects(sTable).DataBodyRange.Resize(, Application.Max(q)).Value
  
       For i = 1 To UBound(va, 1)
           flag = True
          
           If w = 1 Then 'if target is in first data validation column
               d(va(i, q(w))) = Empty
           Else
               'apply criteria from all previous column
               For y = 1 To w - 1
                   If UCase(va(i, q(y))) <> UCase(ActiveSheet.Cells(Target.Row, z(y))) Then flag = False: Exit For
               Next
               'if all criteria are met
               If flag = True Then d(va(i, q(w))) = Empty
           End If
       Next

            If d.Exists("") Then d.Remove ""
            If d.Count > 0 Then
                Dim c As Range
                Application.EnableEvents = False
                Application.ScreenUpdating = False
                    'populate d.keys to helper column & sort it
                    With Sheets(sList)
                        .Columns(.Range(xH).Column).ClearContents
                        Set c = .Range(xH).Resize(d.Count, 1).Offset(1)
                        c = Application.Transpose(Array(d.Keys))
                        c.Sort Key1:=c.Cells(1), Order1:=xlAscending, Header:=xlNo
                    End With
                   'populating range to xName
                    c.Name = xN
       
                Application.ScreenUpdating = True
                Application.EnableEvents = True
            End If
        End If
    End If
End If

End Sub

Private Sub Worksheet_Change(ByVal Target As Range)
If Target.Cells.CountLarge > 1 Then Exit Sub
   
If Not Intersect(Target, Range(sDV)) Is Nothing Then
   
    If isValid(Target) Then     'if activecell has data validation type 3
       If Target.Validation.Formula1 = "=" & xN Then 'if its formula is "=xName"
            If xOld <> Target.Value Then
           
                Dim i As Long, w As Long, z
           
                Application.EnableEvents = False
                'columns with data validation:  "B:B,D:D,G:G"
                z = Application.Transpose(Application.Transpose(Split(sDV, ",")))
               
                For i = 1 To UBound(z)
                    If Target.Column = Range(z(i)).Column Then w = i: Exit For
                Next
                    
                    'if it's not the last column with DV then clear all next column with DV
                    If w < UBound(z) Then
                        For i = w + 1 To UBound(z)
                            ActiveSheet.Cells(Target.Row, Range(z(i)).Column) = ""
                        Next
                    End If
                Application.EnableEvents = True
            End If
        End If
    End If
End If
   
End Sub

Sub toEnableEvent()
Application.EnableEvents = True
End Sub

Function isValid(f As Range) As Boolean
    Dim v
    On Error Resume Next
        v = f.Validation.Type
    On Error GoTo 0
    isValid = v = 3
End Function
This was so very helpful! Thank you so much for sharing. Does the helper column need to be on the same sheet? Can I put it on its own sheet and if so how do I reference it in your code?
 
Upvote 0
Hi, @xlsBruh, welcome to MrExcel.
This has nothing to do with your question:
If you're using Excel 365 you may try using the formula method instead of vba to set up multiple dependent data validation.
Please check post #30.

To answer your question:
This was so very helpful! Thank you so much for sharing. Does the helper column need to be on the same sheet? Can I put it on its own sheet and if so how do I reference it in your code?
In the example, the setup is like this:
Sheet1 : where data validation is located
Sheet2 : where the list & helper column are located
You mean you want to place the helper column in another sheet, separate from the list? say sheet3?
 
Upvote 0
Hi, @xlsBruh, welcome to MrExcel.
This has nothing to do with your question:
If you're using Excel 365 you may try using the formula method instead of vba to set up multiple dependent data validation.
Please check post #30.

To answer your question:

In the example, the setup is like this:
Sheet1 : where data validation is located
Sheet2 : where the list & helper column are located
You mean you want to place the helper column in another sheet, separate from the list? say sheet3?
That is correct. I would like the helper column on a third sheet and thank you for your response. I will also check out post #30.
 
Upvote 0
That is correct. I would like the helper column on a third sheet and thank you for your response. I will also check out post #30.
To place the helper column on sheet3:
in "Private Sub Worksheet_SelectionChange" just change the sheet name in this part:
change this:

Rich (BB code):
                    'populate d.keys to helper column & sort it
                    With Sheets(sList)
                        .Columns(.Range(xH).Column).ClearContents


to this:
Rich (BB code):
                    'populate d.keys to helper column & sort it
                    With Sheets("Sheet3")
                        .Columns(.Range(xH).Column).ClearContents

to change the column of the helper column, just amend this part (at the top of the code module):
VBA Code:
'the helper column, first cell
Private Const xH As String = "H1"
 
Upvote 0
Hi Akuini
how change table to normal range ? I want doing in my project with normal range .
my data in sheet1 is A1: E
so the combobox1 should link with column B2:B and combobox2 with column C2:C , and combobox3 with column D2:D .
thanks
 
Upvote 0

Forum statistics

Threads
1,216,272
Messages
6,129,822
Members
449,538
Latest member
cookie2956

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