Code Problem: Empty Text Box

Humpa

New Member
Joined
Dec 16, 2014
Messages
4
Hi,
I am fairly new to VBA, so this might be rather trivial.

I have a Userform with a Text Box to enter a number.
I want to check, if there was a number entered in the Text Box.
If a number was entered, a certain calculation is to be done with that number
If no number was entered, then this Text Box is rated with a certain grade (e.g. 10) and further calculation is to be done with that grade.

I have written the code below:

Dim A As Variant
Dim B As Variant

Private Sub btnCheck_Click()

If txtA.Text = "" Then
Msg = "You have entered no value for A. Do you want to continue?"
Ans = MsgBox(Msg, vbYesNo)
If Ans = vbNo Then Exit Sub
If Ans = vbYes Then txtA.Text = “#N/A”
End If
A = txtA.Text
If A = “#N/A” Then B = 10
If A > 0 And A <= 400 Then B = 0
If A > 400 Then B = (A - 400) * 0.1

The above does not work. If I exchange "#N/A" with a number, such as "0", then everything works fine.
However, this is not what I want. How do I assign an 'empty' Text Box to a variable?

Thanks,

H.

 
Or maybe even to this...

Code:
B = Evaluate(Replace("IF(ISNUMBER(@),0.01*MAX(0,@-400),10)", "@", txtA.Text))
EDIT:
tested, it works
It is text in the VBA world, but once placed inside the string argument to Evaluate, numbers will be unquoted so they will look like numbers to the ISNUMBER function.

Actually, no, it may work correctly in all circumstances. In thinking about the explanation I provided some more as to why a number in a TextBox would work, I got to wondering what that would mean for arbitrary text the user might type in, and discovered a problem... if the user just happened to type in text that was an existing Defined Name in the workbook, then the Evaluate function would substitute what the Defined Name was defined as in place of that text. If that Defined Name referred to a multi-cell range, my code would return an error; but if that Defined Name referred to a single cell with a value in it, that value would be substitute in place of the text and an incorrect value would result. So, I would suggest that my one-liner not be considered for use. My suggestion would be to use VBA Geek's code from Message #6, but with the IsNumeric function call replaced by one of the code lines below in this warning that I have posted before explaining why IsNumeric should not be used to "proof" a text entry as being a number...

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
 
Last edited:
Upvote 0

Excel Facts

What is the shortcut key for Format Selection?
Ctrl+1 (the number one) will open the Format dialog for whatever is selected.
hi Rick, very handy functions.

I am not sure if Microsoft has changed the algorithm of IsNumeric since you wrote your post as I am getting False from IsNumeric("($1,23,,3.4,,,5,,E67$)") ?
 
Upvote 0
hi Rick, very handy functions.

I am not sure if Microsoft has changed the algorithm of IsNumeric since you wrote your post as I am getting False from IsNumeric("($1,23,,3.4,,,5,,E67$)") ?

I originally posted that message back in the early 2000's for the compiled version of VB (everything in my message applies to VBA though), but I still get True for it. Did you see the Note I included which explains the need to substitute your locale's currency, decimal and thousands symbols in order to see the problem?
 
Upvote 0
I originally posted that message back in the early 2000's for the compiled version of VB (everything in my message applies to VBA though), but I still get True for it. Did you see the Note I included which explains the need to substitute your locale's currency, decimal and thousands symbols in order to see the problem?

that's right, sorry, I changed $ to and now I get a true as well o_O, that's one big flaw as this looks nothing like a number, also CDBL returns from it the number

Code:
-1.23345E+70
which at the end makes sense if IsNumeric returns TRUE
 
Upvote 0
that's right, sorry, I changed $ to and now I get a true as well o_O, that's one big flaw as this looks nothing like a number, also CDBL returns from it the number

Code:
-1.23345E+70
which at the end makes sense if IsNumeric returns TRUE

Yes, IsNumeric returns True if one of the convert functions can determine it to be a number... the caution in my posting was a little more directed... users use a TextBox to take in what they expect to be a number, and assume if IsNumeric says it is a number, then it must consist of only digits and optionally a decimal point with or without thousands separators... my posting was to show that is not exactly the case. One place someone making that assumption can get in trouble is if they want the inputted number to be, say, 3 digits long and their subsequent code depends on this fact. So they set the maximum number of characters to 3, test to make sure the entry has no decimal point and "proof" the entry with IsNumeric... then the user enters 9E9 and BOOM!, the program crashes... or worse yet, doesn't crash, but rather calculates a result using a value that is completely out-of-bounds.
 
Upvote 0

Forum statistics

Threads
1,215,338
Messages
6,124,358
Members
449,155
Latest member
ravioli44

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