Populate multicolumn listbox from array of unknown size

malonemcbain

New Member
Joined
Jul 2, 2013
Messages
3
To preface: I've been able to go from knowing next to nothing about VBA to being fairly competent just by reading these forums. I've never needed to do more than search, until now...

I have a listbox in a userform that I am trying to populate from a range of data in an excel worksheet. To complicate the matter, I added some code to the sub that filters out any rows that have no data in column 1, or are have any fill color in column 1. I do this so that my worksheet can have heading rows that are highlighted, and they won't end up in the listbox.

I used to just use the listbox.additem method to pull from column 1 into the listbox. Now, I'd like to make it a 2 column listbox. So far, I have not been able to sucessfully populate the listbox and I'm not sure why.

My latest effort is below. I can make it through the "if" statement once completely. When vba runs through it the second time, for the next row, I get a "subscript out of range" error. As you can see, right now I haven't even gotten to populating the listbox, i'm just trying to define the array which will eventually populate the listbox.

Any assistance with what I might be doing wrong would be appreciated.

Code:
Private Sub PopulateListbox()
    'sets the range for the ListBoxFac by populating it one by one for each cell in the the facilities tab
    Dim FacRange As Range
    Dim FacCell As Range
    Dim lastrowfac As Long
    Dim facarray()
    Dim i As Long
    i = 0
    
    ListBoxFac.ColumnCount = 2
        
    lastrowfac = Worksheets("facilities").Cells(Rows.Count, 1).End(xlUp).Row
    
    Set FacRange = Range(Worksheets("facilities").Cells(4, 1), Worksheets("facilities").Cells(lastrowfac, 1))
    
    For Each FacCell In FacRange
        If FacCell.Value <> "" _
        And FacCell.Interior.ColorIndex = xlNone Then
            ReDim Preserve facarray(i, 1)
            facarray(i, 0) = FacCell.Value
            facarray(i, 1) = Cells(FacCell.Row, 2)
            i = i + 1
           ' used to say listboxfac.additem faccell.value
        End If
    Next FacCell   
End Sub
 

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,013
Only the last dimension of an array can be re-dimmed. Therefore, try assigning the worksheet values to a '2 Row by N Column' array instead...

Code:
                ReDim Preserve facarray(1, i)
                facarray(0, i) = FacCell.Value
                facarray(1, i) = Cells(FacCell.Row, 2)
Then you can transpose the contents of the array and assign it to your listbox using the List property...

Code:
ListBoxFac.List = Application.Transpose(facarray)
 

malonemcbain

New Member
Joined
Jul 2, 2013
Messages
3
Solved! Seems like a strange quirk of excel but I don't know much about arrays, so maybe there's a good reason for only being able to re-dim the last dimension of the array.
 

Domenic

MrExcel MVP
Joined
Mar 10, 2004
Messages
19,013
Yeah, I don't know why there's that limitation... Glad it helped, though.
 

Forum statistics

Threads
1,082,254
Messages
5,364,057
Members
400,776
Latest member
JimmyLee

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top