I have created a spreadsheet to track people who will be attending orientation. Using VBA I created some userforms hoping to ensure the integrity of the data. However, what I have found is that if they click the save or update buttons on the form and then ALSO click on the red X it will only save part of the data and the validation I built into the form is worthless. Is there a way to hide or disable the red X? The other thing I am so unsure about with VBA is exactly where to put such code to make sure it doesn't interfere with the other validation I am trying to do. I attempted to upload a sample of the workbook, but the file is too large to attach. So, here is the VBA code I have currently for adding a new person to the log:
Option Explicit
Private OLTable As ListObject
Private CurrentRow As Long
' This module inserts a new record into the OrientationLog table
Private Sub CommandButtonSave_Click()
' Initialize the OLTable variable
Set OLTable = ActiveSheet.ListObjects("OrientationLog")
' Error checking
' Make sure a first name is entered
If TextBoxFirstName.Text = "" Then
MsgBox "Please enter a first name."
TextBoxFirstName.SetFocus
Exit Sub
End If
' Make sure a last name is entered
If TextBoxLastName.Text = "" Then
MsgBox "Please enter a last name."
TextBoxLastName.SetFocus
Exit Sub
End If
' Make sure a orientation dates are entered
If ListBoxOrientationDates.Text = "" Then
MsgBox "Please select orientation dates."
ListBoxOrientationDates.SetFocus
Exit Sub
End If
' Make sure the Department was entered
If ListBoxDept.Text = "" Then
MsgBox "Please select a Department."
ListBoxDept.SetFocus
Exit Sub
End If
' Make sure the status is selected
If ListBoxStatus = "" Then
MsgBox "Please select the appropriate status."
ListBoxStatus.SetFocus
Exit Sub
End If
' Unprotect the sheet so data can be added.
ActiveSheet.Unprotect Password:="OrientationLog"
' Add a new row to the table and Insert the data into the new row
ActiveSheet.ListObjects("OrientationLog").ListRows.Add
InsertTableRow OLTable.ListRows(OLTable.ListRows.Count).Range
' Sorts the table by orientation date (Descending), last name, first name
Range("OrientationLog[[#Headers],[Human Resource Specialist]]").Select
ActiveWorkbook.Worksheets("Orientation Log").ListObjects("OrientationLog").Sort _
.SortFields.Clear
ActiveWorkbook.Worksheets("Orientation Log").ListObjects("OrientationLog").Sort _
.SortFields.Add Key:=Range("OrientationLog[Orientation Day 1]"), SortOn:= _
xlSortOnValues, Order:=xlDescending, DataOption:=xlSortNormal
ActiveWorkbook.Worksheets("Orientation Log").ListObjects("OrientationLog").Sort _
.SortFields.Add Key:=Range("OrientationLog[[Last]]"), SortOn:= _
xlSortOnValues, Order:=xlAscending, DataOption:=xlSortNormal
ActiveWorkbook.Worksheets("Orientation Log").ListObjects("OrientationLog").Sort _
.SortFields.Add Key:=Range("OrientationLog[First]"), SortOn:=xlSortOnValues _
, Order:=xlAscending, DataOption:=xlSortNormal
With ActiveWorkbook.Worksheets("Orientation Log").ListObjects("OrientationLog") _
.Sort
.Header = xlYes
.MatchCase = False
.Orientation = xlTopToBottom
.SortMethod = xlPinYin
.Apply
End With
' Protect the worksheet.
ActiveSheet.Protect Password:="OrientationLog", AllowFiltering:=True
' Close the UserForm
Unload Me
End Sub
' Insert Instructions
Private Sub InsertTableRow(TableRow As Range)
With TableRow
' Insert the data from the form into the table
.Cells(1, 2).Value = ListBoxHRStaff.Value
.Cells(1, 3).Value = ""
.Cells(1, 4).Value = ListBoxPayroll.Value
.Cells(1, 5).Value = TextBoxKronosBadge.Value
.Cells(1, 6).Value = TextBoxLastName.Value
.Cells(1, 7).Value = TextBoxFirstName.Value
.Cells(1, 8).Value = TextBoxMiddleName.Value
.Cells(1, 9).Value = TextBoxPhoneNumber.Value
.Cells(1, 10).Value = ListBoxGamComCont.Value
.Cells(1, 11).Value = ListBoxGamingStatus.Value
.Cells(1, 12).Value = ListBoxPendReason.Value
.Cells(1, 13).Value = ListBoxMMPIStatus.Value
.Cells(1, 14).Value = ListBoxTitle31Health.Value
.Cells(1, 15).Value = TextBoxTitle.Value
.Cells(1, 16).Value = ListBoxDept.Value
.Cells(1, 17).Value = TextBoxDivFac.Value
.Cells(1, 18).Value = TextBoxLocation.Value
.Cells(1, 19).Value = ListBoxStatus.Value
.Cells(1, 20).Value = ListBoxExmpt.Value
.Cells(1, 21).Value = TextBoxManager.Value
.Cells(1, 22).Value = ListBoxRehire.Value
.Cells(1, 23).Value = ListBoxOrientationDates.Value
.Cells(1, 29).Value = TextBoxGeneralNotes.Value
.Cells(1, 30).Value = TextBoxDelayedOrientation.Value
.Cells(1, 31).Value = TextBoxRecruitSource.Value
' If one day orientation is selected, then set day2 and day3 attendance to N/A
If ListBoxRehire.Value = "Yes - 1 Day Orientation" Then
.Cells(1, 26).Value = ""
.Cells(1, 27).Value = "N/A"
.Cells(1, 28).Value = "N/A"
Else
.Cells(1, 26).Value = ""
.Cells(1, 27).Value = ""
.Cells(1, 28).Value = ""
End If
End With
End Sub
' This closes the userform without saving anything
Private Sub CommandButtonCancel_Click()
Unload UserFormAddNew
End Sub
Again, I am very new to VBA and have pieced this together through different blogs and posts, so if you have suggestions for streamlining any of this, I'm open to that feedback as well.
Thank you all for your help!
Thank you! That worked!
The cited approach is nasty. All the user wants to do is get out of the dialog, and making the Red X not work punishes the user for your own poor design.
Instead, you can make clicking the Red X actually call your own close button routine.
The following is from the Repurpose the Red X Close Button on a VBA UserForm tutorial on my blog.
The close button is named btnCancel and uses this procedure (for example):
Private Sub btnCancel_Click() Me.Hide End Sub
The code that runs when the Red X is clicked is here. Note that its usual action, unloading the form, is canceled, and instead it calls the procedure above.
Private Sub UserForm_QueryClose(Cancel As Integer, CloseMode As Integer) ' how was the form closed? ' vbFormControlMenu = X in corner of title bar If CloseMode = vbFormControlMenu Then ' cancel normal X button behavior Cancel = True ' run code for click of Cancel button btnCancel_Click End If End Sub