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

Join 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.

Reply
Anonymous
Not applicable

Help with optimizing DAX measure

Hello everybody,

 

I have a Fact table that contains 200Millions rows

I need to optimize this measure to improve response times ,the calculation of my measures takes too much time to compute (6 to 7 seconds everytime you click on something. I tried to do it with two different formulas :

KPI 1 =  SUMX(DISTINCT(SUMMARIZE(FILTER('Fact_Table','Fact_Table'[level]="Low"),'Fact_Table'[id_cv],'FACT_Table'[Server_id])),1)

KPI 2 = countrows(SUMMARIZE(FILTER('Fact_Table','Fact_Table'[level]="Low"),'Fact_Table'[id_cv],'Fact_Table'[Server_id]))

but the response time is almost the same which is 7 seconds.

anyone have a best prosposition?

 

Any help with this would be appreciated.

Thank you 

 

 

1 ACCEPTED SOLUTION
PaulOlding
Solution Sage
Solution Sage

Hi @Anonymous 

Unfortunately these don't look like particularly inefficient queries to me. (Obviously without seeing the real data).

 

The immediate thing that springs to mind is an aggregation table, so the query can be run on a table with much less than 200m rows.  https://docs.microsoft.com/en-us/power-bi/transform-model/aggregations-advanced 

 

However, you'll immediately hit a limitation of agg tables: your 'Fact Table' would need to be in DirectQuery mode.  This article explains a workaround for that: https://dax.tips/2019/11/15/creative-aggs-part-vi-shadow-models/ 

View solution in original post

8 REPLIES 8
AlexisOlson
Super User
Super User

Do any of these columns exist in a dimension table or are they all exclusive to the 'Fact_Table'? Summarizing over dimensions is likely faster.

 

Is your situation such that you could use SUMMARIZECOLUMNS here?

KPI =
COUNTROWS (
    SUMMARIZECOLUMNS (
        'Fact_Table'[id_cv],
        'Fact_Table'[Server_id],
        TREATAS ( { "Low" }, 'Fact_Table'[level] )
    )
)

 

You could also try counting one or the other summarized columns using DISTINCTCOUNT or SUMX:

KPI 1 =
SUMX (
    SUMMARIZECOLUMNS (
        'Fact_Table'[id_cv],
        TREATAS ( { "Low" }, 'Fact_Table'[level] ),
        "@Rows", CALCULATE ( DISTINCTCOUNT ( 'Fact_Table'[Server_id] ) )
    ),
    [@Rows]
)

KPI 2 =
SUMX (
    SUMMARIZECOLUMNS (
        'Fact_Table'[Server_id],
        TREATAS ( { "Low" }, 'Fact_Table'[level] ),
        "@Rows", CALCULATE ( SUMX ( VALUES ( 'Fact_Table'[id_cv] ), 1 ) )
    ),
    [@Rows]
)
PaulOlding
Solution Sage
Solution Sage

Hi @Anonymous 

Unfortunately these don't look like particularly inefficient queries to me. (Obviously without seeing the real data).

 

The immediate thing that springs to mind is an aggregation table, so the query can be run on a table with much less than 200m rows.  https://docs.microsoft.com/en-us/power-bi/transform-model/aggregations-advanced 

 

However, you'll immediately hit a limitation of agg tables: your 'Fact Table' would need to be in DirectQuery mode.  This article explains a workaround for that: https://dax.tips/2019/11/15/creative-aggs-part-vi-shadow-models/ 

Anonymous
Not applicable

@PaulOlding @smpa01 : thank you both for your help i will try the solution with the aggregation table to decrease the data volume and reduce the response time.

@Anonymous  I second with @PaulOlding; as much as any DAX enthusiast would love optimizing an inefficient measure, 6sec for a 200 mil dataset does not sound unreasonable unless you bring an aggregated table from the server and run the measure which will astronomically reduce the evaluation time.

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs
Jihwan_Kim
Super User
Super User

Hi,

Please try the below.

 

KPI 2 =
COUNTROWS (
CALCULATETABLE (
SUMMARIZE ( 'Fact_Table', 'Fact_Table'[id_cv], 'Fact_Table'[Server_id] ),
FILTER ( 'Fact_Table', 'Fact_Table'[level] = "Low" )
)
)


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.


Click here to visit my LinkedIn page

Click here to schedule a short Teams meeting to discuss your question.
Anonymous
Not applicable

Hello @Jihwan_Kim , 

Nina_nax_0-1637939520958.png

Unfortunately, it takes too much time to compute 21seconds

smpa01
Super User
Super User

@Anonymous  does this improve?

 

 

KPI 1 =
COUNTROWS (
    FILTER (
        SUMMARIZE (
            'Fact_Table',
            'Fact_Table'[level],
            'Fact_Table'[id_cv],
            'FACT_Table'[Server_id]
        ),
        'Fact_Table'[level] = "Low"
    )
)

 

 

or this

 

 

KPI1 =
COUNTROWS (
    CALCULATETABLE (
        SUMMARIZE ( 'Table', 'Table'[Server_id], 'Table'[id_cv], 'Table'[level] ),
        KEEPFILTERS ( 'Table'[level] = "Low" )
    )
)

 

@Anonymous  please test out the above two

Did I answer your question? Mark my post as a solution!
Proud to be a Super User!
My custom visualization projects
Plotting Live Sound: Viz1
Beautiful News:Viz1, Viz2, Viz3
Visual Capitalist: Working Hrs
Anonymous
Not applicable

@smpa01 thanks for your answer.

Unfortunately no, the response time is the same: 6 seconds

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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