Run Code Every Other Cell

BrianExcel

Well-known Member
Joined
Apr 21, 2010
Messages
975
I am running the following code to create data validation drop downs.

Code:
Sub DropDownCode()
Dim Choices As String

Choices = "Choice 1, Choice 2, Choice 3"

Sheets("Sheet1").Range("D12").Select

With Selection.Validation
        .Delete
        .Add Type:=xlValidateList, _
        AlertStyle:=xlValidAlertStop, Operator:= _
        xlBetween, Formula1:=Choices
        .IgnoreBlank = True
        .InCellDropdown = True
        .InputTitle = ""
        .ErrorTitle = ""
        .InputMessage = ""
        .ErrorMessage = ""
        .ShowInput = True
        .ShowError = True
    End With
End Sub

Now that this code is working, I need to apply the code to every 4th cell on sheet 1, starting with D12. Then moving to D11, D16, D20, and so on.

Can someone help? Code is appreciated.
 

Excel Facts

Excel Wisdom
Using a mouse in Excel is the work equivalent of wearing a lanyard when you first get to college
Try:

Code:
Public Sub DropDownCode()
Dim i       As Long, _
    LR      As Long, _
    Choices As String
    
With Application
    .ScreenUpdating = False
    .Calculation = xlCalculationManual
    .EnableEvents = False
End With

LR = Range("D" & Rows.Count).End(xlUp).Row
Choices = "Choice 1, Choice 2, Choice 3"
For i = 12 To LR Step 4
    With Range("D" & i).Validation
        .Delete
        .Add Type:=xlValidateList, _
        AlertStyle:=xlValidAlertStop, Operator:= _
        xlBetween, Formula1:=Choices
        .IgnoreBlank = True
        .InCellDropdown = True
        .InputTitle = ""
        .ErrorTitle = ""
        .InputMessage = ""
        .ErrorMessage = ""
        .ShowInput = True
        .ShowError = True
    End With
Next i

With Application
    .ScreenUpdating = True
    .Calculation = xlCalculationAutomatic
    .EnableEvents = True
End With
End Sub
 
Upvote 0
something like this??
Rich (BB code):
Sub DropDownCode()
Dim Choices As String
Choices = "Choice 1, Choice 2, Choice 3"
For i = 12 To Rows.Count Step 4
With Sheets("Sheet1").Cells(i, "D").Validation
        .Delete
        .Add Type:=xlValidateList, _
        AlertStyle:=xlValidAlertStop, Operator:= _
        xlBetween, Formula1:=Choices
        .IgnoreBlank = True
        .InCellDropdown = True
        .InputTitle = ""
        .ErrorTitle = ""
        .InputMessage = ""
        .ErrorMessage = ""
        .ShowInput = True
        .ShowError = True
End With
Next i
End Sub

You might, however, want to adjust it to a certain number of rows or only the used range. The defalust from the rerder can be removed
Rich (BB code):
Sub DropDownCode()
Dim Choices As String
Choices = "Choice 1, Choice 2, Choice 3"
For i = 12 To 1000 Step 4
With Sheets("Sheet1").Cells(i, "D").Validation
        .Delete
        .Add Type:=xlValidateList, _
        AlertStyle:=xlValidAlertStop, Operator:= _
        xlBetween, Formula1:=Choices
        .IgnoreBlank = True
        .InCellDropdown = True
End With
Next i
End Sub

lenze
 
Upvote 0
Sorry, one more question. This obviously has code for specific text in the "Choices" string.

What if I wanted to change that to show a named range? If I change Choices to range instead of string and remove the quotes I get a "Compile Error: Can't find project or library"

Any thoughts?
 
Upvote 0
Untested, but try
Code:
Dim Choices as Range
Set Choices = Range("NamedRange")

lenze
 
Upvote 0
Unfortunately no go. I tried removing brackets, removing quotes, adding both, re-naming the range, etc.

Any other thoughts?
 
Upvote 0

Forum statistics

Threads
1,213,536
Messages
6,114,210
Members
448,554
Latest member
Gleisner2

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