Tmf215

New Member
Joined
Feb 24, 2012
Messages
1
Hi,

I've encountered a very frustrating situation after conquering what I thought had been the hard part of my project. I spent a good part of today looking around on Google and this forum in search of a solution without having any success, so I'm hoping someone can give me a hand!

What I'm working with is a single workbook with two worksheets, ("A" and "B"), the first of which will be manipulated later and the second containing all of my gathered data.

For simplicity, lets say worksheet "B" has ten columns of data five rows deep. Row 1 contains titles and rows 2-5 contains data.

Worksheet "A" has the titles from Worksheet "B" (Row 1, Columns A - J) transposed into column A (Rows 1-10)

What I'm trying to do is have excel create dropdowns on worksheet "A" in column B based on the associated data on worksheet "B". I tried the obvious approach first by creating a data validation dropdown on Worksheet "A" B1 and dragging it down, but it simply repeats the same dropdown without changing the data source. If my real project was only 10 rows it wouldn't be a problem to manually create each dropdown, but my project requires over 600, so it's not really feasible to do each by hand.

This has been driving me crazy, so any help is greatly appreciated!
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
U will have to modufy according to your data.

Code:
Sub Macro1()
Dim shA, shB As Worksheet
Set shA = Sheets("Sheet1")
Set shB = Sheets("Sheet2")

Dim valRange As Range
For i = 1 To 10
    Set valRange = shB.Range(shB.Cells(2, i), shB.Cells(Rows.Count, i).End(xlUp))
    With shA.Range("B" & i).Validation
        .Delete
        .Add Type:=xlValidateList, AlertStyle:=xlValidAlertStop, Operator:= _
        xlBetween, Formula1:="=" & shB.Name & "!" & valRange.Address
        .IgnoreBlank = True
        .InCellDropdown = True
        .InputTitle = ""
        .ErrorTitle = ""
        .InputMessage = ""
        .ErrorMessage = ""
        .ShowInput = True
        .ShowError = True
    End With
Next i
End Sub
 
Upvote 0

Forum statistics

Threads
1,215,019
Messages
6,122,707
Members
449,093
Latest member
Mnur

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