+ Reply to Thread
Results 1 to 3 of 3

How to round up percentage values in a pivot table that add up to 100?

  1. #1
    Registered User
    Join Date
    11-24-2012
    Location
    Greece
    MS-Off Ver
    Excel 2021
    Posts
    2

    How to round up percentage values in a pivot table that add up to 100?

    Please forgive me if I don't describe my problem accurately, I've been forced into this and I haven't used excel for many years.

    I have several survey responses that I'm trying to make pie charts out of. I have mapped these to a pivot table, I think correctly, and now I'm trying to make pie charts for each question.

    What I can't solve for the life of me, is how to perform rounding at the percentage values that adds up to 100. Here is one sample.

    Please Login or Register  to view this content.
    If I format the number to 0 decimals, the percentages add up to 99%. If I try to ROUNDUP the pivot table value cells I get "You cannot edit the formula for a calculated item while custom calculations is used". I don't want to write them by hand because there's several questions.

    Accuracy doesn't really matter either. If I can push the highest percentage to fill the rest up to 100, I'm fine with that!

    Thank you for any help!

    PS: I'm so happy Excel forum still exists! I used it first around 10 years ago, and it's the only website that remembers me every year on my birthday!
    Last edited by mechanicarts; 05-17-2022 at 08:35 AM.

  2. #2
    Administrator 6StringJazzer's Avatar
    Join Date
    01-27-2010
    Location
    Tysons Corner, VA, USA
    MS-Off Ver
    MS365 Family 64-bit
    Posts
    24,705

    Re: How to round up percentage values in a pivot table that add up to 100?

    Welcome to the Forum mechanicarts !

    The rounding error you are describing is an inherent mathematical problem with rounding; it's not an Excel problem. However, here is a solution to round the largest number in such a way as to force the total to be 100%. This assumes your percentage numbers are in column A.

    A better solution might be possible if you attach your file with sample data. See yellow banner at the top of the page.

    Values as displayed
    A
    B
    C
    1
    Original Data
    Rounded numbers
    Adjusted numbers
    2
    71.43%
    71%
    72%
    3
    7.14%
    7%
    7%
    4
    14.29%
    14%
    14%
    5
    7.14%
    7%
    7%
    6
    0.00%
    0%
    0%
    7
    100.0%
    99.0%
    100.0%

    Underlying formulas
    A
    B
    C
    1
    Original Data
    Rounded numbers
    Adjusted numbers
    2
    0.7143
    =ROUND(A2,2)
    {=IF(A2=LARGE($A$2:$A$6,1),1-(SUM(ROUND($A$2:$A$6,2))-ROUND(A2,2)),ROUND(A2,2))}
    3
    0.0714
    =ROUND(A3,2)
    {=IF(A3=LARGE($A$2:$A$6,1),1-(SUM(ROUND($A$2:$A$6,2))-ROUND(A3,2)),ROUND(A3,2))}
    4
    0.1429
    =ROUND(A4,2)
    {=IF(A4=LARGE($A$2:$A$6,1),1-(SUM(ROUND($A$2:$A$6,2))-ROUND(A4,2)),ROUND(A4,2))}
    5
    0.0714
    =ROUND(A5,2)
    {=IF(A5=LARGE($A$2:$A$6,1),1-(SUM(ROUND($A$2:$A$6,2))-ROUND(A5,2)),ROUND(A5,2))}
    6
    0
    =ROUND(A6,2)
    {=IF(A6=LARGE($A$2:$A$6,1),1-(SUM(ROUND($A$2:$A$6,2))-ROUND(A6,2)),ROUND(A6,2))}
    7
    =SUM(A2:A6)
    =SUM(B2:B6)
    =SUM(C2:C6)

    This is an array formula. If you are not using Excel 365, after typing in the formula, do not hit ENTER--hit CTRL+SHIFT+ENTER. You have done it correctly if the formula in the formula box has {braces} around it. You cannot type in the braces; they are just an indicator that it is an array formula.
    Jeff
    | | |會 |會 |會 |會 | |:| | |會 |會
    Read the rules
    Use code tags to [code]enclose your code![/code]

  3. #3
    Registered User
    Join Date
    11-24-2012
    Location
    Greece
    MS-Off Ver
    Excel 2021
    Posts
    2

    Re: How to round up percentage values in a pivot table that add up to 100?

    Thank you sincerely very much for your time. I struggled a bit to understand it, but in the end, I found a much simpler solution.

    Since I only need to visualize the data in charts (and not for scientific use), I just clicked on the pie labels, I selected "percentage" and it did a nice rounding on its own. I can't believe the solution was that simple!

+ 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. Replies: 1
    Last Post: 08-02-2021, 09:19 AM
  2. Turning a percentage round to show the remaining percentage
    By tjb333 in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 08-02-2018, 10:51 AM
  3. VBA for filtering dates in a Pivot Table Round 2
    By PhatRam32 in forum Excel Programming / VBA / Macros
    Replies: 0
    Last Post: 08-14-2013, 02:29 PM
  4. How to calculate percentage change between values in a pivot table
    By no.18shirt in forum Excel Charting & Pivots
    Replies: 3
    Last Post: 07-03-2013, 01:48 PM
  5. Replies: 3
    Last Post: 06-12-2013, 10:53 PM
  6. Pivot Table with Ordinal Values and percentage difference
    By algebr in forum Excel Charting & Pivots
    Replies: 1
    Last Post: 01-21-2013, 01:09 AM
  7. Replies: 0
    Last Post: 10-15-2012, 06:09 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