VBA for data validation range

Michael M

Well-known Member
Joined
Oct 27, 2005
Messages
21,847
Office Version
  1. 365
  2. 2019
  3. 2013
  4. 2007
Platform
  1. Windows
Hi All
I am currently adding a data validation list to my spreadsheet.
I want to have the list range in the validation code to be dynamic as the number of lines in my spreadsheet will constantly change.
My problem is when I try to use the Lrow in my list formula it doesn't seem to work.
My way of doing the list is fairly clunky so I'd be more than happy for someone to advise a better way
Code:
lrow = Worksheets("RBE Data").Cells(Rows.Count, "C").End(xlUp).Row
    Range("C" & lrow + 6) = "Triangular"
    Range("C" & lrow + 7) = "Uniform"
    Range("C" & lrow + 8) = "Pert"
    Range("C" & lrow + 9) = "LogNorm"
    Range("C" & lrow + 10) = "PertAlt"
    Range("C" & lrow + 11) = "LogNormAlt"
    With Range("N7")
        .Validation
        .Delete
        .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
        xlBetween, Formula1:="=C" & lrow + 6":C" & lrow + 11"
        .IgnoreBlank = True
        .InCellDropdown = True
        .ShowInput = True
        .ShowError = True

Regards
Michael M
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
Hi HalfAce
My data list is at the bottom of my spreadsheet....C & lrow + 6
I want to create a validation list in N7 using this list.
But because the sheet never stays the same size, my list formula in the validation needs to address that.
When I put the formula in I keep getting and Expected End of Statement Error

Regards
Michael M
 
Upvote 0
HalfAce
I got it, I got it !!
This works perfectly.
Code:
With Range("N7").Validation
        .Delete
        .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
        xlBetween, Formula1:="=C" & lrow + 6 & ":C" & lrow + 11
        .IgnoreBlank = True
        .InCellDropdown = True
        .ShowInput = True
        .ShowError = True
    End With

Thanks for responding
Regards
Michael M
 
Upvote 0
Hi Michael M,
Try changing your with statement from:
With Range("N7")
.Validation
.Delete

to:
With Range("N7").Validation
.Delete

and make this slight change to your formula:
Formula1:="=C" & lrow + 6 & ":C" & lrow + 11


Hope it helps.

EDIT:
Yep, you got it while I was typing it. Good job. :cool:
 
Upvote 0
Ok, I nearly got it.
What happens when I want to copy the cells down the column.
The formula needs to be Absolute, but at the moment it's Relative

Regards
Michael M
 
Upvote 0
Well, if you want the entire formula to be absolute, you could use this:
Formula1:="=$C$" & lrow + 6 & ":$C$" & lrow + 11

That what you mean?
 
Upvote 0
Ah! Excellent.
That's exactly what I needed

Thank you again for the input.

Regards
Michael M
 
Upvote 0

Forum statistics

Threads
1,215,506
Messages
6,125,194
Members
449,214
Latest member
mr_ordinaryboy

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