Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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: Understanding Color and Conditional Formatting Codes.
Written by Allen Wyatt (last updated January 6, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
In other issues of ExcelTips you learn how formatting codes are used to create custom formats used to display numbers, dates, and times. Excel also provides formatting codes to specify text display colors, as well as codes that indicate conditional formats. These formats only use a specific format when the value being displayed meets a certain criterion.
To understand these codes a bit better, take a look at this format within the Currency category:
$#,##0.00_);[Red]($#,##0.00)
Notice there are two number formats divided by a semicolon. If there are two formats like this, Excel assumes that the one on the left is to be used if the number is 0 or above, and the one on the right is to be used if the number is less than 0. This example results in all numbers having a dollar sign, a comma being used as a thousands separator, amounts less than $1.00 having a leading 0, and negative values being shown in red with surrounding parentheses. The _) part of the left format is used so that positive and negative numbers align properly (positive numbers will leave a space the same width as a right parenthesis after the number).
You are not limited to only two formats, as in this example. You can actually use four formats, each separated by a semicolon. The first is used if the value is above 0, the second is used if it is below 0, the third is used if it is equal to 0, and the fourth is used if the value being displayed is text.
The following table shows the color and conditional formatting codes. As you may have surmised, these codes are used with the formatting codes discussed in other issues of ExcelTips.
Symbol | Effect | |
---|---|---|
[Black] | Black type. | |
[Blue] | Blue type. | |
[Cyan] | Cyan type. | |
[Green] | Green type. | |
[Magenta] | Magenta type. | |
[Red] | Red type. | |
[White] | White type. | |
[Yellow] | Yellow type. | |
[COLOR x] | Type in color code x, where x can be any value from 1 to 56. | |
[= value] | Use this format only if the number equals this value. | |
[< value] | Use this format only if the number is less than this value. | |
[<= value] | Use this format only if the number is less than or equals this value. | |
[> value] | Use this format only if the number is greater than this value. | |
[>= value] | Use this format only if the number is greater than or equals this value. | |
[<> value] | Use this format only if the number does not equal this value. |
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8352) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Understanding Color and Conditional Formatting Codes.
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!
Adding a custom format to Excel is easy. Having that custom format appear in all your workbooks is a different story ...
Discover MoreExcel allows you to format your numeric values in a wide variety of ways. One such formatting option is to display ...
Discover MoreYou can, in a macro, specify a custom format for a range of cells. If the custom format doesn't seem to "stick" (so to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-01-09 04:18:52
Enno
@Dave
Thank yor for your answer.
My major problem was that I use a german version of Excel and therefore everything has to be translated: the "red" and the "."
Now it works
2024-01-08 17:20:23
Dave Bonin
@Enno
In your case, the format you are seeking is:
0.00_);[Red](0.00);[Blue]0_._0_0_)
Or you could use:
0.00;[Red]-0.00;[Blue]0_._0_0
The first format uses parentheses for negative numbers. The second uses a minus sign.
Note that both include '_._0_0' for the zero format portion. This keeps the whole units digit for the zero lined up with the same digits for positive and negative numbers. Much easier to read.
And why not show zero as '0.00'? You can, but that's just adding more clutter digits which may make it harder to see interesting values.
2024-01-08 17:13:06
Dave Bonin
@Liz
If I read your question right, you're wondering why the second part of the format '[Red]($#,##0.00)' does not contain a '[<0]' indicator.
If that's what you're asking, the '[<0]' portion is implied as the default. With only two formats, one to the left of the semicolon and one to the right, the portion is greater than or equal to zero by default and the ight portion is less than zero by default.
You could have written the format as '[>=0]$#,##0.00_);[<0][Red]($#,##0.00)' and gotten the same result.
2024-01-08 09:56:25
Liz
I don't see a LESS THAN indicator - what am I missing ? $#,##0.00_);[Red]($#,##0.00)
2024-01-08 09:29:47
Enno
Can you give an example for a configuration with more than 2 formats, e.g. postive numbers in black, negative in red and the 0 in blue?
It tried this, but got an error message.
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