Use data Validation Dropdown in another sheet

Mmcq16

New Member
Joined
Apr 11, 2013
Messages
9
Hello

I am looking to copy 2 data validation drop down boxes to another sheet. The first box selects from a list of randomly repeated names and the second box selects a value associated with that name. theses lists update automatically whenever you write a new name in excel. here is the cod I am using.

Code:
Option Explicit
 
Private Sub Worksheet_Change(ByVal Target As Range)
    Dim i As Long, LastRow As Long, n As Long
    Dim MyCol As Collection
    Dim SearchString As String, TempList As String
 
    Application.EnableEvents = False
 
    On Error GoTo Whoa
 
    '~~> Find LastRow in Col C
    LastRow = Range("C" & Rows.Count).End(xlUp).Row
 
    If Not Intersect(Target, Columns(1)) Is Nothing Then
        Set MyCol = New Collection
 
        '~~> Get the data from Col C into a collection
        For i = 5 To LastRow
            If Len(Trim(Range("C" & i).Value)) <> 0 Then
                On Error Resume Next
                MyCol.Add CStr(Range("C" & i).Value), CStr(Range("C" & i).Value)
                On Error GoTo 0
            End If
        Next i
 
        '~~> Create a list for the DV List
        For n = 1 To MyCol.Count
            TempList = TempList & "," & MyCol(n)
        Next
 
        TempList = Mid(TempList, 2)
 
        Range("W1").ClearContents: Range("W1").Validation.Delete
 
        '~~> Create the DV List
        If Len(Trim(TempList)) <> 0 Then
            With Range("W1").Validation
                .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
                xlBetween, Formula1:=TempList
                .IgnoreBlank = True
                .InCellDropdown = True
                .InputTitle = ""
                .ErrorTitle = ""
                .InputMessage = ""
                .ErrorMessage = ""
                .ShowInput = True
                .ShowError = True
            End With
        End If
    '~~> Capturing change in cell W1
    ElseIf Not Intersect(Target, Range("W1")) Is Nothing Then
        SearchString = Range("W1").Value
 
        TempList = FindRange(Range("C5:C" & LastRow), SearchString)
 
        Range("Y1").ClearContents: Range("Y1").Validation.Delete
 
        If Len(Trim(TempList)) <> 0 Then
            '~~> Create the DV List
            With Range("Y1").Validation
                .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
                xlBetween, Formula1:=TempList
                .IgnoreBlank = True
                .InCellDropdown = True
                .InputTitle = ""
                .ErrorTitle = ""
                .InputMessage = ""
                .ErrorMessage = ""
                .ShowInput = True
                .ShowError = True
            End With
        End If
    End If
 
LetsContinue:
    Application.EnableEvents = True
    Exit Sub
Whoa:
    MsgBox Err.Description
    Resume LetsContinue
End Sub
 
'~~> Function required to find the list from Col D
Function FindRange(FirstRange As Range, StrSearch As String) As String
    Dim aCell As Range, bCell As Range, oRange As Range
    Dim ExitLoop As Boolean
    Dim strTemp As String
 
    Set aCell = FirstRange.Find(what:=StrSearch, LookIn:=xlValues, _
    lookat:=xlWhole, SearchOrder:=xlByRows, SearchDirection:=xlNext, _
    MatchCase:=False, SearchFormat:=False)
 
    ExitLoop = False
 
    If Not aCell Is Nothing Then
        Set bCell = aCell
        strTemp = strTemp & "," & aCell.Offset(, 1).Value
        Do While ExitLoop = False
            Set aCell = FirstRange.FindNext(After:=aCell)
 
            If Not aCell Is Nothing Then
                If aCell.Address = bCell.Address Then Exit Do
                strTemp = strTemp & "," & aCell.Offset(, 1).Value
            Else
                ExitLoop = True
            End If
        Loop
        FindRange = Mid(strTemp, 2)
    End If
End Function


I would like the dropdown boxes I have in W1 and Y1 linked to appear in another worksheet..

Is this possible?
 

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
You need to use a named range if the data exists on a different sheet then the data validation box.
 
Upvote 0
I assume this is a follow on from your original validation thread , so you might as well have my bit of code !!
Sheet details:-
Sheet1 column "A" (starting row2) has your list of employees (with duplicates)
Sheet1 column "B" has the related Experiments. Sheet1 column "Z" will hold the main Validation List produced from Column "A" and will be named "Sht1" . This column will be updated along with sheet2 validation cell "A1", when the sheet2 Activate event occurs. (see below)
Sheet2 "A1" Is the validation cell for the "Employees" .
Sheet2 "C1" is the validation cell for the "Experiments" Sheet2 Column "AA" will hold the list from Sheet1 Column "B" "Experiments" and will Update on Selection from the Validation cell "A1", along with cell "C1" validation list.
Place the following code in sheet2, sheet module:-
As the main code uses the "Activate" Event the Code will run and Validation cells fill when sheet 2 is reactivated. When you have the code running you could achieve this automatically within "ThisWorksheet" Module with a Workbook _Open" event to Select a different sheet and then select sheet2.
Code:
[COLOR="Navy"]Dim[/COLOR] Dic [COLOR="Navy"]As[/COLOR] Object
Private [COLOR="Navy"]Sub[/COLOR] Worksheet_Activate()
[COLOR="Navy"]Dim[/COLOR] Rng [COLOR="Navy"]As[/COLOR] Range, Dn [COLOR="Navy"]As[/COLOR] Range, n [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Long,[/COLOR] ray
[COLOR="Navy"]With[/COLOR] Sheets("Sheet1")
    [COLOR="Navy"]Set[/COLOR] Rng = .Range(.Range("A2"), .Range("A" & Rows.Count).End(xlUp))
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]Set[/COLOR] Dic = CreateObject("scripting.dictionary")
    Dic.CompareMode = vbTextCompare
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
    [COLOR="Navy"]If[/COLOR] Not Dic.exists(Dn.Value) [COLOR="Navy"]Then[/COLOR]
        Dic.Add Dn.Value, Dn
    [COLOR="Navy"]Else[/COLOR]
        [COLOR="Navy"]Set[/COLOR] Dic.Item(Dn.Value) = Union(Dic.Item(Dn.Value), Dn)
    [COLOR="Navy"]End[/COLOR] If
 [COLOR="Navy"]Next[/COLOR]
[COLOR="Navy"]With[/COLOR] Sheets("Sheet1")
     .Columns("Z:Z").ClearContents
     .Range("Z1").Resize(Dic.Count) = Application.Transpose(Dic.keys)
      [COLOR="Navy"]Set[/COLOR] Rng = Sheets("Sheet1").Range("Z1").Resize(Dic.Count)
     Rng.Name = "sht1"
     
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]With[/COLOR] Sheets("Sheet2")
    .Select
    .Range("A1").Select
    .Range("A1") = Rng(1)
[COLOR="Navy"]With[/COLOR] Selection.Validation
    .Delete
    .Add Type:=xlValidateList, Formula1:="=sht1"
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Private [COLOR="Navy"]Sub[/COLOR] Worksheet_Change(ByVal Target [COLOR="Navy"]As[/COLOR] Range)
[COLOR="Navy"]Dim[/COLOR] R [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] nRng [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] vRng [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] nR [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] c [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer[/COLOR]
[COLOR="Navy"]If[/COLOR] Target.Address(0, 0) = "A1" [COLOR="Navy"]Then[/COLOR]
   [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] R [COLOR="Navy"]In[/COLOR] Dic.Item(CStr(Target))
        [COLOR="Navy"]If[/COLOR] nRng [COLOR="Navy"]Is[/COLOR] Nothing [COLOR="Navy"]Then[/COLOR]
            [COLOR="Navy"]Set[/COLOR] nRng = R.Offset(, 1)
        [COLOR="Navy"]Else[/COLOR]
            [COLOR="Navy"]Set[/COLOR] nRng = Union(nRng, R.Offset(, 1))
        [COLOR="Navy"]End[/COLOR] If
        [COLOR="Navy"]Next[/COLOR] R
Sheets("Sheet2").Columns("AA:AA").ClearContents
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] nR [COLOR="Navy"]In[/COLOR] nRng
    [COLOR="Navy"]With[/COLOR] Sheets("Sheet2")
        c = c + 1
       .Cells(c, "AA") = nR
    [COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]Next[/COLOR] nR
[COLOR="Navy"]Set[/COLOR] vRng = Sheets("Sheet2").Range("AA1").Resize(c)
[COLOR="Navy"]With[/COLOR] Sheets("Sheet2")
    .Range("C1").Select
    .Range("C1") = vRng(1)
[COLOR="Navy"]With[/COLOR] Selection.Validation
    .Delete
    .Add Type:=xlValidateList, Formula1:="=" & vRng.Address & ""
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]End[/COLOR] With
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]If[/COLOR]
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Last edited:
Upvote 0

Forum statistics

Threads
1,203,455
Messages
6,055,541
Members
444,794
Latest member
HSAL

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