Selective Drop down List - Data Validation

vikrampnz

Board Regular
Joined
Jun 20, 2006
Messages
111
Office Version
  1. 2007
Platform
  1. Windows
Hello

I have a workbook that has two lists B2:B203 has "Unit Numbers" and C2:C203 has "Available" or "Sold" status in front of each unit.

I have created a drop down list showing "Unit numbers" in another worksheet using Data Validation. I am trying to figure out a way to only display "Unit Numbers" in the drop down list which are "Available" i.e. Have a status "Available" in the corresponding cell in column C.

For example:

Column B Column C
Unit No. Status
B-101 Sold
B-102 Available
B-103 Available
B-104 Sold .....and so on. Th drop down list showing Unit Numbers should only show Units: B-102 and B-103 as they are available.

Can anyone help please?

Thanks
V
 
Different approach:
Copy and paste this macro into the worksheet code module. Do the following: right click the tab name for your sheet containing the drop down list and click 'View Code'. Paste the macro into the empty code window that opens up. The macro assumes that the drop down list is in cell A1. Change this range (in red-two occurrences) to suit your needs. It also assumes that your lists in B2:C203 are in a sheet named "Sheet1". Change the name (in blue-two occurrences) to suit your needs. Close the code window to return to your sheet. Click on the cell containing the drop down list (A1 or the actual cell you change in the code).
Rich (BB code):
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
    If Intersect(Target, Range("A1")) Is Nothing Then Exit Sub
    Dim LastRow As Long, rngList As Object, Arr As Variant, i As Long
    LastRow = Sheets("Sheet1").Cells.Find("*", SearchOrder:=xlByRows, SearchDirection:=xlPrevious).Row
    Application.ScreenUpdating = False
    Arr = Sheets("Sheet1").Range("B2:B" & LastRow).Resize(, 2).Value
    Set rngList = CreateObject("Scripting.Dictionary")
    For i = LBound(Arr) To UBound(Arr)
        If Arr(i, 2) = "Available" Then
            rngList.Add Arr(i, 1), Nothing
        End If
    Next i
    With Range("A1").Validation
        .Delete
        .Add Type:=xlValidateList, Formula1:=Join(rngList.keys, ",")
    End With
    Application.ScreenUpdating = True
End Sub
 
Upvote 0

Excel Facts

Save Often
If you start asking yourself if now is a good time to save your Excel workbook, the answer is Yes

Forum statistics

Threads
1,214,978
Messages
6,122,549
Members
449,089
Latest member
davidcom

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