Adding a checkbox to new row, and checking or unchecking it

mharper90

Board Regular
Joined
May 28, 2013
Messages
111
Office Version
  1. 365
Platform
  1. MacOS
I have UserForm1 that adds a new row of data to ws1 based on the data submitted in the UserForm. In column "E" of this new row, I'm trying to get the UserForm1, CommandButton1 click macro to add a checkbox to the empty cell, center it within the cell, and then use the value of Userform1.Checkbox2 to either check or uncheck the newly inserted checkbox. Greatly appreciate the help! Also, is there a way to control the size of the inserted checkbox via macro to ensure it's scaled proportional to the rest of the worksheet?
 

Some videos you may like

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
12,593
Office Version
  1. 2007
Platform
  1. Windows
Check the 2 options for Form Checkbox or for ActiveX checkbox Control


Code:
Private Sub CommandButton1_Click()
    Dim lastRow As Double
    Dim sh As Worksheet, nombre As String
    
    Set sh = Sheets("Sheet1")
    lastRow = sh.Range("A" & Rows.Count).End(xlUp).Row + 1
    
    With sh.Range("E" & lastRow)


[COLOR=#0000ff]        'Form checkbox[/COLOR]
        sh.CheckBoxes.Add(.Left + 1, .Top + 1, .Width - 1, .Height - 1).Select
        Selection.Value = Me.CheckBox1.Value
        Selection.Caption = ""


    End With


    With sh.Range("F" & lastRow)
        
[COLOR=#0000ff]        'ActiveX checkbox Control[/COLOR]
        sh.OLEObjects.Add(ClassType:="Forms.CheckBox.1", Link:=False, _
            DisplayAsIcon:=False, Left:=.Left + 1, Top:=.Top + 1, Width:=.Width - 1, Height:=.Height - 1).Select
            nombre = Selection.Name
        sh.OLEObjects(nombre).Object.Caption = ""
        sh.OLEObjects(nombre).Object.Value = Me.CheckBox1.Value
        
    End With
    
End Sub
 

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,785
Perhaps
Code:
Private Sub CommandButton1_Click()
    Dim newRow As Range, ECell As Range
    Dim newBox As CheckBox
   
    Set newRow = Sheet1.Cells(Rows.Count, 1).End(xlUp).EntireRow: adjust to match
    
    Set ECell = newRow.Range("E1")
    
    With ECell
        Set newBox = newRow.Parent.CheckBoxes.Add(.Left, .Top, 100, .Height)
    End With
    With newBox
        .Caption = vbNullString
        .Width = 10
        .Left = ECell.Left + (ECell.Width / 2) - (.Width / 4)
        .LinkedCell = ECell.Address
        .Value = Me.CheckBox2.Value
    End With
    Application.ScreenUpdating = True
End Sub
 

mharper90

Board Regular
Joined
May 28, 2013
Messages
111
Office Version
  1. 365
Platform
  1. MacOS
I used the "Form Checkbox" version. Can you explain why I should choose one over the other? It works great, except that it doesn't seem to be "stuck" to the cell I entered it into. By this, I mean that if I hide or delete a row, the checkbox just sits there. Is there a way to treat it the same way a cell with text or something would be treated for those actions?

Check the 2 options for Form Checkbox or for ActiveX checkbox Control


Code:
Private Sub CommandButton1_Click()
    Dim lastRow As Double
    Dim sh As Worksheet, nombre As String
    
    Set sh = Sheets("Sheet1")
    lastRow = sh.Range("A" & Rows.Count).End(xlUp).Row + 1
    
    With sh.Range("E" & lastRow)


[COLOR=#0000ff]        'Form checkbox[/COLOR]
        sh.CheckBoxes.Add(.Left + 1, .Top + 1, .Width - 1, .Height - 1).Select
        Selection.Value = Me.CheckBox1.Value
        Selection.Caption = ""


    End With

End Sub
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
12,593
Office Version
  1. 2007
Platform
  1. Windows
I used the "Form Checkbox" version. Can you explain why I should choose one over the other?



Each control has different characteristics, however, the ActiveX has more properties than the userform, there is no rule that tells us which one you should choose, you simply choose the one that suits your needs; As you gain experience, you will be able to know which one you need for each occasion.

Is there a way to treat it the same way a cell with text or something would be treated for those actions?

There is no way to treat it like a row, if you delete a row, you will also have to eliminate the control.


However, in the ActiveX, there is the property "Move and change size with cells"



You can perform tests with both and analyze which one is most useful to you.
 

Watch MrExcel Video

Forum statistics

Threads
1,109,421
Messages
5,528,676
Members
409,829
Latest member
CFreeamaz

This Week's Hot Topics

  • Change military grades into rank
    Afternoon all Need help with formula that will change military rank (i.e. 1, 2, 3 into Amn, A1C, SrA). Running IF formula that does not work...
  • VBA COUNTIF SOLUTION
    Hi The following are the errors spread across the several columns from E to Q ie. 13 columns across several sheets with more than 500 rows per...
  • INSERT ROW WITH SPECIFIS TEXT IN A COLUMN
    Hi All! How can identify that that the row to be inserted has to be inserted before 1st row with specific text in column F. If I record the...
  • Auto-Create a monthly Sign in sheet for preschool students
    The image below is what each page looks like. Above is space for the "Child Name" "Month" "Class" School days are obviously Monday-Friday but...
  • VBA vlookup multiple results
    Hi folks, Hopefully someone out there can help. I have a list to vlookup which works (ish). the lookup only picks up the first instance of the...
  • Extract values for earliest/latest times
    I am trying to put together a formula to get the earliest start time, the latest end time from column A for each person in Column B-F without the...
Top