Get certified in Microsoft Fabric—for free! For a limited time, the Microsoft Fabric Community team will be offering free DP-600 exam vouchers. Prepare now
Hi I'm trying to create a running (cumulative) total on a set of data in a matrix table. My rows value isn't numeric so I can't use the formula that I see in all the examples I've been able to find.
The data looks like this (there are 7 days of data as the columns so there would be days for 6/28, 6/29, 6/30.....
Date Received 2016-06-28
Delivered Total Samples
-------------------------------------------
Before 12 | 7
Before 3 | 122
Before 5 | 192
Before 7 | 807
I'm trying to make another column for a running total (actually I'll be making a running percentage for the day but I'm trying to just get the simple runnng total to work first), the final result set would be something like this:
Date Received 2016-06-28
Delivered Total Samples Running Total Running Percentage
---------------------------------------------------------------------------------------
Before 12 | 7 7 0.62%
Before 3 | 122 129 11.44%
Before 5 | 192 321 28.46%
Before 7 | 807 1128 100.00%
If I change the row value to be a number I can get this to work with a formula like the following:
Running Total = CALCULATE(Sum('qrySpecimenTracking\'[Total Samples]),FILTER(ALL('qrySpecimenTracking\'[DeliveredSort]),'qrySpecimenTracking\'[DeliveredSort] <= Max('qrySpecimenTracking\'[DeliveredSort])))
But the actual column that I need for the row values isn't a numeric so won't evaluate in a DAX <= expression.
Thanks in advance for any help / suggestions.
Solved! Go to Solution.
There is definitely a (number of) easy way to do this, unless I'm missing something big. Here's one that I've tried on my machine:
I created an index column in addition to the Delivered column. You can name it whatever you want (the default name is Index and I'm lazy). Here's the formula I'm using for running total:
Running Total = CALCULATE(SUM(Query1[Total Samples]), FILTER(ALL(Query1), Query1[Index] <= EARLIER(Query1[Index])))
And here's the table it creates:
Another formula using the method I mentioned before (had to add the mod because 12 < 3, didn't clue into that before):
Running Total2 = CALCULATE(SUM(Query1[Total Samples]), FILTER(ALL(Query1), MOD(VALUE(RIGHT(Query1[Delivered], LEN(Query1[Delivered]) - SEARCH(" ", Query1[Delivered]))), 12) <= MOD(VALUE(RIGHT(EARLIER(Query1[Delivered]), LEN(EARLIER(Query1[Delivered])) - SEARCH(" ", EARLIER(Query1[Delivered])))), 12)))
That gives exactly the same result as above (on my end at least), the formula is definitely more convoluted but it saves you a column. Hope one of those suits your purposes.
You will find it quite hard to do any calculations without the data being a value. Can you go back to the query editor and change the data type to values or alternatively a calculated column to turn the data into values with =VALUE().
Hi samdthompson,
Thank you for the reply. I have done that, and as mentioned above if I change the value of "Delivered" to be 1,2,3,4 representing the text values then this works properly, the issue with that is that I then lose the meaning in the row values in the matrix. If I have both the value representation and the text representation as row values then it doesn't create a running total. It shows the number per the value for "Delivered". It will only show the running total if I turn on Total row under the general properties.
I'm not sure that using Values will help, since that will return a number multiplied by the number of rows that made up the summary value and I always want the order to be as I have it in my example.
It seems strange that this is so difficult in DAX when it was very easy using QlikSense and even SSRS.
Thanks again for taking the time to reply and for the insight.
If you're fundamentally against changing the table structure, maybe you can parse that column to get a numeric value from it every time you need it? Eg. VALUE(RIGHT([Delivered], LEN([Delivered]) - SEARCH(" ", [Delivered])))
Hi jahida,
Thank you for the reply. I'm not against changing the structure of the returned data but per my reply to samdthompson above that has some difficulties as well. I don't think the Value function will help based on trying it (again see my previous post) but I will try some more variations of using it.
Thanks again for taking the time to reply and for your suggestions. I'm glad to know I didn't miss something obvious, hopefully this will be a feature enhancement in an upcoming release.
There is definitely a (number of) easy way to do this, unless I'm missing something big. Here's one that I've tried on my machine:
I created an index column in addition to the Delivered column. You can name it whatever you want (the default name is Index and I'm lazy). Here's the formula I'm using for running total:
Running Total = CALCULATE(SUM(Query1[Total Samples]), FILTER(ALL(Query1), Query1[Index] <= EARLIER(Query1[Index])))
And here's the table it creates:
Another formula using the method I mentioned before (had to add the mod because 12 < 3, didn't clue into that before):
Running Total2 = CALCULATE(SUM(Query1[Total Samples]), FILTER(ALL(Query1), MOD(VALUE(RIGHT(Query1[Delivered], LEN(Query1[Delivered]) - SEARCH(" ", Query1[Delivered]))), 12) <= MOD(VALUE(RIGHT(EARLIER(Query1[Delivered]), LEN(EARLIER(Query1[Delivered])) - SEARCH(" ", EARLIER(Query1[Delivered])))), 12)))
That gives exactly the same result as above (on my end at least), the formula is definitely more convoluted but it saves you a column. Hope one of those suits your purposes.
Check out the October 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
108 | |
108 | |
108 | |
90 | |
61 |
User | Count |
---|---|
171 | |
138 | |
132 | |
102 | |
86 |