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

Get inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.

Reply
asparagus1_
Frequent Visitor

Slow paginated report - The connection either timed out or was lost. Pareto Analysis

I have a dataset in a Paginated Report that runs slowly because it includes a Pareto analysis of products on a table with around 200,000 rows. When I analyze its DAX query, it takes approximately 10 minutes to execute. Of course, this is not an ideal execution time, but it is what it is.

The problem is that in the Paginated Report, even when I run the report with filters on the product table, it is unable to generate at all. I receive the following error:
"The connection either timed out or was lost. Query execution failed for dataset 'XXX'."

Is there anything I can do about this, or do I just have to keep optimizing the dataset's code?

This is the code:

DEFINE
VAR _TotalSales =
CALCULATE ( [Sales $], ALLSELECTED ( DimProducts[ID_Product] ) )

VAR _SortedProducts =
ADDCOLUMNS (
ALLSELECTED ( DimProducts[ID_Product] ),
"Sales", [Sales $]
)

VAR _SortedProductsRanked =
ADDCOLUMNS (
_SortedProducts,
"Rank", RANKX ( _SortedProducts, [Sales],, DESC, DENSE )
)

VAR _CumulativeSalesTable =
ADDCOLUMNS (
_SortedProductsRanked,
"CumulativeSales",
VAR CurrentRank = [Rank]
RETURN
SUMX (
FILTER ( _SortedProductsRanked, [Rank] <= CurrentRank ),
[Sales]
)
)

VAR _ProductsWithin80Percent =
FILTER (
_CumulativeSalesTable,
DIVIDE ( [CumulativeSales], _TotalSales, 0 ) <= 0.8
)

EVALUATE _ProductsWithin80Percent 

1 ACCEPTED SOLUTION
v-yiruan-msft
Community Support
Community Support

Hi @asparagus1_ ,

You can refer the following link to optimize the query first:

DAX Query Optimization Techniques for Faster Calculations in Power BI: Advanced Guide

DEFINE
    VAR _TotalSales =
        CALCULATE ( [Sales $], REMOVEFILTERS ( DimProducts[ID_Product] ) )
    VAR _ProductSales =
        SUMMARIZE (
            ALLSELECTED ( DimProducts ),
            DimProducts[ID_Product],
            "Sales", [Sales $]
        )
    VAR _SortedProductsRanked =
        ADDCOLUMNS (
            _ProductSales,
            "Rank", RANKX ( _ProductSales, [Sales],, DESC, DENSE )
        )
    VAR _CumulativeSalesTable =
        ADDCOLUMNS (
            _SortedProductsRanked,
            "CumulativeSales",
                VAR CurrentSales = [Sales]
                VAR CurrentRank = [Rank]
                RETURN
                    SUMX ( FILTER ( _SortedProductsRanked, [Rank] <= CurrentRank ), [Sales] )
        )

EVALUATE
FILTER (
    _CumulativeSalesTable,
    DIVIDE ( [CumulativeSales], _TotalSales, 0 ) <= 0.8
)

And increase the Query Timeout:

Set time-out values for Power BI paginated report dataset processing - Power BI | Microsoft Learn

vyiruanmsft_0-1741760997317.png

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

1 REPLY 1
v-yiruan-msft
Community Support
Community Support

Hi @asparagus1_ ,

You can refer the following link to optimize the query first:

DAX Query Optimization Techniques for Faster Calculations in Power BI: Advanced Guide

DEFINE
    VAR _TotalSales =
        CALCULATE ( [Sales $], REMOVEFILTERS ( DimProducts[ID_Product] ) )
    VAR _ProductSales =
        SUMMARIZE (
            ALLSELECTED ( DimProducts ),
            DimProducts[ID_Product],
            "Sales", [Sales $]
        )
    VAR _SortedProductsRanked =
        ADDCOLUMNS (
            _ProductSales,
            "Rank", RANKX ( _ProductSales, [Sales],, DESC, DENSE )
        )
    VAR _CumulativeSalesTable =
        ADDCOLUMNS (
            _SortedProductsRanked,
            "CumulativeSales",
                VAR CurrentSales = [Sales]
                VAR CurrentRank = [Rank]
                RETURN
                    SUMX ( FILTER ( _SortedProductsRanked, [Rank] <= CurrentRank ), [Sales] )
        )

EVALUATE
FILTER (
    _CumulativeSalesTable,
    DIVIDE ( [CumulativeSales], _TotalSales, 0 ) <= 0.8
)

And increase the Query Timeout:

Set time-out values for Power BI paginated report dataset processing - Power BI | Microsoft Learn

vyiruanmsft_0-1741760997317.png

Best Regards

Community Support Team _ Rena
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

FebPBI_Carousel

Power BI Monthly Update - February 2025

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

Feb2025 NL Carousel

Fabric Community Update - February 2025

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