Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Engineering Calculations.
Written by Allen Wyatt (last updated October 10, 2020)
This tip applies to Excel 97, 2000, 2002, and 2003
In an engineering environment, it is not unusual to need to "normalize" numbers in some manner. For instance, you may need to show numeric values normalized to multiples of 10^3, such that 7340 is expressed as 7.34 and 73400 is expressed as 73.4.
It is possible in Excel to use a custom number format to express information in scientific notation that will normalize the display of a number to a multiple of 10^3. To do this, you would follow these steps:
Figure 1. The Number tab of the Format Cells dialog box.
Now, when you enter a number such as 7340 into the cell, Excel displays it as 7.3E+3. Because of the way the cell format was entered, the portion after the E will always be a multiple of 3.
This is fine and good, but what if you want just the 7.3 in the cell, and then a metric prefix with a unit in an adjoining cell, such as kilograms? This is a bit more complex, but it can be done using formulas. For instance, let's assume you have your original number in cell A2, you wanted the normalized number in cell B2, and the metic prefix and unit name in cell C2. All you would need to do is enter the following formula in cell B2:
=IF(OR(A2>=1,A2<=-1),SIGN(A2)*(ABS(A2)/(10^(3*INT(LOG(ABS(A2))/3)))), IF(A2=0,0,SIGN(A2)*(ABS(A2)*10^(-3*INT(LOG(ABS(A2))/3)))))
Assuming the units you are working with are an imaginary unit called a foo, in cell C2 you would use a different formula, as follows:
=IF(OR(A2>=1, A2<=-1),CHOOSE(INT(LOG(ABS(A2))/3)+1, "Foos", "Kilofoos", "Megafoos", "Gigafoos", "Terafoos", "Petafoos", "Exafoos"), IF(A2=0,"",CHOOSE(INT(-LOG(ABS(A2))/3)+1, "Millifoos", "Microfoos", "Nanofoos", "Picofoos", "Femtofoos", "Attofoos")))
These formulas may seem a bit long, and they are. However, they will work for any number between approximately -9.99999E-18 to 9.99999E+20. For instance, if you put the number .000125 in cell A2, then cell B2 will contain 125 and cell C2 would contain Millifoos.
If you prefer to not use longer formulas such as these in your workbooks, you can develop a couple of VBA functions to do the trick. The following function, MySciNum, returns a normalized number. Thus, you would use =MySciNum(A2) in cell B2 to get the same results as noted above:
Function MySciNum(BaseNum As Double) As Double Select Case BaseNum Case Is >= 1 While Abs(BaseNum) > 1000 BaseNum = BaseNum / 1000 Wend Case 0 'Do nothing Case Else While Abs(BaseNum) < 1 BaseNum = BaseNum * 1000 Wend End Select MySciNum = BaseNum End Function
This function only returns a number. To return the units with the appropriate metric prefix, you would use the following function. All you need to do is pass it the cell reference and the name of a single unit. For instance, you could use =MySciPre(A2, "foo"). The macro is as follows:
Function MySciPre(BaseNum As Double, Unit As String) As String Dim OrigNum As Double Dim Pref As Integer Dim Temp As String Pref = 0 OrigNum = BaseNum Select Case BaseNum Case Is >= 1 While Abs(BaseNum) > 1000 BaseNum = BaseNum / 1000 Pref = Pref + 1 Wend Case 0 Pref = 99 Case Else While Abs(BaseNum) < 1 BaseNum = BaseNum * 1000 Pref = Pref - 1 Wend End Select Select Case Pref Case -6 Temp = "atto" & Unit Case -5 Temp = "femto" & Unit Case -4 Temp = "pico" & Unit Case -3 Temp = "nano" & Unit Case -2 Temp = "micro" & Unit Case -1 Temp = "milli" & Unit Case 0 Temp = Unit Case 1 Temp = "kilo" & Unit Case 2 Temp = "mega" & Unit Case 3 Temp = "giga" & Unit Case 4 Temp = "tera" & Unit Case 5 Temp = "peta" & Unit Case 6 Temp = "exa" & Unit Case Else Temp = "" End Select If Len(Temp) > 0 Then Temp = LCase(Temp) Temp = UCase(Left(Temp, 1)) & Mid(Temp, 2) If Abs(OrigNum) <> 1 Then Temp = Temp & "s" End If MySciPre = Temp End Function
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2928) 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: Engineering Calculations.
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 allows you to specify the RGB (red, green, and blue) value for any color used in a cell. Here's a quick way to see ...
Discover MoreWhen sharing workbooks with others, you may find that the macros in those workbooks may not work as you expect. This tip ...
Discover MoreOne of the powerful programming structures available in VBA is the Select Case structure. This tip explains how you can ...
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 © 2024 Sharon Parq Associates, Inc.
Comments