Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Hi PBI Community,
I am building a dashboard where Running Total (based on percentage of emission) need to be shown. This visual would be effected by various filters such as region, country and others.
Following is the measure that works, however the computing time is in excess of 1 minute and unable to compute if the dashboard is published (Visual has exceeded the available resources).
Attached is the sample pbix File. (Data has 59k rows) RunningTotal Power BI File
Carbon RT % =
VAR CarbonRT = CALCULATE([Carbon Sum],FILTER(ALLSELECTED(Emission[Building Name]),SUM(Emission[Carbon])<=[Carbon Sum]))
VAR CarbonTotal = CALCULATE(SUM(Emission[Carbon]),ALLSELECTED(Emission[Building Name]))
VAR CarbonPercentage = DIVIDE(CarbonRT,CarbonTotal)
Return CarbonPercentage
Is there any way I can optimise the measure to run faster or other alternative approach?
Of course limiting the table visual does help in performance, however the requirement is to display the overall table.
Appreciate your input.
Solved! Go to Solution.
Hi,
Please try something like below.
I don't think it improved extremely, but it did improve a little.
Please check if it suits your requirement.
Running total % =
VAR _carbontotal =
CALCULATE ( [Carbon Sum], ALLSELECTED ( Emission[Building Name] ) )
VAR _newtable =
ADDCOLUMNS (
ALLSELECTED ( Emission[Building Name] ),
"@carbonsum", [Carbon Sum]
)
VAR _cumulatetable =
ADDCOLUMNS (
_newtable,
"@cumulatesum",
SUMX (
FILTER ( _newtable, [@carbonsum] >= EARLIER ( [@carbonsum] ) ),
[@carbonsum]
),
"@total", _carbontotal
)
RETURN
MAXX (
FILTER (
ADDCOLUMNS ( _cumulatetable, "@result", DIVIDE ( [@cumulatesum], [@total] ) ),
Emission[Building Name] = MAX ( Emission[Building Name] )
),
[@result]
)
If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.
Schedule a short Teams meeting to discuss your question.
Hi @Jihwan_Kim , brilliant, your solutions works well and significantly reduced the calculation time! thank you.
@ppm1 thanks for the support. Yes, it is alot of data! but unfortunately that is the requirement to facilitate discussion. Will surely keep the limit in mind.
Nice improvement, @Jihwan_Kim . I wrote almost the same measure before I saw your response. @MyKr note that while improving the DAX is great, the real issue on performance is that you have a visual that has >11K rows. If you are creating a visual for people to export data, that's one thing. Otherwise, you may want to consider a report design that limits the # of rows in the table at any given time.
Pat
Hi,
Please try something like below.
I don't think it improved extremely, but it did improve a little.
Please check if it suits your requirement.
Running total % =
VAR _carbontotal =
CALCULATE ( [Carbon Sum], ALLSELECTED ( Emission[Building Name] ) )
VAR _newtable =
ADDCOLUMNS (
ALLSELECTED ( Emission[Building Name] ),
"@carbonsum", [Carbon Sum]
)
VAR _cumulatetable =
ADDCOLUMNS (
_newtable,
"@cumulatesum",
SUMX (
FILTER ( _newtable, [@carbonsum] >= EARLIER ( [@carbonsum] ) ),
[@carbonsum]
),
"@total", _carbontotal
)
RETURN
MAXX (
FILTER (
ADDCOLUMNS ( _cumulatetable, "@result", DIVIDE ( [@cumulatesum], [@total] ) ),
Emission[Building Name] = MAX ( Emission[Building Name] )
),
[@result]
)
If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.
Schedule a short Teams meeting to discuss your question.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
14 | |
10 | |
10 | |
10 | |
9 |
User | Count |
---|---|
20 | |
13 | |
12 | |
11 | |
8 |