Written by Allen Wyatt (last updated June 21, 2018)
This tip applies to Excel 97, 2000, 2002, and 2003
Brenda is interested in knowing the number of significant digits in a value. She wonders if there is an Excel function or formula she can use that would return the number of significant digits in the value shown in a cell.
This question is not as simple as it seems. For some people, finding the number of digits in a value, less any decimal points or negative signs. If that is all you need, then something like this formula will work just fine:
=IF(A1<0,IF(A1=INT(A1),LEN(A1)-1,LEN(A1)-2),IF(INT(A1)=A1,LEN(A1),LEN(A1)-1))
The reason that this isn't that simple, however, is because what constitutes the number of significant digits in a value depends on many things. The bottom line is that you can't always tell by looking at a value how many significant digits it has.
For instance, the value 100 could have 1, 2, or 3 significant digits. It is presumed that the value 1.00 has 3 significant digits, but that may not be the case if the value displayed is the result of formatting imposed by Excel—for instance, the value in the cell could be 1.0000437, which Excel formats as 1.00. You can discover more about the topic of significant digits here:
http://excel.tips.net/T001983
There are some generally accepted ways to identify significant digits in a number, but any attempt to codify a set of rules is always open to debate. One such set of rules has been noted at Wikipedia, in the "Identifying Significant Digits" section of this article:
http://en.wikipedia.org/wiki/Significant_figures
With at least a rudimentary set of rules in mind (such as the one in the Wikipedia article) it is possible to develop a user-defined function that will give you the most likely number of significant digits for a value.
Function SigFigs(rng As Range, Optional iType As Integer = 1) 'iType = 1 is Min 'iType = 2 is Max Dim rCell As Range Dim sText As String Dim sText2 As String Dim iMax As Integer Dim iMin As Integer Dim iDec As Integer Dim i As Integer Application.Volatile Set rCell = rng.Cells(1) 'if not a number then error If Not IsNumeric(rCell) Or IsDate(rCell) Then SigFigs = CVErr(xlErrNum) Exit Function End If sText2 = Trim(rCell.Text) sText = "" 'find position of decimal point (it matters) iDec = InStr(sText2, ".") 'strip out any non-numbers (including decimal point) For i = 1 To Len(sText2) If Mid(sText2, i, 1) >= "0" And _ Mid(sText2, i, 1) <= "9" Then _ sText = sText & Mid(sText2, i, 1) Next 'remove any leading zeroes (they don't matter) While Left(sText, 1) = "0" sText = Mid(sText, 2) Wend iMax = Len(sText) 'strip trailing zeroes (they don't matter if no decimal point) sText2 = sText If iDec = 0 Then While Right(sText2, 1) = "0" sText2 = Left(sText2, Len(sText2) - 1) Wend End If iMin = Len(sText2) 'return Min or Max Select Case iType Case 1 SigFigs = iMin Case 2 SigFigs = iMax Case Else SigFigs = CVErr(xlErrNum) End Select End Function
You call this function by using the following in your worksheet:
=SigFigs(A1, x)
You can replace x with either 1 or 2. If you specify 1, then the function returns the minimum number of significant digits. If you specify 2, then the function returns the maximum number of significant digits. In most cases the two possible return values will be the same, except with values that are whole numbers, without a trailing decimal point, that have trailing zeroes. In other words, if you use the function to evaluate the number 1234000, then the minimum (x is 1) returns 4 and the maximum (x is 2) returns 7.
The function takes into consideration how the number appears in the worksheet, meaning that it matters how the number is formatted. It strips out any formatting characters, such as negative signs, parentheses, and commas.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10975) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Finding the Number of Significant Digits.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
If you have some legacy data stored in very old spreadsheet files, you may be wondering how to get that data into an ...
Discover MoreOne of the settings you can make in Excel is to specify a user's name. This name is accessible through macros, and can ...
Discover MoreWant to find out exactly what version of Excel you are using? Here's how to get to the info.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2018-05-21 08:20:20
P.s. @ Rick
You might want to post again your full comment with the modified URL here, at the XL 2007+ version of Allen's Tip:
excelribbon.tips.net/T010976_Finding_the_Number_of_Significant_Digits
2018-05-21 07:46:38
Worked - got posted straight away
:)
2018-05-21 07:45:03
@ Rick, Hi Rick. Re the posting problem..
That sort of thing happens a lot to me here and elsewhere. People are becoming more careful about links being posted.
I have found the best workaround is to post a link without the first h t t p s and w w w and or c o m part. Most browsers will find straight away the link if you try it without that first bit. It seems that most spam filters just look for that first bit.
Usually works .. I will try it here and see …
excelfox.com/forum/showthread.php/2004-Thinking-About-Using-VBA-s-IsNumeric-Function-Read-this-first
Alan
2018-05-20 18:04:34
Rick Rothstein
The above comment by me appears to be "unreadable". The comment includes a URL to my mini-blog site on the ExcelFox forum (article title "Thinking About Using VBA's IsNumeric Function? Read this first.") which made the comment look like SPAM and forced it to be "moderated". Apparently Allen approved the comment, but all the formatting disappeared when he let the comment get posted. I am assuming if I post the same comment without the URL, it will post correctly formatted immediately, so below is the comment I made above (without the URL) which I hope posts properly formatted...
There are some "problems" with the SigFigs function in the above article. First off, it uses VB's IsNumeric function to proof whether a text value is a real number or not. For example, the SigFigs function returns the following numbers for the following values in cells formatted as Text...
&HEAD ==> 3
&7654 ==> 4
123D45 ==> 5
($1,23,,3.4,,,5,,E67$) ==> 8
In this mini-blog article of mine, I explain why that is not necessarily a good thing to use IsNumeric for that purpose...
URL omitted (you should be able to find it in my first post if you search for it)
I also noticed the following evaluations by the SigFigs function which also produce answers that I do not agree with. First, numbers that Excel converts to E-notation when entered into a cell or the Formula Bar...
123456000000 ==> 8
0.00000012345 ==> 7
0.0000000012 ==> 5
Second, some floating point numbers when entered into a cell formatted as Text... I have not delved into the code to see why, I am simply noting the problem. Here are some examples all of which return a #NUM! error from the function... 1.2, 1.09, 12.34, 10.002, etc. I would note that there are lots of examples of floating point numbers entered into Text formatted cells that work correctly.
Now, of course, I have my own SigFigs function to offer which is more compact, uses no loops and handles the above noted problems correctly (as far as my limited testing is able to confirm)...
Function SigFigs(Rng As Range, Optional iType As Long = 1)
Dim S As String
Application.Volatile
S = Trim(Replace(Replace(Split(Rng.Text, "E", , vbTextCompare)(0), "$", ""), "%", ""))
If Not S Like "*[!0-9.+-]*" And Not S Like "*.*.*" And S <> "." Then
If iType = 1 And Not S Like "*.*" Then S = Replace(Trim(Replace(S, "0", " ")), " ", "0")
SigFigs = Len(Format(Replace(S, ".", ""), String(31, "#") & ";" & String(31, "#") & ";;"))
Else
SigFigs = CVErr(xlErrNum)
End If
End Function
2018-05-19 14:42:32
Rick Rothstein
There are some "problems" with the SigFigs function in the above article. First off, it uses VB's IsNumeric function to proof whether a text value is a real number or not. For example, the SigFigs function returns the following numbers for the following values in cells formatted as Text...&HEAD ==> 3&7654 ==> 4123D45 ==> 5($1,23,,3.4,,,5,,E67$) ==> 8In this mini-blog article of mine, I explain why that is not necessarily a good thing to use IsNumeric for that purpose...http://www.excelfox.com/forum/showthread.php/2004-Thinking-About-Using-VBA-s-IsNumeric-Function-Read-this-firstI also noticed the following evaluations by the SigFigs function which also produce answers that I do not agree with. First, numbers that Excel converts to E-notation when entered into a cell or the Formula Bar...123456000000 ==> 80.00000012345 ==> 70.0000000012 ==> 5Second, some floating point numbers when entered into a cell formatted as Text... I have not delved into the code to see why, I am simply noting the problem. Here are some examples all of which return a #NUM! error from the function... 1.2, 1.09, 12.34, 10.002, etc. I would note that there are lots of examples of floating point numbers entered into Text formatted cells that work correctly.Now, of course, I have my own SigFigs function to offer which is more compact, uses no loops and handles the above noted problems correctly (as far as my limited testing is able to confirm)...Function SigFigs(Rng As Range, Optional iType As Long = 1) Dim S As String Application.Volatile S = Trim(Replace(Replace(Split(Rng.Text, "E", , vbTextCompare)(0), "$", ""), "%", "")) If Not S Like "*[!0-9.+-]*" And Not S Like "*.*.*" And S <> "." Then If iType = 1 And Not S Like "*.*" Then S = Replace(Trim(Replace(S, "0", " ")), " ", "0") SigFigs = Len(Format(Replace(S, ".", ""), String(31, "#") & ";" & String(31, "#") & ";;")) Else SigFigs = CVErr(xlErrNum) End IfEnd Function
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2023 Sharon Parq Associates, Inc.
Comments