VBA to Validate Data

PosieQ

New Member
Joined
Mar 14, 2017
Messages
8
Hello,

I am a true beginner to VBA and would like some help in creating a macro that is triggered when the user goes to save the document. The document contains a check box and, if checked, cell B28 will show TRUE. If the check box is checked, the user is expected to enter additional information in B30. I would like to create a macro with the following conditions so that a message appears when the user tries to save the document:

If B28 is TRUE and B30 is blank, show the message "Please enter a number in B30".

Please let me know if I have not provided enough information. Thank you in advance!
 

JLGWhiz

Well-known Member
Joined
Feb 7, 2012
Messages
11,253
Office Version
2013
Platform
Windows
Copy the code below and paste it into your ThisWorkbook code module. To access the code module, press Alt + F11 amd when the vb editor opens, double click "ThisWorkbook" in the small Project pane at upper left of the vb Editor window. Check the upper margin of the vb Editor window to be sure ThisWorkbook (Code) appears there. Then paste the code into the large code pane. Close the editor and save the workbook as a macro enabled workbook (.xlsm) to preserve the code.

Code:
Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, Cancel As Boolean)
If ActiveSheet.Range("B28").Value = True And ActiveSheet.Range("B30") = "" Then
    MsgBox "Cell B30 is a required entry when cell B28 is True"
    Cancel = True
End If
End Sub
 

PosieQ

New Member
Joined
Mar 14, 2017
Messages
8
Thank you, JLGWHiz! This worked perfectly, and I really appreciate your thorough instructions! One question I didn't think of before. After the message pops up that B30 is required, if I wanted to give the user the option of continuing to save without entering anything in B30 (so B3 would not be a required field), how does the code change?
 

JLGWhiz

Well-known Member
Joined
Feb 7, 2012
Messages
11,253
Office Version
2013
Platform
Windows
Thank you, JLGWHiz! This worked perfectly, and I really appreciate your thorough instructions! One question I didn't think of before. After the message pops up that B30 is required, if I wanted to give the user the option of continuing to save without entering anything in B30 (so B3 would not be a required field), how does the code change?
Try this
Code:
Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, Cancel As Boolean)
Dim ans As Variant
If ActiveSheet.Range("B28").Value = True And ActiveSheet.Range("B30") = "" Then
    ans = MsgBox("Cell B30 is a required entry when cell B28 is True.  Do you want to save the file anyway?", _
        vbQuestion + vbYesNo, "OPTION")
        If ans = vbNo Then
            Cancel = True
        End If
End If
End Sub
 

PosieQ

New Member
Joined
Mar 14, 2017
Messages
8
This, too, did the trick! Thank you so much for your help and for the quick response!
 

PosieQ

New Member
Joined
Mar 14, 2017
Messages
8
Try this
Code:
Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, Cancel As Boolean)
Dim ans As Variant
If ActiveSheet.Range("B28").Value = True And ActiveSheet.Range("B30") = "" Then
    ans = MsgBox([COLOR=#FF0000]"Cell B30 is a required entry when cell B28 is True.  Do you want to save the file anyway?"[/COLOR], _
        vbQuestion + vbYesNo, "OPTION")
        If ans = vbNo Then
            Cancel = True
        End If
End If
End Sub

I made a change to the text in the message box (in red font above) to the following but am getting the error message "Compile error: Expected list separator or)". What am I doing wrong?

Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, Cancel As Boolean)
Dim ans As Variant
If ActiveSheet.Range("B28").Value = True And ActiveSheet.Range("B30") = "" Then
ans = MsgBox("A Prime's Prime Number is required when the role 'Subcontractor" is checked. If number was provided, please enter 'TBD' or 'N/A' as appropriate. Do you want to save the file anyway?", _
vbQuestion + vbYesNo, "OPTION")
If ans = vbNo Then
Cancel = True
End If
End If
End Sub

Also, if I wanted to add a two carriage returns so that "Do you want to save the file anyway?" is on a separate line, how is that done?

Thank you.
 

MrIfOnly

Active Member
Joined
Nov 10, 2016
Messages
489
PosieQ:

You are getting the error because you have a quote mark after the word Subcontractor. Change that to '.

Also, if I wanted to add a two carriage returns so that "Do you want to save the file anyway?" is on a separate line, how is that done?
Code:
ans = MsgBox("A Prime's Prime Number is required when the role 'Subcontractor' is checked. If number was provided, please enter 'TBD' or 'N/A' as appropriate." _
& vbNewLine & vbNewLine & "Do you want to save the file anyway?", _
vbQuestion + vbYesNo, "OPTION")
Regards,

CJ
 

PosieQ

New Member
Joined
Mar 14, 2017
Messages
8
PosieQ:

You are getting the error because you have a quote mark after the word Subcontractor. Change that to '.



Code:
ans = MsgBox("A Prime's Prime Number is required when the role 'Subcontractor' is checked. If number was provided, please enter 'TBD' or 'N/A' as appropriate." _
& vbNewLine & vbNewLine & "Do you want to save the file anyway?", _
vbQuestion + vbYesNo, "OPTION")
Regards,

CJ

CJ, thank you for catching the double quotes!

Your change works perfectly according to the conditions I provided, but I see now that I needed to provide more specifics. I thought that by clicking ‘No’ the user would be returned to the document, but instead the document completely closes. Can the code be changed so that the user is returned to the document when ‘No’ is clicked?

Also, rethinking this a little differently now, can the ‘Yes’ button be changed to ‘Continue Saving’ and ‘No’ changed to ‘Return to Document’?

I appreciate all your help!
 

MrIfOnly

Active Member
Joined
Nov 10, 2016
Messages
489
To prevent closing use the following code which used the BeforeClose event instead of the BeforeSave event:

Code:
Private Sub Workbook_BeforeClose(Cancel As Boolean)
Dim ans As Variant
    If ActiveSheet.Range("A1").Value = True And ActiveSheet.Range("B2") = "" Then
        ans = MsgBox("A Prime's Prime Number is required when the role 'Subcontractor' is checked. If number was provided, please enter 'TBD' or 'N/A' as appropriate." _
        & vbNewLine & vbNewLine & "Do you want to close the file anyway?", _
        vbQuestion + vbYesNo, "OPTION")
            If ans = vbNo Then
                Cancel = True
            End If
    End If
End Sub

Also, rethinking this a little differently now, can the ‘Yes’ button be changed to ‘Continue Saving’ and ‘No’ changed to ‘Return to Document’?
Not with the standard msgbox, but you can create a userform with your message and commandbuttons with those captions.

CJ
 

Forum statistics

Threads
1,081,527
Messages
5,359,295
Members
400,524
Latest member
Excelbat

Some videos you may like

This Week's Hot Topics

  • VBA (Userform)
    Hi All, I just would like to know why my code isn't working. Here is my VBA code: [CODE=vba]Private Sub OKButton_Click() Dim i As Integer...
  • List box that changes fill color
    Hello, I have gone through so many pages trying to figure this out. I have a 2020 calendar that depending on the day needs to have a certain...
  • Remove duplicates and retain one. Cross-linked cases
    Hi all I ran out of google keywords to use and still couldn't find a reference how to achieve the results of a single count. It would be great if...
  • VBA Copy and Paste With Duplicates
    Hello All, I'm in need of some input. My VBA skills are sub-par at best. I've assembled this code from basic research and it works but is...
  • Macro
    is it possible for a macro to run if the active cell value is different to the value above it
  • IF DATE and TIME
    I currently use this to check if date has passed but i also need to set a time on it too. Is it possible? [CODE=vba]=IF(B:B>TODAY(),"Not...
Top