+ Reply to Thread
Results 1 to 9 of 9

How To Make CONCATENATE Generate A Text String Using The Custom Formatted Value Of A Cell?

  1. #1
    Registered User
    Join Date
    05-02-2014
    Location
    New York, NY
    MS-Off Ver
    Excel 2010
    Posts
    10

    Red face How To Make CONCATENATE Generate A Text String Using The Custom Formatted Value Of A Cell?

    Hello,

    I have an Excel 2010 spreadsheet that I am using to save several numbers all in the same column. These numbers can range from the several thousands up to billions. The formatting I am using for these numbers is Number (using 1000s separator).

    number_forma.png

    I am also using the spreadsheet to generate a text string for each of the numbers. I don't want the text string to show the number as it is, I want to shorten the number by only showing the first few digits followed by a "B" for billion, "M" for million, or "K" for thousand. For example, in the text string I want to show 1,600,000 as 1.6B.

    In order to shorten the number I use the cell in the column to the right of each number. This cell uses the following custom formatting (which I found by doing a Google search):

    [>999999999.999]#.0,,,"B";[>999999.999]#,,"M";#,"K";

    custom_format.png

    As you can see the formatting is quite complex (at least for me it is) but it does what I want it to do.

    Here is a screenshot of what the original and custom formatted cells look like:

    custom_formatted_cells.png

    As you can see the custom formatting works and does exactly what I wan

    The next column (after the custom formatted number) is where I put the generated text string for each of the numbers. As I stated above, I want the generated text to use the shortened version of the number (e.g. 1.6B).

    To generate the text I use the CONCATENATE function with a reference to the cell containing the shortened number as one of the arguments. For example:

    CONCATENATE("SOME STRING ", B1)

    Where B1 is the custom formatted cell.

    The problem I am running into is, the text that gets generated doesn't show the shortened format of the number, it shows the full number. Here is a screenshot demonstrating what is happening:

    concatenate_formula.png

    As you can see the generated text is "SOME STRING 1600000000". This is not what I want. I want the generated text to be "SOME STRING 1.6B".

    I think I understand what's going on. When the CONCATENATE function references a cell it takes the actual value of the cell and ignores any formatting. (I suppose formatting is just the way you see the data, not how underlying functions receive the data.)

    My question is, how can I re-write the CONCATENATE function (or use another function, etc. available to me) to use the formatted version of the cell?

    Thank you,

    Jan

    *UPDATE* I have attached my spreadsheet as an attachment to this post (tackyjan_excelforums.xlsx). Please note that it was created and saved using Excel 2010.
    Attached Files Attached Files
    Last edited by tackyjan; 05-02-2014 at 09:22 PM.

  2. #2
    Forum Guru TMS's Avatar
    Join Date
    07-15-2010
    Location
    The Great City of Manchester, NW England ;-)
    MS-Off Ver
    MSO 2007,2010,365
    Posts
    44,464

    Re: How To Make CONCATENATE Generate A Text String Using The Custom Formatted Value Of A C

    Try

    Formula: copy to clipboard
    Please Login or Register  to view this content.



    Regards, TMS
    Trevor Shuttleworth - Retired Excel/VBA Consultant

    I dream of a better world where chickens can cross the road without having their motives questioned

    'Being unapologetic means never having to say you're sorry' John Cooper Clarke


  3. #3
    Registered User
    Join Date
    05-02-2014
    Location
    New York, NY
    MS-Off Ver
    Excel 2010
    Posts
    10

    Re: How To Make CONCATENATE Generate A Text String Using The Custom Formatted Value Of A C

    Quote Originally Posted by TMS View Post
    Try

    Formula: copy to clipboard
    Please Login or Register  to view this content.



    Regards, TMS
    I tried that. The problem is, my custom format is too complex. When I first try to use the TEXT function and insert my custom format:

    TEXT(B16,"[>999999999.999]#.0,,,"B";[>999999.999]#,,"M";#,"K";")

    Excel complains about the "B" (it highlights it after popping up an error message). I thought it was because the B is surrounded by quotes and that poses a problem because the format argument to the TEXT function is supposed to be enclosed in quotes.

    I tried several things to fix the issue. First, I tried to use the escape character in front of each of the quoted values in my format text ("B", "M", "K") such as:

    ,,,\"B\";

    This did not work. I guess you can't use the escape character in Excel like you can in most programming languages.

    The next thing I tried was using single quotes instead of double quotes around the B, M, and K:

    TEXT(B16,"[>999999999.999]#.0,,,'B';[>999999.999]#,,'M';#,'K';")

    Excel accepted the formula (it did not complain when I hit Enter) but now the cell shows #VALUE! which I guess means there is a problem with referencing a cell?

    The thing that really confuses me is I used the Error Checking feature on the Formulas tab to see what was happening as the formula gets evaluated. When I stepped in to the evaluation Excel gave me the following error:

    "The cell currently being evaluated contains a constant."

    I tried Google searches earlier to see what this means and how to fix it but I could not find a solution. Most people said that the referenced cell needs to be formatted as General. I can't do that however, because I need to format it as Custom to use my formula to display the shortened values.

    Thanks!

  4. #4
    Registered User
    Join Date
    03-22-2014
    Location
    Philippines
    MS-Off Ver
    Excel 2007,2010
    Posts
    39

    Re: How To Make CONCATENATE Generate A Text String Using The Custom Formatted Value Of A C

    Hi tackyjan ,

    try to post sample excel spreadsheet showing what is your existing and your target. members will easily understand what you want. I can also try to help you.

    REgards,

  5. #5
    Registered User
    Join Date
    05-02-2014
    Location
    New York, NY
    MS-Off Ver
    Excel 2010
    Posts
    10

    Re: How To Make CONCATENATE Generate A Text String Using The Custom Formatted Value Of A C

    Quote Originally Posted by blueblink01 View Post
    Hi tackyjan ,

    try to post sample excel spreadsheet showing what is your existing and your target. members will easily understand what you want. I can also try to help you.

    REgards,
    Okay, here is my spreadsheet attached to this post. I will also attach it to my original post.

    Thank you,

    Jan
    Attached Files Attached Files

  6. #6
    Registered User
    Join Date
    03-22-2014
    Location
    Philippines
    MS-Off Ver
    Excel 2007,2010
    Posts
    39

    Re: How To Make CONCATENATE Generate A Text String Using The Custom Formatted Value Of A C

    hi tackyjan

    Paste this formula in D1,

    =H1&" "&TEXT(A1,CHOOSE(LEN(TEXT(A1,"#,##0"))-LEN(SUBSTITUTE(TEXT(A1,"#,##0"),",",""))+1,"0","0.0,""K""","0.0,,""M""","0.0,,,""B""","0.0,,,,""T"""))

    Regards,

  7. #7
    Forum Guru
    Join Date
    03-02-2006
    Location
    Los Angeles, Ca
    MS-Off Ver
    WinXP/MSO2007;Win10/MSO2016
    Posts
    12,613

    Re: How To Make CONCATENATE Generate A Text String Using The Custom Formatted Value Of A C

    Try:
    Please Login or Register  to view this content.
    Attached Files Attached Files
    Ben Van Johnson

  8. #8
    Registered User
    Join Date
    05-02-2014
    Location
    New York, NY
    MS-Off Ver
    Excel 2010
    Posts
    10

    Re: How To Make CONCATENATE Generate A Text String Using The Custom Formatted Value Of A C

    Quote Originally Posted by blueblink01 View Post
    hi tackyjan

    Paste this formula in D1,

    =H1&" "&TEXT(A1,CHOOSE(LEN(TEXT(A1,"#,##0"))-LEN(SUBSTITUTE(TEXT(A1,"#,##0"),",",""))+1,"0","0.0,""K""","0.0,,""M""","0.0,,,""B""","0.0,,,,""T"""))

    Regards,
    Wow what a complicated formula! Thanks for the answer I will check it out and let you know.

  9. #9
    Registered User
    Join Date
    05-02-2014
    Location
    New York, NY
    MS-Off Ver
    Excel 2010
    Posts
    10

    Re: How To Make CONCATENATE Generate A Text String Using The Custom Formatted Value Of A C

    Quote Originally Posted by protonLeah View Post
    Try:
    Please Login or Register  to view this content.
    Again, thanks for your answer and wow what a formula! I will check it out and let you know.

+ 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. [SOLVED] Custom Cell Format - Number ending with text string
    By BeautyBlues in forum Excel General
    Replies: 4
    Last Post: 06-20-2013, 07:53 AM
  2. Extracting numbers and text from inconsistent text/number formatted string
    By Brandivil in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 01-25-2013, 01:46 PM
  3. Interrogate value of "text" in custom formatted cell
    By margalo in forum Excel General
    Replies: 0
    Last Post: 10-16-2012, 12:25 PM
  4. Converting 'General' formatted cells to Text formatted cell using.
    By Zahid Khan in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 03-12-2005, 04:06 PM
  5. [SOLVED] How to make a cell return the formatted value in a text string (i.
    By n.almeida in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 02-02-2005, 10:06 AM

Tags for this Thread

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