Form Button Magic On Worksheets
There are two types of buttons: Forms Control Buttons which can be linked to a Macro, and Active-X (OLE Objects) Buttons. This article concerns only Forms Control buttons. There are many times when it is valuable to dynamically insert a button onto a worksheet, and then delete, hide or unhide it. The button inserted is assigned to a macro and when clicked by the user, the button will initiate the assigned Macro. The following code shows how to create and delete buttons, and how to reference them as Shape and Button Objects.
Program Code
Option Explicit
Public Sub TestButton()
' *******************************************************************
' There are 2 types of buttons: Forms Control and Active-X
' This demonstration is only for Forms Control Buttons
' *******************************************************************
Dim wkbThisWorkbook As Workbook
Dim wksButtonSheet As Worksheet
' *******************************************************************
' Button Objects for Forms Control Buttons (Shape Type 8)
' *******************************************************************
Dim btnButton As Button
Dim btnButton1 As Button
Dim btnButton2 As Button
' *******************************************************************
' Shape Objects
' *******************************************************************
Dim shpButton As Shape
' *******************************************************************
' Range Objects
' *******************************************************************
Dim rngButton2 As Range
' *******************************************************************
' Initialize Workbook, Worksheet and Range Variables
' *******************************************************************
Set wkbThisWorkbook = ActiveWorkbook
Set wksButtonSheet = wkbThisWorkbook.Sheets("Sheet1")
Set rngButton2 = wksButtonSheet.Cells(20, "C")
' ********************************************************************
' Delete All Forms Control Buttons
' ********************************************************************
wksButtonSheet.Buttons.Delete
MsgBox ("Buttons Deleted")
' ********************************************************************
' Create Adequate Space For A Button Based on Cell Size
' ********************************************************************
wksButtonSheet.Rows("20:20").RowHeight = 44.5
wksButtonSheet.Columns("C:C").ColumnWidth = 25.5
' ********************************************************************
' Create A Forms Control Button (Button1) Using the Button Object
' Place it in an exact screen location
' ********************************************************************
Set btnButton1 = wksButtonSheet.Buttons.Add(100, 100, 100, 100)
With btnButton1
.OnAction = "TestButton"
.Caption = "*Button 1*"
.Name = "btnRunMacro1"
.Font.Name = "Arial"
.Font.Size = 15
.Font.Color = RGB(255, 0, 0)
.Font.Bold = True
.Visible = False 'Choose one of these two
.Visible = True 'Choose one of these two
.Placement = xlFreeFloating 'Choose one of these three
.Placement = xlMove 'Choose one of these three
.Placement = xlMoveAndSize 'Choose one of these three
End With
MsgBox ("Button1 Created")
' ********************************************************************
' Create A Forms Control Button (Button2) Using the Button Object
' Fill an entire Cell with the button
' Note: The Caption sets the Alternative Text Property For the Shape
' ********************************************************************
Set btnButton2 = wksButtonSheet.Buttons.Add(rngButton2.Left, rngButton2.Top, _
rngButton2.Width, rngButton2.Height)
With btnButton2
.OnAction = "TestButton"
.Caption = "*Button 2*"
.Name = "btnRunMacro2"
.Font.Name = "Arial"
.Font.Size = 15
.Font.Color = RGB(255, 0, 0)
.Font.Bold = True
.Visible = False 'Choose one of these two
.Visible = True 'Choose one of these two
.Placement = xlFreeFloating 'Choose one of these three
.Placement = xlMove 'Choose one of these three
.Placement = xlMoveAndSize 'Choose one of these three
End With
MsgBox ("Button2 Created")
' ********************************************************************
' Change Button's Dimensions By Referencing The Shape Object
' ********************************************************************
With wksButtonSheet.Shapes("btnRunMacro1")
.Height = 23.25
.Width = 200.1
.Left = 586.5
.Top = 28.5
End With
' ********************************************************************
' Manipulate Existing Buttons Looping Through Shape Objects
' And Only Selecting Type 8 (Forms Control Button) Objects
' ********************************************************************
For Each shpButton In wksButtonSheet.Shapes
If shpButton.Type = 8 Then
Debug.Print shpButton.Name
Debug.Print shpButton.AlternativeText
Debug.Print shpButton.Type
Application.ScreenUpdating = False
shpButton.Visible = False
Application.ScreenUpdating = True
MsgBox ("Button " & shpButton.AlternativeText & " Should Be Hidden")
Application.ScreenUpdating = False
shpButton.Visible = True
Application.ScreenUpdating = True
MsgBox ("Button " & shpButton.AlternativeText & " Should Be Visible")
shpButton.AlternativeText = "NewButton"
End If
Next
' ********************************************************************
' Manipulate Existing Button Using Specific Button Object
' ********************************************************************
With wksButtonSheet.Buttons("btnRunMacro1")
.Height = 28
.Width = 80
.Left = 600
.Top = 30
.OnAction = "TestButton"
.Caption = "Run New"
End With
' ********************************************************************
' Manipulate Existing Button Looping Through Button Objects
' ********************************************************************
For Each btnButton In wksButtonSheet.Buttons
Debug.Print btnButton.Name
Debug.Print btnButton.Caption
Debug.Print btnButton.Font.Name
Debug.Print btnButton.Font.Color
Next btnButton
End Sub