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 significant digits in a value means counting the number of digits, excluding 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:
https://excelribbon.tips.net/T012083
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 (10976) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 365. You can find a version of this tip for the older menu interface of Excel here: Finding the Number of Significant Digits.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
In Excel you can reference a cell in a formula by entering the coordinates for the cell you want to reference. This can ...
Discover MoreWant to provide a bit of contact information in a workbook? A great place to do it (out of sight, but not inaccessible) ...
Discover MoreWorking on a computer system that has multiple monitors can help increase your productivity. If you want to work with ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2021 Sharon Parq Associates, Inc.
Comments