I would like to populate the 2nd List box based on the selection of the 1st List box? The product codes are unique to a supplier in my workbook. I have attached a sample file.
Thanks in advance
I would like to populate the 2nd List box based on the selection of the 1st List box? The product codes are unique to a supplier in my workbook. I have attached a sample file.
Thanks in advance
Aland2929,
Attached is a modified version of your test file.
I have provided two different solutions, a Formula solution and the requested VBA userform solution.
For the formula solution:
First I converted the data in columns A:D into a table (Selected the data -> Insert tab -> Table)
Then in cell F2 and copied down is this formula to get the list of unique suppliers:
Next I created a dynamic named range called listUnqSuppliers with this named range formula:![]()
=IFERROR(INDEX(Table1[Supplier],MATCH(0,INDEX(COUNTIF(F$1:F1,Table1[Supplier]),),0)),"")
Cell J1 uses a data validation list with that named range to display a drop-down list of the unique suppliers.![]()
=Sheet1!$F$2:INDEX(Sheet1!$F:$F,MAX(2,ROWS(Sheet1!$F:$F)-COUNTBLANK(Sheet1!$F:$F)))
To get the list of the products for the chosen supplier, in cell G2 and copied down is this formula:
I also created a dynamic named range called listSupplierProducts with this named range formula:![]()
=IF(OR($J$1="",ROWS(G$1:G1)>COUNTIF(Table1[Supplier],$J$1)),"",INDEX(Table1[Product],MATCH(1,INDEX((Table1[Supplier]=$J$1)*(COUNTIF(G$1:G1,Table1[Product])=0),),0)))
Cell J2 uses a data validation list with that named range to display a drop-down list of the products. The list only contains products for the selected Supplier. I threw in a couple of extra formulas in cells J4 and J5 to display the Code and Units for the chosen Supplier and Product.![]()
=Sheet1!$G$2:INDEX(Sheet1!$G:$G,MAX(2,ROWS(Sheet1!$G:$G)-COUNTBLANK(Sheet1!$G:$G)))
On to the VBA portion. First I deleted the RowSource property of ListBox1, and I used the Userform_Initialize event in order to populate ListBox1:
![]()
Private Sub UserForm_Initialize() Dim ws As Worksheet Dim rngSuppliers As Range Dim SupplierCell As Range Dim strUnq As String Set ws = Sheets("Sheet1") Set rngSuppliers = ws.Range("B2", ws.Cells(Rows.Count, "B").End(xlUp)) For Each SupplierCell In rngSuppliers.Cells If InStr(1, "|" & strUnq & "|", "|" & SupplierCell.Text & "|", vbTextCompare) = 0 Then strUnq = strUnq & "|" & SupplierCell.Text Next SupplierCell If Len(strUnq) > 0 Then Me.ListBox1.List = Split(Mid(strUnq, 2), "|") Set ws = Nothing Set rngSuppliers = Nothing Set SupplierCell = Nothing End Sub
Next I used the ListBox1_Change event in order to populate ListBox2:
![]()
Private Sub ListBox1_Change() Dim ws As Worksheet Dim rngFound As Range Dim strFirst As String Dim strList As String Me.ListBox2.Clear If Me.ListBox1.ListIndex = -1 Then Exit Sub Set ws = Sheets("Sheet1") Set rngFound = ws.Columns("B").Find(Me.ListBox1.Text, , xlValues, xlWhole) If Not rngFound Is Nothing Then strFirst = rngFound.Address Do strList = strList & "|" & ws.Cells(rngFound.Row, "C").Text Set rngFound = ws.Columns("B").Find(Me.ListBox1.Text, rngFound, xlValues, xlWhole) Loop While rngFound.Address <> strFirst Me.ListBox2.List = Split(Mid(strList, 2), "|") End If Set ws = Nothing Set rngFound = Nothing End Sub
Hopefully you can adapt one of these solutions to fit your needs.
Hope that helps,
~tigeravatar
Forum Rules: How to use code tags, mark a thread solved, and keep yourself out of trouble
Absolutely brilliant! Thanks so much for your time and effort. These solutions are perfect.
![]()
There are currently 1 users browsing this thread. (0 members and 1 guests)
Bookmarks