+ Reply to Thread
Results 1 to 6 of 6

Code Function With Blanks

Hybrid View

  1. #1
    Registered User
    Join Date
    04-28-2010
    Location
    Rockledge, Florida
    MS-Off Ver
    Excel 2007
    Posts
    3

    Code Function With Blanks

    Hello,

    I have a function that averages the grades in a column. Part of the function needs to use the code function. It returns #VALUE! whenever I have an empty cell in the range.

    For example
    CODE(A1:A5)
    If A4 is blank, then it will return an error.

    How do I make it so that it doesn't count the blanks?

  2. #2
    Registered User
    Join Date
    03-28-2010
    Location
    United States
    MS-Off Ver
    Excel 2007
    Posts
    29

    Re: Code Function With Blanks

    Hey ninjadan,

    The code function is designed to work on a single cell, not a range. If you want it to go over an entire range, you would need to use an array formula or create a column designated for just that purpose.

    I don't know why you would want to do that though, can you post an example, or a full formula?
    Warm regards,

    Shampoo Monkey

    If you are happy with the results, please add to my reputation by clicking the icon next to the Post # in the bar above this post.

  3. #3
    Registered User
    Join Date
    04-28-2010
    Location
    Rockledge, Florida
    MS-Off Ver
    Excel 2007
    Posts
    3

    Re: Code Function With Blanks

    Quote Originally Posted by Shampoo Monkey View Post
    Hey ninjadan,

    The code function is designed to work on a single cell, not a range. If you want it to go over an entire range, you would need to use an array formula or create a column designated for just that purpose.

    I don't know why you would want to do that though, can you post an example, or a full formula?
    Here's the entire formula:
    =CHAR(INT(SUMPRODUCT(CODE(A1:A5))/COUNTA(A1:A5)))
    It works if I have all cells filled with letter grades.

  4. #4
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Code Function With Blanks

    Try:

    =CHAR(INT(SUM(IF(A1:A5<>"",CODE(A1:A5)))/COUNTA(A1:A5)))

    confirmed with CTRL+SHIFT+ENTER
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  5. #5
    Forum Guru
    Join Date
    08-05-2004
    Location
    NJ
    MS-Off Ver
    365
    Posts
    13,582

    Re: Code Function With Blanks

    OR
    =CHAR(AVERAGE(IF(ISNUMBER(CODE(A1:A5)),CODE(A1:A5),"")))
    Also an array function so use CNTRL SHFT ENTER

    Note: Your formula (and these formula's) seem flawed as if there is even 1 A and 4 B's, the result is A. Is that an issue?
    ChemistB
    My 2?

    substitute commas with semi-colons if your region settings requires
    Don't forget to mark threads as "Solved" (Edit First post>Advanced>Change Prefix)
    If I helped, Don't forget to add to my reputation (click on the little star at bottom of this post)

    Forum Rules: How to use code tags, mark a thread solved, and keep yourself out of trouble

  6. #6
    Forum Expert Paul's Avatar
    Join Date
    02-05-2007
    Location
    Wisconsin
    MS-Off Ver
    2016/365
    Posts
    6,887

    Re: Code Function With Blanks

    I was thinking the same thing, Chemist. I would suggest using ROUND rather than INT. INT will always round down (disregard the decimal, actually) giving a higher average than may be true.

    BBBAA would result in 97.6, and should average to a B.
    BBAAA would result in 97.4 and should average to an A.

    =CHAR(ROUND(SUM(IF(A1:A5<>"",CODE(A1:A5)))/COUNTA(A1:A5),0))

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

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