Written by Allen Wyatt (last updated December 1, 2018)
This tip applies to Excel 97, 2000, 2002, and 2003
Henk asked if there is a way in Excel to display a number using six digits, independent of the placement of the decimal point. For instance, 0.1 would be displayed as 0.10000, 200 would be displayed as 200.000, and 25000 would be displayed as 25000.0.
Unfortunately, there is no formatting that will do the trick; all display formatting seems to be dependent on the position of the decimal point. You can format a display for a specific number of digits after the decimal point, but that number of digits will be used regardless of how many digits appear before the decimal point.
Several ExcelTips subscribers came up with suggestions that involve using formulas to display the number as desired. For instance, the following formula will display the value in A1 using six digits:
=FIXED(A1,IF(ABS(A1)<1,5,5-INT(LOG(ABS(A1)))),TRUE)
Other readers provided formulas that relied on converting the number to a text string and displaying it as such. Converting a number to its textual equivalent, however, has the distinct drawback of no longer being able to use the number in other formulas. (Remember—it is text at this point, not a number.) The above formula does not have that limitation.
If you wanted to, you could also use a macro to set the formatting within a cell that contains a value. The advantage to such a macro is that you don't have to use a cell for a formula, as shown above. The drawback to a macro is that you need to remember to run it on the cells whenever values within them change. The following macro is an example of such an approach:
Sub SetFigures() Dim iDecimals As Integer Dim bCommas As Boolean Dim sFormat As String Dim CellRange As Range Dim TestCell As Range bCommas = False 'Change as desired Set CellRange = Selection For Each TestCell In CellRange If Abs(TestCell.Value) < 1 Then iDecimals = 5 Else iDecimals = 5 - Int(Log(Abs(TestCell.Value)) / Log(10#)) End If sFormat = "0" If bCommas Then sFormat = "#,##0" If iDecimals < 0 Then sFormat = "General" If iDecimals > 0 Then sFormat = sFormat & _ "." & String(iDecimals, "0") TestCell.NumberFormat = sFormat Next TestCell End Sub
In order to use the macro, simply select the cells you want to format, then execute it. Each cell in the range you selected is set to display six digits, unless the number in the cell is too large or too small.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (1933) 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: Using an Exact Number of Digits.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
If you want information to display on the screen using fractions instead of decimals, you're in luck. Excel provides ...
Discover MoreWant to draw attention to some information in a particular cell? Make the cell flash, on and off. Here's how you can ...
Discover MoreWant to change the attributes of your text (or what Excel refers to as font styles)? Here's how to do it.
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 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 © 2025 Sharon Parq Associates, Inc.
Comments