• Skip to main content
  • Skip to header right navigation
  • Skip to site footer

My Online Training Hub

Learn Dashboards, Excel, Power BI, Power Query, Power Pivot

  • Courses
  • Pricing
    • SALE 20% Off All Courses
    • Free Courses
    • Power BI Course
    • Excel Power Query Course
    • Power Pivot and DAX Course
    • Excel Dashboard Course
    • Excel PivotTable Course – Quick Start
    • Advanced Excel Formulas Course
    • Excel Expert Advanced Excel Training
    • Excel Tables Course
    • Excel, Word, Outlook
    • Financial Modelling Course
    • Excel PivotTable Course
    • Excel for Customer Service Professionals
    • Multi-User Pricing
  • Resources
    • Free Downloads
    • Excel Functions Explained
    • Excel Formulas
    • Excel Add-ins
    • IF Function
      • Excel IF Statement Explained
      • Excel IF AND OR Functions
      • IF Formula Builder
    • Time & Dates in Excel
      • Excel Date & Time
      • Calculating Time in Excel
      • Excel Time Calculation Tricks
      • Excel Date and Time Formatting
    • Excel Keyboard Shortcuts
    • Excel Custom Number Format Guide
    • Pivot Tables Guide
    • VLOOKUP Guide
    • ALT Codes
    • Excel VBA & Macros
    • Excel User Forms
    • VBA String Functions
  • Members
    • Login
    • Logout
    • Password Reset
  • Blog
  • Excel Webinars
  • Excel Forum
    • Register as Forum Member

Hide and/or disable the red X to close a Userform|VBA & Macros|Excel Forum|My Online Training Hub

You are here: Home / Hide and/or disable the red X to close a Userform|VBA & Macros|Excel Forum|My Online Training Hub

sale now on

Avatar
sp_LogInOut Log In sp_Registration Register
sp_Search Search
Advanced Search
Search
Forum Scope




Match



Forum Options



Minimum search word length is 3 characters - maximum search word length is 84 characters
sp_Search Search
sp_RankInfo
Lost password?
sp_CrumbsHome HomeExcel ForumVBA & MacrosHide and/or disable the red X to cl…
sp_PrintTopic sp_TopicIcon
Hide and/or disable the red X to close a Userform
Avatar
Pam Simpson
Oklahoma
Member
Members

Dashboards

Power Pivot
Level 0
Forum Posts: 20
Member Since:
June 25, 2016
sp_UserOfflineSmall Offline
1
September 20, 2017 - 4:37 am
sp_Permalink sp_Print

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. Wink

Thank you all for your help!

sp_AnswersTopicSeeAnswer See Answer
Avatar
Anders Sehlstedt
Eskilstuna, Sweden

VIP
Members


Trusted Members
Level 3
Forum Posts: 858
Member Since:
December 7, 2016
sp_UserOfflineSmall Offline
2
September 20, 2017 - 8:50 am
sp_Permalink sp_Print

Hello,

I found this tip from a search engine.

Br,

Anders

Avatar
Pam Simpson
Oklahoma
Member
Members

Dashboards

Power Pivot
Level 0
Forum Posts: 20
Member Since:
June 25, 2016
sp_UserOfflineSmall Offline
3
September 21, 2017 - 8:17 am
sp_Permalink sp_Print

Thank you!  That worked! Laugh

Avatar
Jon Peltier
Member
Members
Level 0
Forum Posts: 9
Member Since:
November 17, 2017
sp_UserOfflineSmall Offline
4
November 18, 2017 - 12:23 am
sp_Permalink sp_Print sp_EditHistory

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
sp_AnswersTopicAnswer
Answers Post
sp_Feed
Go to top
Forum Timezone: Australia/Brisbane
Most Users Ever Online: 170
Currently Online: Jose Molina, Dieneba NDIAYE
Guest(s) 113
Currently Browsing this Page:
2 Guest(s)
Top Posters:
SunnyKow: 1432
Anders Sehlstedt: 858
Velouria: 580
Purfleet: 412
Frans Visser: 346
David_Ng: 306
lea cohen: 214
A.Maurizio: 202
Aye Mu: 201
Jessica Stewart: 189
Newest Members:
Richard Adams
Vincent Starcevich
Patrick Lawrence
Louise Bell
GIJO GEORGE
Kumud Patel
Atos Franzon
Andrew MacDonald
Artie Ball
Jenn Cain
Forum Stats:
Groups: 3
Forums: 24
Topics: 6079
Posts: 26684

 

Member Stats:
Guest Posters: 49
Members: 31571
Moderators: 2
Admins: 4
Administrators: Mynda Treacy, Philip Treacy, Catalin Bombea, FT
Moderators: MOTH Support, Riny van Eekelen
© Simple:Press —sp_Information

Sidebar

Blog Categories

  • Excel
  • Excel Charts
  • Excel Dashboard
  • Excel Formulas
  • Excel PivotTables
  • Excel Shortcuts
  • Excel VBA
  • General Tips
  • Online Training
  • Outlook
  • Power Apps
  • Power Automate
  • Power BI
  • Power Pivot
  • Power Query
trustpilot excellent rating
 

Company

  • About My Online Training Hub
  • Disclosure Statement
  • Frequently Asked Questions
  • Guarantee
  • Privacy Policy
  • Terms & Conditions
  • Testimonials
  • Become an Affiliate

Support

  • Contact
  • Forum
  • Helpdesk - For Technical Issues

Copyright © 2023 · My Online Training Hub · All Rights Reserved

Microsoft and the Microsoft Office logo are trademarks or registered trademarks of Microsoft Corporation in the United States and/or other countries. Product names, logos, brands, and other trademarks featured or referred to within this website are the property of their respective trademark holders.