Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Maxemus2000
Helper II
Helper II

Need help calculating a cumulative sum of measures?

Hi Community,

I'm working on a project that calculates a total of mix impact when comparing data between 2 selected periods. I have measures that calculate all of component, but I can't sum them up as a total. Is there a way to do it?

Below is a mock data.

 

Fact Table

Period IDStateTypeType
1CAVolume10000
1CACost50000
1NYVolume1500
1NYCost15000
2CAVolume8000
2CACost45000
2NYVolume3000
2NYCost20000
2TXVolume1000
2TXCost6000
3NYVolume2500
3NYCost10000
3TXVolume1000
3TXCost5000

 

User will use 2 slicers to select data for a comparison. These slicers are Period ID. Let's say a user select peiord 1 in slicer #1 and period 2 in slicer #2

 

The calculation logics:

 

Period 1
StateVolCostAvg
CA10000500005
NY15001500010
TX000
Total11500650005.652174

 

Period 2
StateVolCostAvg
CA8000450005.625
NY3000200006.666667
TX100060006
Total12000710005.916667

 

First we find a total of Volume, Cost, and Average for each period. Here are the measures 

[Volume Sel 1] >> a total volume of each state
[Total Volume Sel 1] >> a total volume of all state in a period
[Avg Cost Sel 1] >> an average cost of each state
[Total Avg Cost Sel 1] >> an average cost of all state in a period
 
selection #2 has the same measures

 

Now, we have to find a percentage of a volume from each state comparing to a total of all state in a period. Then, we find what a percentage change of each state between 2 period 

 

Vol %
StatePeriod 1Period 2Chg
CA0.86956520.666666667-0.2029
NY0.13043480.250.119565
TX00.0833333330.083333
Total110

 

Once we have a percentage different of each state, we will each state volume impact. To do this, we use a percentage different multiply by a total volume of all state from period #1

 

To find Avg cost Impact of each state, we use state cost average from period #1 subtract by a total average cost from period #1. Since TX didn't have an average cost in period #1, we use TX average cost from period #2 and subtract by  a total average cost from period #1.

 

Dol Impact
StateVol ImpactAvg Impact 
CA-2333.3333-0.652173911521.739
NY13754.3478260875978.261
TX958.333330.347826087333.3333
Total  7833.333

 

Once we have both Vol Impact and Avg Impact, we will calculate Dol Impact by multiply Vol Impact by Avg Impact then sum all of state Dol Impact to get our total Dol Impact. 

Here is my Dol Impact measure code

 

Dol Impact = 

VAR Vol1_Pct = [Volume Sel 1] / [Total Volume Sel 1]
VAR Vol2_Pct = [Volume Sel 2] / [Total Volume Sel 2]
VAR Pct_Diff = Vol1_Pct - Vol2_Pct
VAR Vol_Impact = Pct_Diff * [Total Volume Sel 1]
VAR AvgCost_Impact =
IF([Volume Sel 1] <> 0, [Avg Cost Sel 1], [Avg Cost Sel 2) - IF([Total Volume Sel 1] <> 0, [Total Avg Cost Sel 1], [Total Avg Cost Sel 2])
VAR Dollar_Impact = Vol_Impact * AvgCost_Impact
RETURN
Dollar_Impact
 
So, when I put this Dol Impact measure in a Matrix table with State as rows, it displays each state dollar impact correctly, but the total line shows 0. My goal is to display a total dollar impact as a card. As of right now, it shows 0 as a total dollar impact as a card. 
 
Is there a way to sum each state dollar impact up and display as one value? Please help! Thank you for your time.
1 ACCEPTED SOLUTION
OwenAuger
Super User
Super User

Hi @Maxemus2000 

 

When you want a measure calculated at a certain granularity then summed, I would normally use SUMX.

The first argument of SUMX should be a table containing rows representing the granularity of the calculation (in your case State), and the second argument should be the calculation itself.

 

In your case, you have a couple of options:

 

1. Write another measure than sums the original measure by State, and use this new measure in your visuals:

Dol Impact Summed by State = 
SUMX ( 
    VALUES ( FactTable[State] ),
    [Dol Impact]
)

 

2. Rewrite the original measure so that it sums by State:

Dol Impact =
SUMX (
    VALUES ( FactTable[State] ),
    VAR Vol1_Pct = [Volume Sel 1] / [Total Volume Sel 1]
    VAR Vol2_Pct = [Volume Sel 2] / [Total Volume Sel 2]
    VAR Pct_Diff = Vol1_Pct - Vol2_Pct
    VAR Vol_Impact = Pct_Diff * [Total Volume Sel 1]
    VAR AvgCost_Impact =
        IF ( [Volume Sel 1] <> 0, [Avg Cost Sel 1], [Avg Cost Sel 2] )
            - IF ( [Total Volume Sel 1] <> 0, [Total Avg Cost Sel 1], [Total Avg Cost Sel 2] )
    VAR Dollar_Impact = Vol_Impact * AvgCost_Impact
    RETURN
        Dollar_Impact
)

Notes:

  1. In this situation, the 2nd argument of SUMX should either consist of measures or be wrapped in CALCULATE (in order to trigger context transition so that State is applied as a filter). As far as I can see, all values calculated that would depend on the State filter are already measures so I think there is no need to add an explicit CALCULATE.
  2. Also, I can see that you might want to consider declaring a few extra variables to avoid repeated calculation of some of the sub-measures.

Regards,

Owen


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

View solution in original post

9 REPLIES 9
OwenAuger
Super User
Super User

Hi @Maxemus2000 

 

When you want a measure calculated at a certain granularity then summed, I would normally use SUMX.

The first argument of SUMX should be a table containing rows representing the granularity of the calculation (in your case State), and the second argument should be the calculation itself.

 

In your case, you have a couple of options:

 

1. Write another measure than sums the original measure by State, and use this new measure in your visuals:

Dol Impact Summed by State = 
SUMX ( 
    VALUES ( FactTable[State] ),
    [Dol Impact]
)

 

2. Rewrite the original measure so that it sums by State:

Dol Impact =
SUMX (
    VALUES ( FactTable[State] ),
    VAR Vol1_Pct = [Volume Sel 1] / [Total Volume Sel 1]
    VAR Vol2_Pct = [Volume Sel 2] / [Total Volume Sel 2]
    VAR Pct_Diff = Vol1_Pct - Vol2_Pct
    VAR Vol_Impact = Pct_Diff * [Total Volume Sel 1]
    VAR AvgCost_Impact =
        IF ( [Volume Sel 1] <> 0, [Avg Cost Sel 1], [Avg Cost Sel 2] )
            - IF ( [Total Volume Sel 1] <> 0, [Total Avg Cost Sel 1], [Total Avg Cost Sel 2] )
    VAR Dollar_Impact = Vol_Impact * AvgCost_Impact
    RETURN
        Dollar_Impact
)

Notes:

  1. In this situation, the 2nd argument of SUMX should either consist of measures or be wrapped in CALCULATE (in order to trigger context transition so that State is applied as a filter). As far as I can see, all values calculated that would depend on the State filter are already measures so I think there is no need to add an explicit CALCULATE.
  2. Also, I can see that you might want to consider declaring a few extra variables to avoid repeated calculation of some of the sub-measures.

Regards,

Owen


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

@OwenAuger,
Thank you for your help! I used option #1and it works great. I was previously trying to do SUMX after the return in Dol Impact measure calculation and it didn't work. Maybe I used the state component from a different table (rookie mistake).


I have one more question, if you don't mind answering.  Instead of State details, what if I want to do State and Store details? What do I need to add/change when I calculate the total sum using SUMX? 

@Maxemus2000 

That's good news 🙂

 

If you have State & Store defining your granularity, I would usually use SUMMARIZE to create a table of existing combinations and SUMX over that:

 

Dol Impact Summed by State = 
SUMX ( 
    SUMMARIZE( FactTable, FactTable[State], FactTable[Store] ),
    [Dol Impact]
)

Notes:

  • State & Store can be either in FactTable itself or in tables on the 1-side of a relationship with FactTable.
  • Another option is to use nested SUMXs over each dimension in turn: SUMX ( VALUES(...), SUMX ( VALUES(...), [Dol Impact] ) )

Regards,

Owen 🙂

 


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

@OwenAuger 
Thanks again for helping. I used nested SUMX and it gave me "NaN" as a result. I guess there might be some calculation error somewhere. 
On another hand, I have tried the SUMMARIZE solution you have provided, it gave me 0 as a total. Does this related to the "calculation error"? 

Also, can you educate me on why do I need to create another measure to calculate Total Dollar? I tried adding the same SUMX statement after RETURN in the Dol Impact and it gave me 0 instead of the total. 

Got the NaN error taking care of. 

 

Some of the data were blank and PBI doesn't like it when I do "A / B". So, I used DIVIDE(A, B, 0) instead. 

That's good 🙂
Is the SUMMARIZE method still giving a zero result?

To debug, I would create a table or matrix visual with both State & Store, plus the final measure using SUMMARIZE.

The individual measure values should sum to the total, and you will be able to see why they are offsetting to zero.


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

Yes, the summerize is still giving me 0. I put this in a matrix table and it shows all 0. 

 

Test =
SUMX(SUMMARIZE('Volume', 'Volume'[State], 'Volume'[Store]), 'Impact'[Dol Impact])

Thanks, not sure what's causing that, something in the logic of the [Dol Impact] calculation.

Can you share a sample pbix file (with sanitised data if needed) that shows this problem?

Regards,

Owen


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

Unfortunately, due to time crunch and data privacy, I can't share my original .pbix file and don't have enough time to replicate it with a mock data. The example is pretty much using the exact calculation I provided. As for now, the nested SUMX got the job done. I will look around for a the SUMMRIZE solution when I have time. Thank you for all of your help 🙂

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.