+ Reply to Thread
Results 1 to 2 of 2

Number format excel

  1. #1
    Forum Contributor
    Join Date
    11-26-2010
    Location
    usa
    MS-Off Ver
    Office 365
    Posts
    1,224

    Number format excel

    Hello all

    I am having some issues with formatting my numbers. I have my range in millions from +5M to -5M in my data set (see attached worksheet).

    I can get the positive # to appear as i.e. $4.1M but anytime the value is negative million, it just comes at i.e. -$1,308,316 (I would like to show as "red" ($1.3M)

    How can i get the brackets to be added and for it to show in red - below is my format > customer # format
    [>1000000]$#.0,,"M";[>1000]$#,"K";$#,##0

    Also, if it less than M, I would like the value to auto adjust to show i.e. $198K or "red" ($140k)

    any help would be appreciated!
    Attached Files Attached Files
    Last edited by jw01; 03-28-2015 at 02:05 PM.

  2. #2
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: Number format excel

    (source material)

    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.

    ==========

    Hopefully you can adapt this technique to your exact specifications.
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Similar Threads

  1. Need formula or code to convert number(s) from custom format to number format
    By tuongtu3 in forum Excel Programming / VBA / Macros
    Replies: 6
    Last Post: 01-12-2015, 07:44 PM
  2. Replies: 0
    Last Post: 01-18-2014, 02:02 PM
  3. Excel: How to convert time format into number format that can be added?
    By Frances Jones in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 09-17-2012, 04:10 PM
  4. Replies: 1
    Last Post: 05-18-2006, 11:45 PM
  5. [SOLVED] convert text-format number to number in excel 2000%3f
    By Larry in forum Excel General
    Replies: 1
    Last Post: 07-29-2005, 04:05 PM

Bookmarks

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1