Add event handling for combobox created at runtime

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
I've been playing around with adding ComboBoxes at run time (eg in response to user actions on a sheet) and this I can easily manage. However, I was wondering how I can then get this newly created combobox itself to respond to user events eg user selecting a value, user clicking out of the combobox etc? Have I missed something simple?

Thanks for all replies!

Richard
 

Some videos you may like

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"

Andrew Poulsom

MrExcel MVP
Joined
Jul 21, 2002
Messages
73,092
Here is an example:

Code:
Sub Test()
    Dim oole As OLEObject
    Dim CodeMod As Object
    Dim Code As String
    Dim Line As Integer
    Set oole = ActiveSheet.OLEObjects.Add(ClassType:="Forms.ComboBox.1", Link:=False, _
        DisplayAsIcon:=False, Left:=231.75, Top:=54.75, Width:=69.75, Height _
        :=24)
    MsgBox TypeName(oole)
    With oole.Object
        .List = Array("a", "b", "c", "d")
    End With
    Set CodeMod = ThisWorkbook.VBProject.VBComponents(ActiveSheet.CodeName).CodeModule
    With CodeMod
        Line = .CreateEventProc("Change", oole.Name) + 1
        Code = "   MsgBox ""You chose "" & " & oole.Name & ".Value"
        .InsertLines Line, Code
    End With
End Sub
 

Norie

Well-known Member
Joined
Apr 28, 2004
Messages
75,835
Office Version
  1. 365
Platform
  1. Windows
Richard

What type of comboboxes are you dealing with?

Perhaps you should look into using a class module to handle the events.
 

Richard Schollar

MrExcel MVP
Joined
Apr 19, 2005
Messages
23,707
Thanks Andrew - exactly what I was after :biggrin:

Thanks Norie - using class modules is a very good idea, and one which I shall investigate.

:biggrin:
 

Watch MrExcel Video

Forum statistics

Threads
1,109,505
Messages
5,529,264
Members
409,859
Latest member
emperorgenghiskhan
Top