Fill Listbox with Multiple Ranges

mucah!t

Well-known Member
Joined
Jun 27, 2009
Messages
593
Hi all,

Is it possible to fill a ActiveX Listbox with multiple dynamic ranges?
[ie; A4-C10, D4-F18, G4-I9]
 

Excel Facts

Shade all formula cells
To shade all formula cells: Home, Find & Select, Formulas to select all formulas. Then apply a light fill color.
I tried a couple of ways and it doesn't seem that it is.

Are you using VB in your project at all? It might be possible to achieve in code, although I've not tried this way yet.
 
Upvote 0
This is one way:-
NB:-Column widths are "25"
Code:
[COLOR="Navy"]Sub[/COLOR] MG11Sep08
[COLOR="Navy"]Dim[/COLOR] Rng     [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] Ray     [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]Dim[/COLOR] Dn      [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] A       [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] c       [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer[/COLOR]
[COLOR="Navy"]Dim[/COLOR] W       [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]String[/COLOR]
[COLOR="Navy"]Dim[/COLOR] Col     [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer[/COLOR]
[COLOR="Navy"]Dim[/COLOR] RwMax   [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer[/COLOR]
[COLOR="Navy"]Dim[/COLOR] ColNum  [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer[/COLOR]
[COLOR="Navy"]Dim[/COLOR] oMin    [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer[/COLOR]
[COLOR="Navy"]Set[/COLOR] Rng = Range("A4:C10,D4:F18,G4:I9")
oMin = Rng.Count
[COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] A [COLOR="Navy"]In[/COLOR] Rng.Areas
    oMin = Application.Min(A(1).Row, oMin)
    c = c + A.Columns.Count
        [COLOR="Navy"]For[/COLOR] Col = 1 To A.Columns.Count
            W = W & "25,"
        [COLOR="Navy"]Next[/COLOR] Col
            RwMax = Application.Max(A.Rows.Count, RwMax)
            ColNum = ColNum + A.Columns.Count
[COLOR="Navy"]Next[/COLOR] A
ReDim Ray(1 To RwMax, 1 To ColNum)
    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
        Ray(Dn.Row - oMin + 1, Dn.Column) = Dn
    [COLOR="Navy"]Next[/COLOR] Dn
[COLOR="Navy"]With[/COLOR] ListBox1
    .ColumnWidths = W
    .ColumnCount = c
    .List = Ray
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]With[/COLOR]
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0
Hello Mick,

How do I get this working for an ActiveX Listbox?
I tried "view Code" and pasting it their, but that didn't work.
 
Upvote 0
This will fill the Listbox when you activate the sheet.
Right click the "Listbox " sheet Tab , Select "view code".
Vb window appears.
Paste Code into Window.
NB:- At the start of the code you will see the line
With Sheets("Sheet68")
Change this to the sheet name of the sheet with the Data on.
i.e. Sheet of :- (Range("A4:C10,D4:F18,G4:I9"))
This is in case your data is on a different sheet to your Listbox sheet.
Code:
Private [COLOR=navy]Sub[/COLOR] Worksheet_Activate()
[COLOR=navy]Dim[/COLOR] Rng     [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Dim[/COLOR] Ray     [COLOR=navy]As[/COLOR] Variant
[COLOR=navy]Dim[/COLOR] Dn      [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Dim[/COLOR] A       [COLOR=navy]As[/COLOR] Range
[COLOR=navy]Dim[/COLOR] c       [COLOR=navy]As[/COLOR] [COLOR=navy]Integer[/COLOR]
[COLOR=navy]Dim[/COLOR] W       [COLOR=navy]As[/COLOR] [COLOR=navy]String[/COLOR]
[COLOR=navy]Dim[/COLOR] Col     [COLOR=navy]As[/COLOR] [COLOR=navy]Integer[/COLOR]
[COLOR=navy]Dim[/COLOR] RwMax   [COLOR=navy]As[/COLOR] [COLOR=navy]Integer[/COLOR]
[COLOR=navy]Dim[/COLOR] ColNum  [COLOR=navy]As[/COLOR] [COLOR=navy]Integer[/COLOR]
[COLOR=navy]Dim[/COLOR] oMin    [COLOR=navy]As[/COLOR] [COLOR=navy]Integer[/COLOR]
[COLOR=navy]With[/COLOR] Sheets("Sheet68")
    [COLOR=navy]Set[/COLOR] Rng = .Range("A4:C10,D4:F18,G4:I9")
[COLOR=navy]End[/COLOR] With
oMin = Rng.Count
[COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] A [COLOR=navy]In[/COLOR] Rng.Areas
    oMin = Application.Min(A(1).Row, oMin)
    c = c + A.Columns.Count
        [COLOR=navy]For[/COLOR] Col = 1 To A.Columns.Count
            W = W & "25,"
        [COLOR=navy]Next[/COLOR] Col
            RwMax = Application.Max(A.Rows.Count, RwMax)
            ColNum = ColNum + A.Columns.Count
[COLOR=navy]Next[/COLOR] A
ReDim Ray(1 To RwMax, 1 To ColNum)
    [COLOR=navy]For[/COLOR] [COLOR=navy]Each[/COLOR] Dn [COLOR=navy]In[/COLOR] Rng
        Ray(Dn.Row - oMin + 1, Dn.Column) = Dn
    [COLOR=navy]Next[/COLOR] Dn
[COLOR=navy]With[/COLOR] ListBox1
    .ColumnWidths = W
    .ColumnCount = c
    .List = Ray
[COLOR=navy]End[/COLOR] With
[COLOR=navy]End[/COLOR] [COLOR=navy]Sub[/COLOR]
Regards Mick
 
Upvote 0
That's pretty straight forward in comparison.

Code:
[COLOR="Navy"]Sub[/COLOR] MG12Sep22
[COLOR="Navy"]Dim[/COLOR] Rng     [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] Ray     [COLOR="Navy"]As[/COLOR] Variant
[COLOR="Navy"]Dim[/COLOR] Dn      [COLOR="Navy"]As[/COLOR] Range
[COLOR="Navy"]Dim[/COLOR] c       [COLOR="Navy"]As[/COLOR] [COLOR="Navy"]Integer[/COLOR]
[COLOR="Navy"]Set[/COLOR] Rng = Range("A4:C10,D4:F18,G4:I9")
ReDim Ray(1 To Rng.Count)
    [COLOR="Navy"]For[/COLOR] [COLOR="Navy"]Each[/COLOR] Dn [COLOR="Navy"]In[/COLOR] Rng
        c = c + 1
        Ray(c) = Dn
    [COLOR="Navy"]Next[/COLOR] Dn
ListBox1.List = Application.Transpose(Ray)
[COLOR="Navy"]End[/COLOR] [COLOR="Navy"]Sub[/COLOR]
Regards Mick
 
Upvote 0

Forum statistics

Threads
1,224,618
Messages
6,179,917
Members
452,949
Latest member
beartooth91

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