+ Reply to Thread
Results 1 to 2 of 2

Excel Dropbox Help

  1. #1
    Registered User
    Join Date
    07-17-2005
    Posts
    22

    Question Excel Dropbox Help

    Hi all,

    I'm hoping someone can help me out with a dropbox problem.

    I am using two dropboxes on each row of data. The following code is attached to the first dropbox -

    Sub DropDown10_Change()

    If Cells(2, 5) = 1 Then
    ActiveSheet.Shapes("Drop Down 1").Select
    With Selection
    .ListFillRange = "Inputs!$A$2:$A$9"

    End With
    End If

    If Cells(2, 5) = 2 Then
    ActiveSheet.Shapes("Drop Down 1").Select
    With Selection
    .ListFillRange = "Inputs!$B$2:$B$9"

    End With
    End If

    If Cells(2, 5) = 3 Then
    ActiveSheet.Shapes("Drop Down 1").Select
    With Selection
    .ListFillRange = "Inputs!$C$2:$C$5"

    End With
    End If

    End Sub


    The dropbox is linked to the cell it sits in. So the code basically reads the number in the cell, and depending on what option was selected - decides what to populate the second drop box with.

    The problem has stemmed from my need to copy these drop boxes down (up to 1000 times). Is there some way to -

    a) Automatically update the cell link in the format control of the drop box as I fill the box down (ie. update from A1 to A2 when dragged down)

    b) Instead of using "Cells(2,5)", use a bit of code to say - 'whatever cell the drop box is linked to'.

    c)Overcome the naming problem with filling the boxes down. ie. box in A1 and A2 are 'Dropbox 10', so instead of referring to them by name, refer to them as 'selected drop box'.

    Hope this makes sense. I don't think I can do what I want to do (without programming the macro and renaming each drop box). I think the only solution is for me to have one data entry sheet, and another for storing the info. - this seems more practical - however is not suitable as I intend this to be a data entry page with lots of repetitive info. The feature of excel that picks up on data already entered (ie if you have john in a cell and type 'j' john will come up automatically) is important. This would be lost with a seperate input page.

    Any advice would be appreciated!

    Cheers

    systematic
    Last edited by systematic; 11-30-2005 at 09:45 AM.

  2. #2
    Dave Peterson
    Guest

    Re: Excel Dropbox Help

    I think you might be able to do what you want, but how about a different
    approach.

    I'm kind of confused at what's happening and when it should happen, but maybe
    you could do all the work with just one drop down. Just have it move to the
    selected cell and set things up based on that selected cell.

    I put one dropdown from the Forms toolbar on a worksheet. I named it "Drop Down
    1".

    Then I rightclicked on the worksheet tab and selected view code. I pasted this
    into that window:

    Option Explicit
    Private Sub Worksheet_SelectionChange(ByVal Target As Range)

    Dim myDD As DropDown
    Dim myList As Range

    If Target.Cells.Count > 1 Then Exit Sub

    Set myDD = Nothing
    On Error Resume Next
    Set myDD = Me.DropDowns("drop down 1")
    On Error GoTo 0

    If myDD Is Nothing Then
    Set myDD = Me.DropDowns.Add(0, 0, 0, 0)
    myDD.Name = "Drop Down 1"
    End If

    If Intersect(Target, Me.Range("e:e")) Is Nothing Then
    myDD.Visible = False
    Exit Sub
    End If

    With Target
    myDD.Top = .Top
    myDD.Left = .Left
    myDD.Width = .Width
    myDD.Height = .Height
    myDD.LinkedCell = .Cells.Address(external:=True)
    myDD.Visible = True

    Select Case .Value
    Case Is = 1
    Set myList = Me.Parent.Worksheets("inputs").Range("a2:a9")
    Case Is = 2
    Set myList = Me.Parent.Worksheets("inputs").Range("b2:b9")
    Case Is = 3
    Set myList = Me.Parent.Worksheets("inputs").Range("c2:c5")
    Case Else
    Set myList = Me.Parent.Worksheets("inputs").Range("a2:a9")
    End Select

    myDD.listfillrange = myList.Address(external:=True)

    End With

    End Sub

    I was confused about how to determine the listfillrange, though.

    Basing the listfillrange on that linked cell that may have been based on a
    different range seemed kind of strange to me.

    systematic wrote:
    >
    > Hi all,
    >
    > I'm hoping someone can help me out with a dropbox problem.
    >
    > I am using two dropboxes on each row of data. The following code is
    > attached to the first dropbox -
    >
    > sub dropdown10_change()
    >
    > if cells(2, 5) = 1 then
    > activesheet.shapes(\"drop down 1\").select
    > with selection
    > listfillrange = \"inputs!$a$2:$a$9\"
    >
    > end with
    > end if
    >
    > if cells(2, 5) = 2 then
    > activesheet.shapes(\"drop down 1\").select
    > with selection
    > listfillrange = \"inputs!$b$2:$b$9\"
    >
    > end with
    > end if
    >
    > if cells(2, 5) = 3 then
    > activesheet.shapes(\"drop down 1\").select
    > with selection
    > listfillrange = \"inputs!$c$2:$c$5\"
    >
    > end with
    > end if
    >
    > end sub
    >
    > The dropbox is linked to the cell it sits in. So the code basically
    > reads the number in the cell, and depending on what option was selected
    > - decides what to populate the second drop box with.
    >
    > The problem has stemmed from my need to copy these drop boxes down (up
    > to 1000 times). Is there some way to -
    >
    > a) Automatically update the cell link in the format control of the drop
    > box as I fill the box down (ie. update from A1 to A2 when dragged down)
    >
    > b) Instead of using "Cells(2,5)", use a bit of code to say - 'whatever
    > cell the drop box is linked to'.
    >
    > c)Overcome the naming problem with filling the boxes down. ie. box in
    > A1 and A2 are 'Dropbox 10', so instead of referring to them by name,
    > refer to them as 'selected drop box'.
    >
    > Hope this makes sense. I don't think I can do what I want to do
    > (without programming the macro and renaming each drop box). I think the
    > only solution is for me to have one data entry sheet, and another for
    > storing the info. - this seems more practical.
    >
    > Any advice would be appreciated!
    >
    > Cheers
    >
    > systematic
    >
    > --
    > systematic
    > ------------------------------------------------------------------------
    > systematic's Profile: http://www.excelforum.com/member.php...o&userid=25294
    > View this thread: http://www.excelforum.com/showthread...hreadid=489401


    --

    Dave Peterson

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1