ComboBox List from Range that selects a range until last row

RawlinsCross

Active Member
Joined
Sep 9, 2016
Messages
291
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
 

Some videos you may like

Excel Facts

When they said...
When they said you are going to "Excel at life", they meant you "will be doing Excel your whole life".

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
42,835
Office Version
365
Platform
Windows
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---"
 

RawlinsCross

Active Member
Joined
Sep 9, 2016
Messages
291
Good day, tried that code and I'm getting a "Run-time error '1004' Application-defined or object-defined error"
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
42,835
Office Version
365
Platform
Windows
Which line of code returned the error?
 

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,641
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
 

RawlinsCross

Active Member
Joined
Sep 9, 2016
Messages
291
@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.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
42,835
Office Version
365
Platform
Windows
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:

RawlinsCross

Active Member
Joined
Sep 9, 2016
Messages
291
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)
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
42,835
Office Version
365
Platform
Windows
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
 

RawlinsCross

Active Member
Joined
Sep 9, 2016
Messages
291
Right, that clears up some confusion - I was thinking 'wouldn't it be xldown?' Anyhow, good lesson here. Cheers!
 

Watch MrExcel Video

Forum statistics

Threads
1,102,662
Messages
5,488,166
Members
407,628
Latest member
Faceless Judge

This Week's Hot Topics

  • Timer in VBA - Stop, Start, Pause and Reset
    [CODE=vba][/CODE] Option Explicit Dim CmdStop As Boolean Dim Paused As Boolean Dim Start Dim TimerValue As Date Dim pausedTime As Date Sub...
  • how to updates multiple rows in muliselect listbox
    Hello everyone. I need help with below code. code is only chaning 1st row in mulitiselect list box. i know issue with code...
  • Delete Row from Table
    I am trying to delete a row from a table using VBA using a named range to find what I need to delete. My Range is finding the right cell. In the...
  • Assigning to a variable
    I have a for each block where I want to assign the value in column 5 of the found row to the variable Serv. [CODE=vba] For Each ws In...
  • Way to verify information
    Hi All, I don't know what to call this formula, and therefore can't search. I have a spreadsheet with information I want to reference...
  • Active Cell Address – Inactive Sheet
    How to use VBA to get the cell address of the active cell in an inactive worksheet and then place that cell address in a location on the current...
Top