Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Finding the Number of Significant Digits.
Written by Allen Wyatt (last updated February 8, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
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 2021. You can find a version of this tip for the older menu interface of Excel here: Finding the Number of Significant Digits.
Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!
When you freeze panes in a worksheet, those panes should persist even though you save the workbook and reload it. There ...
Discover MoreAutoComplete is a great feature for quickly adding data to a worksheet. If you are confused by why some things are picked ...
Discover MoreBy default, Excel provides some feedback on your formulas so that you can easily locate potential errors. If you get ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-03-21 10:31:02
J. Woolley
@Pablo
Instead of a macro, you should use a custom number format like 0.000000 (for six digits after the decimal).
See https://exceljet.net/custom-number-formats
or https://www.thespreadsheetguru.com/blog/excel-custom-number-format-rules
or https://customformats.com/
https://sites.google.com/view/MyExcelToolbox/
2021-03-20 21:21:39
Pablo Aguirre
I'm a high school astronomy teacher. I'm using Excel to do calculations for my students. I want them to be acquainted with various scientific laws that affect astronomical bodies such as Newton's Law of Gravitation. However, Excel is difficult to work because of significant figures. It drops trailing zeros after the decimal. I was pleased to see your macro. I have very little VBA or macro skills. I have enough to use your macro. Thank you for making it available. However, Excel continues to drop the trailing zeros, even though the comments in the macro seem to indicate that the trailing zeros after the decimal will be kept. If you can provide some help I would be very grateful.
Sincerely,
Pablo Aguirre
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 © 2025 Sharon Parq Associates, Inc.
Comments