Two Different Sets of Drop Downs In The Same Two Columns

barim

Board Regular
Joined
Apr 19, 2006
Messages
176
Hello everybody,

I have this piece of code that is adding drop downs to where is the end of the data. Now, from the first blank data, exactly where the end of data is, I need to continue adding 1000 more drop downs with different set of values.
I have another set of codes below that adds only 1 line and I had to use .Select which I am not happy with.
Is there a way to avoid this .Select and how am I going to loop through and add 1000 more drop downs?

Thanks in advance.

Code:
For i = 2 To LastRow 'loop from Row 2 to Last
     
        With ws.Cells(i, "A").Validation
            .Delete
            .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
            xlBetween, Formula1:="Selection1,Selection2,Selection3,Selection4"
            .IgnoreBlank = True
            .InCellDropdown = True
            .ShowInput = True
            .ShowError = True
        If ws.Cells(i, "A").Value = "" Then
            ws.Cells(i, "A").Value = "No Selection"
            End If
        End With
 Next i
 For i = 2 To LastRow 'loop from Row 2 to Last
        With ws.Cells(i, "B").Validation
            .Delete
            .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
            xlBetween, Formula1:="Selection1,Selection2,Selection3"
            .IgnoreBlank = True
            .InCellDropdown = True
            .ShowInput = True
            .ShowError = True
        If ws.Cells(i, "B").Value = "" Then
            ws.Cells(i, "B").Value = "No Selection"
            End If
        End With
 Next i

Code:
Range("A1").End(xlDown).Offset(1, 0).Select
     
        With Selection.Validation
            .Delete
            .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
            xlBetween, Formula1:="Another1, Another2"
            .IgnoreBlank = True
            .InCellDropdown = True
            .ShowInput = True
            .ShowError = True
        If Selection.Value = "" Then
            Selection.Value = "No Selection"
            End If
        End With

Range("B1").End(xlDown).Offset(1, 0).Select
     
        With Selection.Validation
            .Delete
            .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
            xlBetween, Formula1:="Another3, Another4"
            .IgnoreBlank = True
            .InCellDropdown = True
            .ShowInput = True
            .ShowError = True
        If Selection.Value = "" Then
            Selection.Value = ""
            End If
        End With
 

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes
No need for loops, you can do it like
Code:
   With Ws.Range("A2:A" & Lastrow).Validation
      .Delete
      .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
         xlBetween, Formula1:="Selection1,Selection2,Selection3,Selection4"
      .IgnoreBlank = True
      .InCellDropdown = True
      .ShowInput = True
      .ShowError = True
      .Parent.Value = "No Selection"
   End With
   With Ws.Range("B2:B" & Lastrow).Validation
      .Delete
      .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
         xlBetween, Formula1:="Selection1,Selection2,Selection3"
      .IgnoreBlank = True
      .InCellDropdown = True
      .ShowInput = True
      .ShowError = True
      .Parent.Value = "No Selection"
   End With
   With Ws.Range("A" & Lastrow).Offset(1).Resize(1000).Validation
      .Delete
      .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
         xlBetween, Formula1:="Another1, Another2"
      .IgnoreBlank = True
      .InCellDropdown = True
      .ShowInput = True
      .ShowError = True
      .Parent.Value = "No Selection"
   End With
 
Upvote 0
Fluff, thanks so much for this modification. It works perfectly. Now I know how to use resize function. Thanks again.
 
Upvote 0
You're welcome & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,223,234
Messages
6,170,891
Members
452,366
Latest member
TePunaBloke

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