userform textbox validation not longer working

jacobrcotton

Board Regular
Joined
Jan 28, 2017
Messages
51
Hi,

This code was working this morning! I don't know where I've broken it.

this is a different problem, but using the similar coding and the same project as a previous thread (https://www.mrexcel.com/forum/excel...rform-textbox_change-call-validation-sub.html)

My current code below is taking the input from a TextBox and running it through a series of validation tests. The first test is titled IsNumericTest and (surprise surprise) it is testing that the Textbox input is nonNull & is a number However, I can't seem to get the MsgBox to trigger (unless i comment out the With & If coding, basically forcing the MsgBox to appear without criteria). I've narrowed this down to something wrong with my .ActiveControl and the .Value coding, but I dont know what is actually wrong.


I can get the code to work by directly referencing the input textbox as "IndDedINN.Value", but this defeats the purpose as I need to run multiple TextBoxes through the same IsNumericTest validation.

*Note that I have several of the validation tests (ie, NotLessThanZeroTest, LessThanMaximumTest, etc) that are all exhibiting the same problem.

Code:
Private Sub IndDedINN_AfterUpdate()
  
     IsNumericTest


End Sub

Private Sub IsNumericTest()
    If TypeName(Me.ActiveControl) = "TextBox" Then
        With Me.ActiveControl
            If Not IsNumeric(.Value) And .Value <> vbNullString Then
                MsgBox "Numeric Values Only" & vbNewLine & vbNewLine & "TEST: IsNumericTest"
                .Value = vbNullString
            End If
         End With
     End If
End Sub


Thoughts?
 

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.
Why not pass the textbox to the validation sub?
Code:
Private Sub IndDedINN_AfterUpdate()
  
     IsNumericTest IndDedINN


End Sub

Private Sub IsNumericTest(ctl As MSForms.Control)
    If TypeName(ctl) = "TextBox" Then
        With ctl
            If Not IsNumeric(.Value) And .Value <> vbNullString Then
                MsgBox "Numeric Values Only" & vbNewLine & vbNewLine & "TEST: IsNumericTest"
                .Value = vbNullString
            End If
         End With
     End If
End Sub
 
Upvote 0
The code above works and seems to be a usable solution, so I'll move forward with this. But why is the original coding NOT working?
 
Upvote 0
Hard to tell, but could it be that ActiveControl isn't what you think it is?
 
Upvote 0
From a previous post of mine...

I usually try and steer people away from using IsNumeric to "proof" supposedly numeric text. Consider this (also see note below):

Code:
ReturnValue = IsNumeric("($1,23,,3.4,,,5,,E67$)")

Most people would not expect THAT to return True. IsNumeric has some "flaws" in what it considers a proper number and what most programmers are looking for.

I had a short tip published by Pinnacle Publishing in their Visual Basic Developer magazine that covered some of these flaws. Originally, the tip was free to view but is now viewable only by subscribers.. Basically, it said that IsNumeric returned True for things like -- currency symbols being located in front or in back of the number as shown in my example (also applies to plus, minus and blanks too); numbers surrounded by parentheses as shown in my example (some people use these to mark negative numbers); numbers containing any number of commas before a decimal point as shown in my example; numbers in scientific notation (a number followed by an upper or lower case "D" or "E", followed by a number equal to or less than 307 -- the maximum power of 10 in VB); and Octal/Hexadecimal numbers (&H for Hexadecimal, &O or just & in front of the number for Octal).

NOTE:
======
In the above example and in the referenced tip, I refer to $ signs and commas and dots -- these were meant to refer to your currency, thousands separator and decimal point symbols as defined in your local settings -- substitute your local regional symbols for these if appropriate.

As for your question about checking numbers, here are two functions that I have posted in the past for similar questions..... one is for digits only and the other is for "regular" numbers (the code is simple enough that it can be pulled from the function "housing" and used directly inside your own code):

Code:
Function IsDigitsOnly(Value As String) As Boolean
    IsDigitsOnly = Len(Value) > 0 And Not Value Like "*[!0-9]*"
End Function

Function IsNumber(ByVal Value As String) As Boolean
    '   Leave the next statement out if you don't
    '   want to provide for plus/minus signs
    If Value Like "[+-]*" Then Value = Mid$(Value, 2)
    IsNumber = Not Value Like "*[!0-9.]*" And Not Value Like "*.*.*" And Len(Value) > 0 And Value <> "."
End Function

Here are revisions to the above functions that deal with the local settings for decimal points (and thousand's separators) that are different than used in the US (this code works in the US too, of course).

Code:
Function IsNumber(ByVal Value As String) As Boolean
  Dim DP As String
  '   Get local setting for decimal point
  DP = Format$(0, ".")
  '   Leave the next statement out if you don't
  '   want to provide for plus/minus signs
  If Value Like "[+-]*" Then Value = Mid$(Value, 2)
  IsNumber = Not Value Like "*[!0-9" & DP & "]*" And Not Value Like "*" & _
             DP & "*" & DP & "*" And Len(Value) > 0 And Value <> DP
End Function

I'm not as concerned by the rejection of entries that include one or more thousand's separators, but we can handle this if we don't insist on the thousand's separator being located in the correct positions (in other words, we'll allow the user to include them for their own purposes... we'll just tolerate their presence).

Code:
Function IsNumber(ByVal Value As String) As Boolean
  Dim DP As String
  Dim TS As String
  '   Get local setting for decimal point
  DP = Format$(0, ".")
  '   Get local setting for thousand's separator
  '   and eliminate them. Remove the next two lines
  '   if you don't want your users being able to
  '   type in the thousands separator at all.
  TS = Mid$(Format$(1000, "#,###"), 2, 1)
  Value = Replace$(Value, TS, "")
  '   Leave the next statement out if you don't
  '   want to provide for plus/minus signs
  If Value Like "[+-]*" Then Value = Mid$(Value, 2)
  IsNumber = Not Value Like "*[!0-9" & DP & "]*" And Not Value Like "*" & _
             DP & "*" & DP & "*" And Len(Value) > 0 And Value <> DP
End Function

Closing Note
-----------------------------
The above functions for checking if text is a number were written back in my volunteer days for the compiled version of Visual Basic and while it all still works in Excel's VBA, you could also reach out to the worksheet's ISNUMBER function and test the text for being a number that way (its probably a tad slower to do it that way, but probably not enough to worry about unless used in a huge loop of some kind).

Code:
Function IsNumber(Value) As Boolean
  IsNumber = Evaluate("ISNUMBER(0+""" & Value & """)")
End Function
 
Upvote 0

Forum statistics

Threads
1,214,974
Messages
6,122,536
Members
449,088
Latest member
RandomExceller01

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top