Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Handling Negative Numbers in a Complex Custom Format

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: Handling Negative Numbers in a Complex Custom Format.

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.

Some people may also think you could use conditional formatting in this case. Conditional formatting doesn't allow you to modify the presentation of the number in the cell, however. While you can check for the value (more than a thousand or a million, for instance), you cannot then divide, round, and add a suffix to the value in the cell. Nor can you do things like add parentheses to negative values.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10226) 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: Handling Negative Numbers in a Complex Custom Format.

Related Tips:

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

Comments for this tip:

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.