Trapping Events Of Embeeded CommandButtons Via Class Modules

Jaafar Tribak

Well-known Member
Joined
Dec 5, 2002
Messages
9,621
Office Version
  1. 2016
Platform
  1. Windows
Hi Experts,

I have 40 CommandButtons embeeded on a worksheet.

I want to assign a generic On Click Event procedure to all these Buttons via a class Module so that when any of the Buttons is Clicked ,a MsgBox pops up with the name of the Button displayed.

This can easily be done with CommandButtons on a UserForm using the above technic with no problems.

It is also possible to achieve the same effect with Worksheet Buttons from the Forms Toolbar thanks to the OnAction and Application Caller properties.

However, I can't seem to make any of the above aproaches work when it comes to embeeded worksheet OLEobjects such as CommandButtons from the Control ToolBar. :unsure:

I am very curious to know if this is possible.

Any Ideas ? :pray:

TIA.
 

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.
Hi Jaafar

Add a class module called clsCommandButtons and paste this code in:

Code:
Option Explicit
Public WithEvents Button As CommandButton

Private Sub Button_Click()
'This sub is run upon each click event
MsgBox Button.Caption
End Sub

Then in the ThisWorkbook class paste this:

Code:
Dim buttons() As New clsCommandButtons

Private Sub Workbook_Open()
Dim Cntl As OLEObject
Dim x As Integer
x = -1
With Sheet1
    For Each Cntl In .OLEObjects
        If TypeName(Cntl.Object) = "CommandButton" Then
        x = x + 1
            ReDim Preserve buttons(0 To x)
            Set buttons(x).Button = Cntl.Object
        End If
    Next Cntl
End With
Set Cntl = Nothing
End Sub


HTH
 
Upvote 0
Re: Trapping Events Of Embeeded CommandButtons Via Class Mod

Zilpher , Very interesting code (y)

Nice use of the Object array as an alternative to using collections.

I know where I went wrong : I was setting the Button pointer to the Cntl variable instead of the Cntl.Object Object !

I have always found this Object property of Objects a bit confusing !!

Anyway , in case anybody is interested to see the slightly different approach I followed in my code then here it is :


In the WorkBook Class module:


<font face=Courier New><SPAN style="color:#00007F">Dim</SPAN> ObjButton <SPAN style="color:#00007F">As</SPAN> clsCommandButtons
<SPAN style="color:#00007F">Dim</SPAN> Col <SPAN style="color:#00007F">As</SPAN> <SPAN style="color:#00007F">New</SPAN> Collection

<SPAN style="color:#00007F">Private</SPAN> <SPAN style="color:#00007F">Sub</SPAN> Workbook_Open()
    <SPAN style="color:#00007F">Dim</SPAN> Cntl <SPAN style="color:#00007F">As</SPAN> OLEObject
    <SPAN style="color:#00007F">With</SPAN> Sheet1
        <SPAN style="color:#00007F">For</SPAN> <SPAN style="color:#00007F">Each</SPAN> Cntl <SPAN style="color:#00007F">In</SPAN> .OLEObjects
            <SPAN style="color:#00007F">If</SPAN> Cntl.progID = "Forms.CommandButton.1" <SPAN style="color:#00007F">Then</SPAN>
            <SPAN style="color:#00007F">Set</SPAN> ObjButton = <SPAN style="color:#00007F">New</SPAN> clsCommandButtons
            <SPAN style="color:#00007F">Set</SPAN> ObjButton.GenericButton = Cntl.Object
            Col.Add ObjButton
            <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">If</SPAN>
        <SPAN style="color:#00007F">Next</SPAN> Cntl
    <SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">With</SPAN>
    <SPAN style="color:#00007F">Set</SPAN> Cntl = <SPAN style="color:#00007F">Nothing</SPAN>
<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN>
</FONT>


In the Class Module : (clsCommandButtons)

<font face=Courier New><SPAN style="color:#00007F">Public</SPAN> <SPAN style="color:#00007F">WithEvents</SPAN> GenericButton <SPAN style="color:#00007F">As</SPAN> CommandButton

<SPAN style="color:#00007F">Private</SPAN> <SPAN style="color:#00007F">Sub</SPAN> GenericButton_Click()
    MsgBox GenericButton.Caption
<SPAN style="color:#00007F">End</SPAN> <SPAN style="color:#00007F">Sub</SPAN>
</FONT>


Thanks again for the quick answer.
 
Upvote 0

Forum statistics

Threads
1,215,332
Messages
6,124,314
Members
449,153
Latest member
JazzSingerNL

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