Listbox with 17 columns

FAD

New Member
Joined
Feb 23, 2021
Messages
5
Office Version
  1. 365
Platform
  1. Windows
Hi All,
I am a dummy in VBA excel. I need help with the user form to display 12 columns from 17 columns worksheet that is from column 1:10,16,17. and columns 11:15 in the popup user form 2 in text box. I have copied some codes from the net it works, On a start-up it displays all the records in the list box with above mention format. When I use search the particular record it displays only 1:10 columns and on 11th column it gives me error. Due to limitations of List box Add Items. I don't know how to change the codes. Anyone Please help me to rewrite the code for the attached procedure. Thanks in advance.
VBA Code:
Dim isim As Range, liste As Long

Private Sub cmdbul1_Click()
Application.ScreenUpdating = False
ListBox2.RowSource = Empty
For Each isim In Range("b3:b" & Range("b" & Rows.Count).End(xlUp).Row)
    If UCase(LCase(isim)) Like UCase(LCase(TextBox1)) & "*" Then
        liste = ListBox2.ListCount
            ListBox2.AddItem
            ListBox2.List(liste, 0) = isim
            ListBox2.List(liste, 1) = isim.Offset(0, 1)
            ListBox2.List(liste, 2) = isim.Offset(0, 2)
            ListBox2.List(liste, 3) = isim.Offset(0, 3)
            ListBox2.List(liste, 4) = isim.Offset(0, 4)
            ListBox2.List(liste, 5) = isim.Offset(0, 5)
            ListBox2.List(liste, 6) = isim.Offset(0, 6)
            ListBox2.List(liste, 7) = isim.Offset(0, 7)
            ListBox2.List(liste, 8) = isim.Offset(0, 8)
            ListBox2.List(liste, 9) = isim.Offset(0, 9)
            ListBox2.List(liste, 10) = isim.Offset(0, 10) ' I am getting this error here "Could not set the list property. Invalid property value.", because of it limitations, which allows only 10 columns
            ListBox2.List(liste, 11) = isim.Offset(0, 11) ' from 'Liste 0-9'. I want to change the code here with something else, which can display
                                                        ' first 10 and last 2 columns here. And the middle five columns in the text box below.
                                                       
          End If
Next
Application.ScreenUpdating = True
End Sub
 
Last edited by a moderator:

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Can you not just show all columns in listbox and then hide the ones you don't want

VBA Code:
ListBox1.ColumnWidths = "50;50;0;0;0;50"

Here 6 columns are shown with three set to 0 width, so they will be hidden in the list box
 
Upvote 0
Something like this

VBA Code:
Userform1.ListBox1.ColumnCount = 6
    Userform1.ListBox1.ColumnWidths = "50;50;0;0;0;50"
    Userform1.ListBox1.RowSource = "'" & Sheet1.Name & "'!$A$1:$F$" & Sheet1.Cells(Sheet1.Rows.Count, 1).End(xlUp).Row
 
Upvote 0
Can you not just show all columns in listbox and then hide the ones you don't want

VBA Code:
ListBox1.ColumnWidths = "50;50;0;0;0;50"

Here 6 columns are shown with three set to 0 width, so they will be hidden in the list box
Thanks Sharid, for your reply. That's what i did in my initial list box. When I load the form it displays all the records in it. I have hidden columns 11:15, as you have mention. but the problem comes When I search and display the record it does the procedure I have attached. Could you change that procedure code for me, so that it can display as you have mention. Thanks
 
Upvote 0
Not sure if you saw my second post, this is a update. Change the sheet, listbox and userform name. Also the column width, currently its 50

VBA Code:
Userform1.ListBox1.ColumnCount = 17
    ColumnWidths = "50;50;50;50;50;50;50;50;50;50;50;0;0;0;50;50;50"
    Userform1.ListBox1.RowSource = "'" & Sheet1.Name & "'!$A$1:$q$" & Sheet1.Cells(Sheet1.Rows.Count, 1).End(xlUp).Row
Userform1.ListBox1.repaint

Did you hide the columns on the sheet or on the listbox?

As all columns need to be visible on the sheet, this hides them on the listbox.
 
Upvote 0
It is doing that procedure with the search results. it has to display there search results. Will your code work there? For your understanding I can attach my workbook it not complex just simple. Is it possible to attach a workbook, How?
 
Upvote 0
Hi & welcome to MrExcel.
How about
VBA Code:
Private Sub cmdbul1_Click()
   Dim Rws As Variant, Ary As Variant
   Dim Txt As String
   
   Txt = Me.TextBox1.Value
   With Range("B3:R" & Range("B" & Rows.Count).End(xlUp).Row + 1)
      Rws = Filter(Evaluate(Replace(Replace(Replace("transpose(if(left(@,len(""" & Txt & """))=""" & Txt & """,row(@)-#,false))", "@", .Columns(1).Address), "#", .Rows(0).Row), "~", Me.TextBox1.Value)), False, False)
      ReDim Preserve Rws(0 To UBound(Rws) + 1)
      Rws(UBound(Rws)) = .Rows.Count
      Ary = Application.Index(.Value, Application.Transpose(Rws), Array(1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 16, 17))
   End With
   Me.Listbox2.RowSource = Empty
   Me.Listbox2.List = Ary
End Sub
 
Upvote 0
Solution
did you get this to work? if not i have solved this issue in my own programs. i have listboxes with more than 100 columns that work fine
 
Upvote 0
Hi & welcome to MrExcel.
How about
VBA Code:
Private Sub cmdbul1_Click()
   Dim Rws As Variant, Ary As Variant
   Dim Txt As String
  
   Txt = Me.TextBox1.Value
   With Range("B3:R" & Range("B" & Rows.Count).End(xlUp).Row + 1)
      Rws = Filter(Evaluate(Replace(Replace(Replace("transpose(if(left(@,len(""" & Txt & """))=""" & Txt & """,row(@)-#,false))", "@", .Columns(1).Address), "#", .Rows(0).Row), "~", Me.TextBox1.Value)), False, False)
      ReDim Preserve Rws(0 To UBound(Rws) + 1)
      Rws(UBound(Rws)) = .Rows.Count
      Ary = Application.Index(.Value, Application.Transpose(Rws), Array(1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 16, 17))
   End With
   Me.Listbox2.RowSource = Empty
   Me.Listbox2.List = Ary
End Sub
Thank you very much for your help. Your code did work, but with minor changes. I have to add rest of the array numbers in the array, which was omitted. Thank you once again and Thank to Sharid as well.
 
Upvote 0
You're welcome & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,587
Messages
6,120,405
Members
448,958
Latest member
Hat4Life

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