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
 

Excel Facts

Can a formula spear through sheets?
Use =SUM(January:December!E7) to sum E7 on all of the sheets from January through December
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)
 
Upvote 0
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.
 
Upvote 0
Yeah, I don't know why there's that limitation... Glad it helped, though.
 
Upvote 0

Forum statistics

Threads
1,214,821
Messages
6,121,762
Members
449,048
Latest member
excelknuckles

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