Ever wondered how to get percentage of another value in Excel pivot tables, like this:
In this tip, learn how to create such calculations using Excel pivot tables.
Note: this tip is not compatible with older versions of Excel. If you are using Excel 2007 / 2010 / 2013, then please install free Power Pivot add-in to create measures.
Step 1: Create a data model pivot table from your data
Let’s say you have some ledger entries data like this, in a table named data:
Go to Insert > Pivot Table and create a data model pivot table from this. Make sure you check “Add this data to the data model” option.
Step 2: Create a measure to calculate percentage of another value in Excel pivot tables
Now that we have a data model pivot, you can add measures to calculate various interesting things. Let’s create a measure to calculate the amount as a percentage of sales. To do that, right click on table in fields list and click on “Add Measure…” option.
Write below measure:
=SUM(data[Amount]) / CALCULATE(SUM(data[Amount]) , ALL(data), data[Category]="Sales")
And click ok. Now your measure has been created. Add this to the pivot table values area and you can see other values as % of sales. Cool no?
How does this work?
There are two parts in this calculation.
-
SUM(data[Amount])
: gives the total amount for the category / sub-category in the pivot table rowCALCULATE(SUM(data[Amount]) , ALL(data), data[Category]="Sales")
: calculates the total amount for “Sales” category by first removing filters on the data table { ALL(data) part } and then setting a filter with data[Category]=”Sales”
If all of this sounds like Greek and Latin, then check out my excellent introduction to DAX page first. You will learn how DAX works with simpler examples.
If you want to show the percentages only for non-sales category:
then you can use below measure definition:
=IF(HASONEVALUE(data[Category]), IF(values(data[Category])<>"Sales", sum(data[Amount]) / CALCULATE(sum(data[Amount]), all(data), data[Category]="Sales"), blank()), blank())
See all this in action – Video tutorial on “How to calculate percentage of another value in Excel pivot tables”
Check out this short video to understand how to create your percentage of sales measure in Excel. You can also watch it on Chandoo.org YouTube Channel.
Download percentage calculations pivot table example
Click here to download example workbook for this tip. Right click on the measures and select “Edit” to see the DAX formula.
More advanced pivot table tips
Been making pivot tables for a while and want to graduate to next level? Check out below tips:
- Distinct count in Excel Pivot Tables
- Rank totals with in a category in pivot table
- First and last date of a sale using pivot tables
- Generate combinations of two lists quickly
- Excel for accounting – 6 part tutorial
- More on Excel pivot tables & Power Pivot
Pivot much? What is the coolest pivot you have built
I build pivot tables every day, even on those unfortunate days when I don’t get to work on Excel or Power BI (yes, I build them in my mind on those days, you silly). They are powerful, useful and essential.
What about you? What is the coolest pivot you have built? Please, pretty please, do tell me in the comments. Off you go.
11 Responses to “How to get percentage of something calculations in Excel Pivot Tables”
Hi,
I am great fan your work and online teaching, I have created a automatically generated roster in excel but i am not able to add the needed criteria for roster so i need help would you kindly help me to add few criteria according the roster will be generated.
I will be happy to pay you once you complete the task i will explain the criteria and also send the excel which i have already created if you are happy to help me out in this.
Regards
Deb.
Thanks Chandoo! Keep up the kind sharing!
Pretty! This was an xtremely wonderful post. Many thanks foor supplying these
details.
How to get percentage of something calculations in Excel Pivot Tables
HI Chandoo
Hope you are doing well. I have applied your Dax formula on my excel sheet but I got data in different column as departments. And I need excel to calculate the percentage on the total of the each cost center but this one instead has taken the grand total of all the string under sales.
May I please ask for some help on this percentage calculations on different columns (For Each Department). Please share the formula. Thanks
Regards
Imran
Hi Chandoo,
this post was extremely helpful! Thanks for it. I was doing this with using two pivots with slicers until now, but it wasn't that comfortable. Using calculated field in pivot table as you shown in this post was much better.
Hello,
I have the same problem as Imran
On columns i have months and i have different cost centers and I need excel to calculate the percentage of costs per each month, on the total sales of each cost center.
Thank You!
Hi Ramona...
You can use this measure to get the % of cost center sales output.
=sum(Range[VALUE])/ calculate(sum(Range[VALUE]),all(Range[LinieBuget]), Range[TYPE]="SALES")
Hello,
I have similar problem,
I have Profit & Loss per years ( years are columns) and i need to (measure) calculate Percent of every row from SALES, BUT PER YEAR?
Can you help me?
Hello,
I have similar problem,
I have Profit & Loss per years ( years are columns) and i need to (measure) calculate Percent of every row from SALES, BUT PER YEAR?
Can you help me?
Hello,
Big fan of your work! Can you calculate a percentage of
another value in Excel pivot tables without using power pivot? Is there a work around? I have some users still using Excel 2010 and 2013(we can’t install power pivot plug-in)
Hi Chandoo
I use this formular to calulate percentage of the revenue in my income statement ( I have seen it in your you tube channel:-))
=Sum('LEDTRANS 1'[AMOUNTMST])/Calculate(sum('LEDTRANS 1'[AMOUNTMST]);all('LEDTRANS 1');'LEDTRANS 1'[Type]="Revenue")
It calculates the correct percentage for all the data but if I chose a month in the pivot table the result is not correct, hope you can help?
Best regards
Jens