Column total

kizofilax

New Member
Joined
Sep 10, 2012
Messages
8
Name20112011-Ratio20122012-Ratio
system1212/345050/80
board2222/343030/80
TOTAL3480

<tbody>
</tbody>

I am trying to calculate the Ratio columns. Basically my problem is to create a measure for each row that is the total of the column and using it as a divisor on each row. If I only have 1 year I can accomplish this with

=CALCULATE( SUM([Sum] ), ALLSELECTED( )) but as soon as I add another year this doesn't work

Any ideas?

Thanks
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Can't you just choose to display the values as a percentage of the column in the pivot table rather than using a measure?
 
Upvote 0
The problem with your calculation is that SUM([Sum]) will be evaluated for the whole pivot table, so get a table grand-total.

This being said, you cannot create a measure that says "Total of the column". You can, however, calculate the total for all selected products, or for the currently selected year, ...

The following measure calculates the total of "Sum" for all selected products.
Total - Selected Products :=
CALCULATE( SUM([Sum] ), ALLSELECTED(YourTableName[Name] ))

The following measure calculates the total of "Sum" does some sort of "ALLSELECTED EXCEPT Year" calculation (grand total for the current year):
Grand Total - Year :=
CALCULATE( SUM([Sum] ), ALLSELECTED(), VALUES(YourTableName[Year]))

For the given layout, both calculations will return the same results, but if you had another attribute in your table like "Country", they would give different results.

Take a look at both measures, to see which one is best suited.
 
Upvote 0
If I understand the issue correctly, all you need is a measure that takes the current value (per [Name]) and divides its amount against the amount of the current Year. If this is the case, you can simply use the following as a measures:

SUM(Table1[Amount]) / CALCULATE( SUM(Table1[Amount]) , ALLEXCEPT(Table1, Table1[Year] ) )

The only issue would be the measure name, as you cannot dynamically title it (2011-Ratio or 2012-Ratio). It would have to be called just 'Ratio'
 
Upvote 0

Forum statistics

Threads
1,214,914
Messages
6,122,211
Members
449,074
Latest member
cancansova

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top