Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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: Handling Negative Numbers in a Complex Custom Format.
Written by Allen Wyatt (last updated November 6, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Douglas is having some problems getting his head around a custom format he needs. He has created a custom format that displays large numbers the way he wants, such that $1,000,000 is displayed as $1.0M and $1,000 is displayed as $1.0K. This format is as follows:
[>1000000]$#.0,,"M";[>1000]$#.0,"K";$#,##0.0
Douglas wants to know how to adjust the custom format so that negative numbers appear in this same fashion, but in red with parentheses around them, like ($1.0K).
Unfortunately, what you want to do is not possible with a single custom format. The reason is because a single custom format can only have four conditions, each separated by a semicolon. This is the general syntax of a custom format:
positive; negative; zero; text
Note that the first format is used when the value is positive, the second when it is negative, the third when the value is exactly zero, and the fourth when the value is text. While this is the general syntax for custom formats, you can "fudge" the formats a little in the way you are doing. Consider the format you are using:
[>1000000]$#.0,,"M";[>1000]$#.0,"K";$#,##0.0
Note that according to the general syntax, the format before the first semicolon would be used for positive values, the next format for negative values, and the third for zero values. However, this is not the way in which Excel translates this custom format. It translates it as "if greater than 1,000,000, do this; if greater than 1,000 do this; else do this". There is no positive or negative connotation in the format; in fact, any negative values are treated to the default treatment, which is the third format.
What you are trying to do is to define two positive conditions (one for millions and one for thousands) and two negative conditions (again, for millions and thousands). This cannot be done in a single custom format, regardless of how you try to put it together. Instead, you should use two custom formats, such as these:
[>=1000000]$#.0,,"M ";[>=1000]$#.0,"K ";$#,##0.0 [Red][<=-1000000]($#.0,,"M");[Red][<=-1000]($#.0,"K");[Red]($#,##0.0)
The first format is to be used in the case of positive values; it is a variation on the original format suggested at the first of the tip. The second format is to be used with negative values. These custom formats will need to be manually applied, based upon the value in the cell.
This may seem like a lot of work to go through to get the formatting you want. It is possible to create a macro that applies the formats, but the macro would not be a trivial endeavor. It would need to check what the value in the cell is, pick the proper format, construct the format, stuff it into the custom format for the cell, and then move on to the next cell.
There is one thing you can do, however—you can combine the use of a custom format with Excel's conditional formatting capabilities. Set up the following three custom formats in your worksheet:
_($#.0_K_);[Red]($#.0_K);;@ _($#.0,"K"_);[Red]($#.0,"K");;@ _($#.0,,"M"_);[Red]($#.0,,"M");;@
Then you can use the conditional formatting capabilities (Home tab of the ribbon | Conditional Formatting | Manage Rules) to define six different formatting rules. When you click the New Rule button to start defining each rule, you'll choose Format Only Cells that Contain at the top of the New Formatting Rule dialog box. Here are the six rules you'll define:
Cell Value <= -1000000 Cell Value >= 1000000 Cell Value between -999999 and -1000 Cell Value between 1000 and 999999 Cell Value between -999 and -1 Cell Value between 0 and 999
As you define each of these rules, you'll click the Format button in the New Formatting Rule dialog box. This presents the Format Cells dialog box in which you should click the Number tab. There you can choose the Custom category and pick one of the three custom formats you defined. Here are the ones you should choose:
That's it; the conditional formatting rules do the testing for your value ranges and then apply the proper custom formats for those numbers.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10227) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Handling Negative Numbers in a Complex Custom Format.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
Want to apply a custom format to your dates and times? To do it effectively you need to understand the custom formatting ...
Discover MoreWant information in a worksheet to be formatted and displayed as rounded to a power of ten? You may be out of luck, ...
Discover MoreCustom formats can be very powerful in Excel, but not every formatting scenario can be addressed through the use of a ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-05-16 11:54:37
Schragoo
Thank you for this! I have been looking to do this for months.
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 © 2024 Sharon Parq Associates, Inc.
Comments