Results 1 to 9 of 9
  1. #1
    5 Star Lounger
    Join Date
    Aug 2001
    Location
    Surrey, United Kingdom
    Posts
    1,001
    Thanks
    0
    Thanked 0 Times in 0 Posts

    UserForm link to RangeNames (2003 SP2)

    Good morning

    As all regulars are aware I have steered away from VBA because it is something that I have not been comfortable with, I am however trying to dip my toe in so to speak and am trying to make a UserForm, I have so far got this behind a button on the form

    Private Sub cmdAddLeave_Click()
    Dim Irow As Long
    Dim Iname As Long
    Dim ws As Worksheet
    Set ws = Worksheets("2008")

    'find first empty row in db

    Irow = ws.Cells(Rows.Count, 1).End(xlUp).Offset(1, 0).Row
    Iname = Me.cboName.ListIndex

    'Check for a name

    If Trim(Me.cboName.Value) = "" Then MsgBox "Please enter an emplyees name"
    Exit Sub
    End If

    'Copy the data to the database

    With ws
    .Cells(Irow, 1).Value = Me.cboName
    .Cells(Irow, 2).Value = Me.cboName.List(Iname, 1)
    .Cells(Irow, 3).Value = Me.txtDateFrom.Value
    .Cells(Irow, 4).Value = Me.txtDateTo.Value
    .Cells(Irow, 5).Value = Me.cboLeaveType.Value
    End With

    'Clear the data

    Me.cboName.Value = ""
    Me.txtDateFrom.Value = ""
    Me.txtDateTo.Value = ""
    Me.cmdAddLeave.Value = ""
    Me.cboName.SetFocus

    End Sub

    I can't seem to fathom out how I populate the Combo's on the UserForm, combo 1 cboName needs to be populated by a range on the ws called Staff and combo 2 cboLeaveType by a range on the ws called LeaveTypes

    Any pointers would be appreciated

    Cheers

    Steve
    Cheers

    Steve

    Asking the questions everbody wants the answers too but feels too stupid to ask themselves :-)

  2. #2
    Platinum Lounger
    Join Date
    Feb 2001
    Location
    Weert, Limburg, Netherlands
    Posts
    4,812
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: UserForm link to RangeNames (2003 SP2)

    In some event sub of the userform (e.g. the initialize event):

    Dim oCell as Range
    Combo1.Clear
    For Each oCell in ThisWorkbook.Names("Staff").RefersToRange
    Combo1.AddItem cStr(oCell.Value)
    Next

    Etcetera...
    Jan Karel Pieterse
    Microsoft Excel MVP, WMVP
    www.jkp-ads.com
    Professional Office Developers Association

  3. #3
    5 Star Lounger
    Join Date
    Aug 2001
    Location
    Surrey, United Kingdom
    Posts
    1,001
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: UserForm link to RangeNames (2003 SP2)

    Thank you

    I will go of and try that now

    Cheers

    Steve
    Cheers

    Steve

    Asking the questions everbody wants the answers too but feels too stupid to ask themselves :-)

  4. #4
    WS Lounge VIP rory's Avatar
    Join Date
    Dec 2000
    Location
    Burwash, East Sussex, United Kingdom
    Posts
    6,280
    Thanks
    3
    Thanked 191 Times in 177 Posts

    Re: UserForm link to RangeNames (2003 SP2)

    You should also be able to use:
    <code>cboName.List = ws.Range("Staff").Value</code>

    just as an alternative option. (You could also bind the combo to the range, but I prefer not to, unless it's a fixed list)
    Regards,
    Rory

    Microsoft MVP - Excel

  5. #5
    5 Star Lounger
    Join Date
    Aug 2001
    Location
    Surrey, United Kingdom
    Posts
    1,001
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: UserForm link to RangeNames (2003 SP2)

    Thanks Rory

    Where would I need to add that piece of code and would I do it for both in the same place, for example

    cboName.List = ws.Range("Staff").Value
    cboName.List = ws.Range("LeaveType").Value

    Cheers

    Steve
    Cheers

    Steve

    Asking the questions everbody wants the answers too but feels too stupid to ask themselves :-)

  6. #6
    Plutonium Lounger
    Join Date
    Mar 2002
    Posts
    84,353
    Thanks
    0
    Thanked 29 Times in 29 Posts

    Re: UserForm link to RangeNames (2003 SP2)

    Rory's code would replace the code suggested by Pieterse.

    It makes no sense to set the list of the same combo box twice. The second instruction overrides the result of the first one. I assume that you meant to use two different combo boxes.

  7. #7
    WS Lounge VIP rory's Avatar
    Join Date
    Dec 2000
    Location
    Burwash, East Sussex, United Kingdom
    Posts
    6,280
    Thanks
    3
    Thanked 191 Times in 177 Posts

    Re: UserForm link to RangeNames (2003 SP2)

    Based on your earlier post, you would use:
    <pre>cboName.List = ws.Range("Staff").Value
    cboLeave.List = ws.Range("LeaveType").Value
    </pre>

    I guess.
    Regards,
    Rory

    Microsoft MVP - Excel

  8. #8
    Platinum Lounger
    Join Date
    Feb 2001
    Location
    Weert, Limburg, Netherlands
    Posts
    4,812
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: UserForm link to RangeNames (2003 SP2)

    Rory: Assigning an entire array at once to a listbox/combo fails sometimes, which is why I prefer to do them one at the time.
    Jan Karel Pieterse
    Microsoft Excel MVP, WMVP
    www.jkp-ads.com
    Professional Office Developers Association

  9. #9
    5 Star Lounger
    Join Date
    Aug 2001
    Location
    Surrey, United Kingdom
    Posts
    1,001
    Thanks
    0
    Thanked 0 Times in 0 Posts

    Re: UserForm link to RangeNames (2003 SP2)

    Thanks everybody

    Both worked great but I went for the longer version because of the comments regarding errors

    Cheers

    Steve
    Cheers

    Steve

    Asking the questions everbody wants the answers too but feels too stupid to ask themselves :-)

Posting Permissions

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