Adding multiple checkboxes

G

Guest

I am creating a large data entry excel spreadsheet and I want to be able to
insert, probably 100+ check boxes, my problem is that I dont want to have to
associate every single checkbox with every single cell. is there a way that I
can just click and drag (like fomulas do) and have the cells be populated by
checkboxes.

I do not want to have to right click each checkbox --> properties -->
control, and then link the value to a cell.

Please help!
 
T

T. Valko

Here's a macro by Dave Peterson:

Option Explicit
Sub addCBX()
Dim myCBX As CheckBox
Dim myCell As Range

With ActiveSheet
.CheckBoxes.Delete 'nice for testing
For Each myCell In ActiveSheet.Range("a2:a10").Cells
With myCell
Set myCBX = .Parent.CheckBoxes.Add _
(Top:=.Top, Width:=.Width, _
Left:=.Left, Height:=.Height)
With myCBX
.LinkedCell = myCell.Address(external:=True)
'.Caption = "" 'or whatever you want
'.Name = "CBX_" & myCell.Address(0, 0)
End With
.NumberFormat = ";;;"
End With
Next myCell
End With
End Sub

Change the range (set to A2:A10) as needed. The macro automatically sets the
linked cell to be the same cell the checkbox is "in". It also sets the
linked cell font format to be "invisible". If you want custom captions for
each checkbox you have to do that manually. If you want no caption "un REM"
the line:

'.Caption = "" 'or whatever you want

To:

..Caption = "" 'or whatever you want

Note: make sure the column is wide enough (about ~130 pixels) otherwise the
default caption could get truncated.

Biff
 
G

Guest

Thank you so much, this macro is awesome!

T. Valko said:
Here's a macro by Dave Peterson:

Option Explicit
Sub addCBX()
Dim myCBX As CheckBox
Dim myCell As Range

With ActiveSheet
.CheckBoxes.Delete 'nice for testing
For Each myCell In ActiveSheet.Range("a2:a10").Cells
With myCell
Set myCBX = .Parent.CheckBoxes.Add _
(Top:=.Top, Width:=.Width, _
Left:=.Left, Height:=.Height)
With myCBX
.LinkedCell = myCell.Address(external:=True)
'.Caption = "" 'or whatever you want
'.Name = "CBX_" & myCell.Address(0, 0)
End With
.NumberFormat = ";;;"
End With
Next myCell
End With
End Sub

Change the range (set to A2:A10) as needed. The macro automatically sets the
linked cell to be the same cell the checkbox is "in". It also sets the
linked cell font format to be "invisible". If you want custom captions for
each checkbox you have to do that manually. If you want no caption "un REM"
the line:

'.Caption = "" 'or whatever you want

To:

..Caption = "" 'or whatever you want

Note: make sure the column is wide enough (about ~130 pixels) otherwise the
default caption could get truncated.

Biff
 
T

T. Valko

I'll take the credit for realizing how useful it is and saving it and give
Dave due credit for writing it. Dave's the man!

Biff
 
G

Guest

Hi guys, I dont know if youll reply now that this has gotten to the 4th page.
But im noticing the check boxes start to creep up in their postition the more
I add, i want to add 30 of these checkboxes to a particular column, and the
30th is on the 29th row, it makes it hard for the user to know exactly what
they are clicking. Is there a way to clean this formatting up?

As in I have 30checkboxes in 29 rows, rather than a check box in each row
 
T

T. Valko

Hmmm.....

I've not experienced that. I tried it in various range sizes up to 200 rows
and each ckbx is positioned exactly the same in each row. I'm using the
default row height 12.75. Are all your rows the same height? Other than that
I have no other thoughts.

Biff
 
D

Dave Peterson

Just to add to Biff's thoughts. I seem to have better luck when the zoom is set
to 100%. What is your zoom set to?
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top