Create multiple checkboxes instantly with VBA

Checkboxes placed onto the face of the worksheet are an excellent way for users to interact with a spreadsheet.  Each checkbox can be linked to a cell, so that when clicked the value in the cell changes between TRUE and FALSE.

But if you have a lot of checkboxes to create it becomes a real pain; there are just too many settings to set for each checkbox. If I have to create more than 2, then I’m groaning inside because of the inefficient process to set-up each box individually.

So I created some VBA to use in my Personal Macro Book.  When the macro runs it will create, link, unlock and align as many checkboxes as I need in seconds!  That makes me happy 🙂

How the VBA code works

When the VBA code below is run it will display two Input Boxes.

From the first Input Box select the range of cells in which to create the checkboxes, then click OK.  In the screenshot below, it will create 30 checkboxes, being one in each cell from A1 – C10.

Create Checkboxes - Select Range

The second Input Box (shown below) will set the default value.

  • True or 1 = Checked
  • False or 0 = Unchecked

Once completed click OK.

Create Checkboxes - Default Value

The macro will now create all the checkboxes, a fantastic time saver.

Create Checkboxes - After

Be warned; if you select a large range (such as an entire column or row), it might take some time as Excel is creating the checkboxes one by one.

The VBA Code – create multiple checkboxes

Copy the following code into a standard module, then run the macro entitled CreateCheckBoxes.

Sub CreateCheckBoxes()

'Declare variables
Dim c As Range
Dim chkBox As CheckBox
Dim ansBoxDefault as Long
Dim chkBoxRange As Range
Dim chkBoxDefault As Boolean

'Ingore errors if user clicks Cancel or X
On Error Resume Next

'Use Input Box to select cells
Set chkBoxRange = Application.InputBox(Prompt:="Select cell range", _
    Title:="Create checkboxes", Type:=8)

'Exit the code if user clicks Cancel or X
If Err.Number <> 0 Then Exit Sub

'Use MessageBox to select checked or unchecked
ansBoxDefault = MsgBox("Should the boxes be checked?", vbYesNoCancel, _
    "Create checkboxes")
If ansBoxDefault = vbYes Then chkBoxDefault = True
If ansBoxDefault = vbNo Then chkBoxDefault = False
If ansBoxDefault = vbCancel Then Exit Sub

'Turn error checking back on
On Error Goto 0

'Loop through each cell in the selected cells
For Each c In chkBoxRange

    'Create the checkbox
    Set chkBox = chkBoxRange.Parent.CheckBoxes.Add(0, 1, 1, 0)

    With chkBox

        'Set the position of the checkbox based on the cell
        .Top = c.Top + c.Height / 2 - chkBox.Height / 2
        .Left = c.Left + c.Width / 2 - chkBox.Width / 2

        'Set the name of the checkbox based on the cell address
        .Name = c.Address

        'Set the linked cell to the cell with the checkbox
        .LinkedCell = c.Offset(0, 0).Address(external:=True)

        'Enable the checkBox to be used when worksheet protection applied
        .Locked = False

        'Set the caption to blank
        .Caption = ""

    End With

    'Set the cell to the default value
    c.Value = chkBoxDefault

    'Hide the value in the cell with Number Formatting
    c.NumberFormat = ";;;"

Next c

End Sub

In the code above I have assumed certain settings:

  • The caption should be blank, as I normally use the cell next to the checkbox as the caption.
  • The checkbox is not locked, therefore when the worksheet is protected the checkbox will still function.
  • The name of the checkbox is the address of the cell in which it sits.
  • The linked cell is the same as the cell containing the checkbox, but the number format will hide the value form the user.
  • The location of the checkbox is centered in the cell.

The VBA Code – Delete multiple checkboxes

Having created a lot of checkboxes, the next problem you could face is how to delete a lot of checkboxes.

Delete all the checkboxes

The following VBA code will delete all the checkboxes on the active sheet.

Sub DeleteAllCheckBoxes()

ActiveSheet.CheckBoxes.Delete

End Sub

Whilst this will delete all the checkboxes, it will not remove the value from the linked cell.  Therefore the following macro may be more appropriate.

Delete some checkboxes

If you only want to delete some checkboxes, then the following VBA code will do the trick.  An Input Box will ask for a range of cells; these are the cells from which the checkboxes will be deleted.

Sub DeleteCheckBoxesInRange()

'Create variables
Dim c As Range
Dim chkBox As CheckBox
Dim chkBoxRange As Range

'Ingore errors if user clicks Cancel or X
On Error Resume Next

'Use Input Box to select cells
Set chkBoxRange = Application.InputBox(Prompt:="Select cell range:", _
    Title:="Delete checkboxes", Type:=8)

'Exit the code if user clicks Cancel or X
If err.Number <> 0 Then Exit Sub

'Turn error checking back on
On Error Goto 0
'Look through each checkbox
For Each chkBox In chkBoxRange.Parent.CheckBoxes

    'Delete checkbox where the cell containing the checkbox intersects 
    with the selected range
    If Not Application.Intersect(Range(chkBox.TopLeftCell.Address), _
        chkBoxRange) Is Nothing Then

        'Clear the linked cell including formatting
        chkBox.Parent.Range(chkBox.LinkedCell).Value = ""
        chkBox.Parent.Range(chkBox.LinkedCell).NumberFormat = "General"

        'Delete the check box
        chkBox.Delete

    End If

Next chkBox

End Sub

Note: In the macro above it is the top left pixel of the checkbox which determines it’s location.  Even if the checkbox overspills into multiple cells, from a VBA perspective it is only within the cell containing to top left pixel.


Discover how you can automate your work with our Excel courses and tools.

Excel Academy

Excel Academy
The complete program for saving time by automating Excel.

Excel Automation Secrets

Excel Automation Secrets
Discover the 7-step framework for automating Excel.

Office Scripts Course

Office Scripts: Automate Excel Everywhere
Start using Office Scripts and Power Automate to automate Excel in new ways.

16 thoughts on “Create multiple checkboxes instantly with VBA”

  1. Excel VBA:

    If I select all the child check box then parent check box should automatically get select.

    If any one of the child check box is Unchecked then parent check box get unchecked automatically

    Please help me with VBA code.

    Reply
  2. Great Script…. Downloaded and was perfect. Many Thanks!!!
    However, something wrong with the line “If Err.Number 0 And chkBoxDefault = “” Then Exit Sub.”
    I dont know why. I just deleted it and the rest is what I need.

    Reply
    • Thanks David – It’s caused by the True/False nature of closing the Inputbox. I have now updated the post to use message box to select the Checked/Unchecked option.

      Reply
  3. The check boxes are coming up only half a box? What part of the code do I need to modify? I tried even on large cells but still comes up very small and have to right click and drag each one to increase size.

    Reply
        • Hi Kate – I’ve no longer got a version of Excel 2016. But I’ve not been able to re-create the problem on PC or Mac on Excel 365.

          What happens if you create checkboxes normally? Do they appear the correct size?

          Does anybody else have this issue, or can advise what causes it?

          Reply
          • Hello!
            Thank you for your reply!
            When I’m creating checkbox normally, the place where you put a tick is extremely small. I was asked to larger this “window”, but I have no idea where/ how to do it (of course I can play with zoom level, but it’s not the solution that I’m looking for). Example: text in checkbox is 16 and window when you click a tick is about 2mmx2mm .
            In the end maybe I’ll install on my Mac Excel 365 and there give a try 🙂

      • Thanks Kenneth.

        Unfortunately, somebody else will then want the macro to not select the checkboxes. With a bit of investigation, I’m sure you’ll be able to add this to your version of the macro. 🙂

        Reply
  4. This is sooo good. I’ve looked at a dozen other examples of adding multiple checkboxes. This is the best I’ve found and it’s great.

    Reply

Leave a Comment