Number or String

docm24

New Member
Joined
Apr 27, 2016
Messages
4
I'm hoping someone can decipher this for me. I was testing a cell in VBA using the IsNumeric function. Most of the time it was working fine, but when it tested the cell that contained "1d3", it returned true stating that the cell contained a number. It seemed like I could change the numbers in that cell to any number, but having the center character as a 'd' caused it to return true in the IsNumeric function. The same happened if I used an 'e'. The 'e' I get a little bit more because Excel could be misinterpreting that to be scientific notation. But with the 'd', I am at a loss.

Can anyone help clue me in?

Thanks,
Doc
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
From a previous post of mine (your problem is highlighted in blue below)...

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
 
Last edited:
Upvote 0
I never knew that. But with some testing, it turns out that d means decimal places. typing msgbox 1d3 or msgbox 1D3 into my immediate window I can see 1000 returned to me. 1d5 = 100000

1D-2 is also numeric and means .01

The exact same result for e and E. I do not know why excel needs two bits of identical mathematical notation... And I imagine this could be frustrating when you are trying to test for 3-length strings or 3 digit numbers.
 
Upvote 0
I never knew that. But with some testing, it turns out that d means decimal places. typing msgbox 1d3 or msgbox 1D3 into my immediate window I can see 1000 returned to me. 1d5 = 100000

1D-2 is also numeric and means .01

The exact same result for e and E. I do not know why excel needs two bits of identical mathematical notation... And I imagine this could be frustrating when you are trying to test for 3-length strings or 3 digit numbers.
Its a cross platform historical legacy notation.

Back in the day, when I was programming Fortran using punch cards, there was something called Double Precision. The notation was the same as exponential notation, except with a D instead of an E.

Apparently Excel recognizes that old numeric notation. Yes 1D-02 = 1E-02 = .01
 
Upvote 0
I guess you could use the Worksheet function IsNumber to give a more accurate result in your case of values like 1d3...
 
Upvote 0
In VBA, you could test with something like

Code:
If aString Like "[0-9][0-9][0-9]" Then
    MsgBox "aString is a three digit numeral"
ElseIf aString Like "*[!0-9]*" Then
    MsgBox "aString has at least one non numeric character"
End If
 
Upvote 0
I guess you could use the Worksheet function IsNumber to give a more accurate result in your case of values like 1d3...
I like using the Like operator...

Code:
If Not MyValue Like "*[!0-9]*" Then
   ' MyValue is all digits
Else
  ' MyValue contains a non-digit
End If

or alternately...

Code:
If MyValue Like String(Len(MyValue), "#") Then
  ' MyValue is all digits
Else
  ' MyValue contains a non-digit
End If
 
Upvote 0
Rick, Mike, Tiger; thank you all for the input. I stumbled upon by mere coincidence while trying to verify that UPC codes were all numeric. The codes will always be long enough to avoid this situation, but this is all great knowledge to have for the future.

Thanks again and I hope you all have a great weekend!
Doc
 
Upvote 0

Forum statistics

Threads
1,216,075
Messages
6,128,662
Members
449,462
Latest member
Chislobog

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