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.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10920) applies to Microsoft Excel 2007, 2010, and 2013. You can find a version of this tip for the older menu interface of Excel here: Using an Exact Number of 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!
Excel often changes the formatting of a cell based on how it parses what you are entering into that cell. This is ...
Discover MoreThe ability to center text across a range of cells has long been a staple of experienced Excel users. Here's how to ...
Discover MoreNeed to cram a bunch of text all on a single line in a cell? You can do it with one of the lesser-known settings in Excel.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2015-05-13 16:41:58
patman
How about this:
You have '1' in A1, '2' in A2, etc, you want it to be '000001', '000002', etc on down the column. Manually type the extra 0s in those cells, highlight them and drag them with the bottom-right handle down the column over the numbers. The numbers are now all 6-digits with leading 0s.
2015-01-16 10:13:33
Dennis Costello
Actually, the exact result for
4656.25 * 2510.35 = 11,688,817.1875, which on my calculator rounds to .19
2014-12-24 04:07:26
Naba Raj Bagale
I want to ask you that why excel does not show the value exact value like calculator after decimal point in Multiplication case. I need accuracy of number while calculating. What is the solution please. For instance I found 4656.25
2510.35
= 11688817.19
Rather the exact number should be 11688817.18
I am terrified with this case. Can you give me solution please.
2014-12-01 04:52:02
Pete
I would use only
=FIXED(A1,5-INT(LOG(ABS(A1))),TRUE)
otherwise the formula suggest above
will yeald wrong results with numbers
smaller than 1 (eg. 0.0012345678)
2014-11-29 20:18:19
Bill Macky
How about the following as a function?
'aaa is value, b is figures displayed,c is 1 for commas
Function MyFixed(aaa, b, c)
MyFixed = Application.WorksheetFunction.Fixed(aaa, b - Int(Log(Abs(aaa)) / Log(10)) - 1, c)
End Function
Seems to work. Actually something I've wanted for a while.
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 © 2018 Sharon Parq Associates, Inc.
Comments