ComboBox List from Range that selects a range until last row

RawlinsCross

Active Member
Joined
Sep 9, 2016
Messages
437
So I have a userform that initializes with the following code. The comboboxes are named CB_AQUEOUS and CB_SOLDIS. I have ranges in Sheet1 that I source the lists from. But if the ranges change, I have to manually update the code. Is there a way I can simply do a *last row* on this? Is the fact that this is in an initialization routine problematic?

Code:
Private Sub UserForm_Initialize()

Me.DTPicker1 = Date - 190
Me.DTPicker2 = Date

'This is the code I want to look at.
CB_AQUEOUS.List = Worksheets("Sheet1").Range("A2:A36").Value
CB_SOLIDS.List = Worksheets("Sheet1").Range("B2:B11").Value
CB_AQUEOUS.Value = "---Please Select---"
CB_SOLIDS.Value = "---Please Select---"


Set mwksWorksheet = wWorksheetPVar
msICP = sSamplePVar
msICP = sICPPVar & sSamplePVar
Call PopulateControlArrays
Call MonthButtonColor
Call SetSummary
End Sub
 

Excel Facts

Return population for a City
If you have a list of cities in A2:A100, use Data, Geography. Then =A2.Population and copy down.
How about
Code:
With Worksheets("Sheet1")
   CB_AQUEOUS.List = .Range("A2", Range("A" & Rows.Count).End(xlUp)).Value
   CB_SOLIDS.List = .Range("B2", .Range("B" & Rows.Count).End(xlUp)).Value
End With
CB_AQUEOUS.Value = "---Please Select---"
CB_SOLIDS.Value = "---Please Select---"
 
Upvote 0
Good day, tried that code and I'm getting a "Run-time error '1004' Application-defined or object-defined error"
 
Upvote 0
Which line of code returned the error?
 
Upvote 0
Perhaps
Code:
Private Sub UserForm_Initialize()

Me.DTPicker1 = Date - 190
Me.DTPicker2 = Date

'This is the code I want to look at.
With Worksheets("Sheet1")
    With Range("A:A")
        CB_AQUEOUS.List = Range((.Cells(2,1), .Cells(Rows.Count,1).End(xlup)).Value
    End With
    With Range("B:B")
        CB_SOLIDS.List = Range((.Cells(2,1), .Cells(Rows.Count,1).End(xlup)).Value
    End With
End With

'...
End Sub
 
Upvote 0
@Fluff
The code is failing at
Code:
CB_AQUEOUS.List = .Range("A2", Range("A" & Rows.Count).End(xlUp)).Value
@Mike
Your code runs but I had to remove the first bracket (code font was red indicating syntax error). But it seems it's grabbing the range not from "Sheet" one but from another sheet where the userform is launched.
 
Upvote 0
Oops, I missed a . before the 2nd Range. It should be
Code:
CB_AQUEOUS.List = .Range("A2", [COLOR=#ff0000].[/COLOR]Range("A" & Rows.Count).End(xlUp)).Value
 
Last edited:
Upvote 0
Yes, that worked... @Mike - curious as to why your code is pulling from another Worksheet.
@Fluff - How does the rows.count know which column it's dealing with (in my sheet column A and B have different counts)
 
Upvote 0
Rows.Count, simply counts the number of available rows in the sheet. So these days that's 1048576, but when using an xls file it's only 65536

Mike made the same mistake as me
Code:
With Worksheets("Sheet1")
    With [COLOR=#ff0000].[/COLOR]Range("A:A")
        CB_AQUEOUS.List = Range(.Cells(2,1), .Cells(Rows.Count,1).End(xlup)).Value
    End With
    With [COLOR=#ff0000].[/COLOR]Range("B:B")
        CB_SOLIDS.List = Range(.Cells(2,1), .Cells(Rows.Count,1).End(xlup)).Value
    End With
End With
 
Upvote 0

Forum statistics

Threads
1,213,549
Messages
6,114,264
Members
448,558
Latest member
aivin

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