Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. 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.

Handling Negative Numbers in a Complex Custom Format

by Allen Wyatt
(last updated April 11, 2015)

4

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's the ones you should choose:

  • For the first two conditional formatting rules listed above, choose the third custom format listed above.
  • For the third and fourth conditional formatting rules listed above, choose the second custom format listed above.
  • For the fifth and sixth conditional formatting rules listed above, choose the first custom format listed above.

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, and 2013. You can find a version of this tip for the older menu interface of Excel here: Handling Negative Numbers in a Complex Custom Format.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He  is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Shortcut to Merge Cells

Need to merge a bunch of cells together on a regular basis? You'll love the two macros in this tip which can make short work ...

Discover More

Deleting Everything Up to a Character Sequence

Sometimes you have too much information in a cell and you need to "pare down" what is there to get to the info you really ...

Discover More

Printing Only Selected Pages

When you print a worksheet, you don't need to print the whole thing. You can print only the pages you want. Here's how to do ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Adding a Custom Format to those Offered by Excel

Adding a custom format to Excel is easy. Having that custom format appear in all your workbooks is a different story ...

Discover More

Notation for Thousands and Millions

When working with very large numbers in a worksheet, you may want the numbers to appear in a shortened notation, with an ...

Discover More

Easy Value Hiding

Want a quick and easy way to hid the information in a cell? You can do it with a simple three-character custom format.

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is four less than 9?

2015-12-11 12:39:49

Andrew

Hi,

Thank you for your tips, they have been very helpful.

I have one question about adding a notation to make "0" appear as a - (en dash).

Here's my notation to format numbers as $M or $K depending on the specific number entered. But, I want to also have it so that zero is displayed as "-".

My current notation:
[>999999]$#.0,,"M";[>1000]$#,"K";$#,##0;


2015-04-12 05:41:10

Col Delane

A variation to Paul's suggestion is a combination of the middle and final solutions described in the tip (i.e. use [>=1000000]$#.0,,"M ";[>=1000]$#.0,"K ";$#,##0.0 as the base format, and
[Red][<=-1000000]($#.0,,"M");[Red][<=-1000]($#.0,"K");[Red]($#,##0.0) via conditional formatting when values are negative).

However, if you do go with the final solution, the number of conditional formats can be reduced to just two (less CF is always better) by:
(1) using _($#.0_K_);[Red]($#.0_K);;@
as the base cell format,
(2) using Conditional Format _($#.0,"K"_);[Red]($#.0,"K");;@
with a custom formula =AND(ABS([REF])>999,ABS([REF])<=999999), and
(3) using Conditional Format _($#.0,,"M"_);[Red]($#.0,,"M");;@
with a custom formula =ABS([REF])>999999


2015-04-11 08:39:50

Daniel

Paul, remember that the originally defined custom format doesn't specify any format for negative values. We could use conditional formatting to make negative values red, but that still doesn't fix the issue of using "K" or "M" in those negative values.


2015-04-11 07:13:43

paul

why not just use the originally defined custom format in combination with one conditional formatting formula: if <0 then text color = red


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.