cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
shobhitgupta Regular Visitor
Regular Visitor

Need help in optimizing Dax query

Hi Team,

 

I need help in optimizing this query that i am writing in dax 

 

Debug Avg =
AVERAGEX(SUMMARIZE(approxtable,approxtable[Customer_ID],"s",CALCULATE(DIVIDE(SUM(approxtable[Sales]),DISTINCTCOUNT(approxtable[Customer_ID]),0),PATHCONTAINS(TRIM(SUBSTITUTE(SUBSTITUTE(VALUES(approxtable[Control_Id]), ",","|")," ","")),approxtable[Customer_ID]))),[s])

 

 

 

1 ACCEPTED SOLUTION

Accepted Solutions
shobhitgupta Regular Visitor
Regular Visitor

Re: Need help in optimizing Dax query

Hey, i got the solution. In the previous query, PathContains were taking too long as it has a callback during query execution.

So I did change my query to this

 

AVERAGEX(SUMMARIZE(approxtable,approxtable[Customer_ID],"S",
VAR OrderList = TRIM(SUBSTITUTE(SUBSTITUTE(VALUES(approxtable[Control_Id]),",","|")," ",""))
VAR OrderCount = PATHLENGTH ( OrderList )
VAR HandleNullCount = IF(OrderCount>0,OrderCount,1)
VAR NumberTable = GENERATESERIES ( 1, HandleNullCount, 1 )
VAR OrderTable =
GENERATE (
NumberTable,
VAR CurrentKey = [Value]
RETURN
ROW ( "Key", PATHITEM ( OrderList, CurrentKey ) )
)
VAR GetKeyColumn = SELECTCOLUMNS ( OrderTable, "Key", [Key] )
VAR FilterTable = TREATAS ( GetKeyColumn, approxtable[Customer_ID] )
RETURN
CALCULATE(SUM(approxtable[Sales]), FilterTable )),[S])

 

 

This query executes pretty fast. 

Thanks 

4 REPLIES 4
Moderator v-qiuyu-msft
Moderator

Re: Need help in optimizing Dax query

Hi @shobhitgupta,

 

Please modify it as below:

 

Debug Avg =
AVERAGEX (
    SUMMARIZE (
        approxtable,
        approxtable[Customer_ID],
        "s", IF (
            PATHCONTAINS (
                TRIM (
                    SUBSTITUTE (
                        SUBSTITUTE ( VALUES ( approxtable[Control_Id] ), ",", "|" ),
                        " ",
                        ""
                    )
                ),
                approxtable[Customer_ID]
            )
                = TRUE,
            DIVIDE (
                SUM ( approxtable[Sales] ),
                DISTINCTCOUNT ( approxtable[Customer_ID] ),
                0
            )
        )
    ),
    [s]
)

 

Best Regards,
Qiuyun Yu 

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

Re: Need help in optimizing Dax query

@v-qiuyu-msft Hi thanks for replying.

 

But somehow this query is not returning any output.

shobhitgupta Regular Visitor
Regular Visitor

Re: Need help in optimizing Dax query

Hey, i got the solution. In the previous query, PathContains were taking too long as it has a callback during query execution.

So I did change my query to this

 

AVERAGEX(SUMMARIZE(approxtable,approxtable[Customer_ID],"S",
VAR OrderList = TRIM(SUBSTITUTE(SUBSTITUTE(VALUES(approxtable[Control_Id]),",","|")," ",""))
VAR OrderCount = PATHLENGTH ( OrderList )
VAR HandleNullCount = IF(OrderCount>0,OrderCount,1)
VAR NumberTable = GENERATESERIES ( 1, HandleNullCount, 1 )
VAR OrderTable =
GENERATE (
NumberTable,
VAR CurrentKey = [Value]
RETURN
ROW ( "Key", PATHITEM ( OrderList, CurrentKey ) )
)
VAR GetKeyColumn = SELECTCOLUMNS ( OrderTable, "Key", [Key] )
VAR FilterTable = TREATAS ( GetKeyColumn, approxtable[Customer_ID] )
RETURN
CALCULATE(SUM(approxtable[Sales]), FilterTable )),[S])

 

 

This query executes pretty fast. 

Thanks 

shobhitgupta Regular Visitor
Regular Visitor

Re: Need help in optimizing Dax query

Is it possible to improve query performance or achieve this in some other manner as this query is still running slow.

Helpful resources

Announcements
Community Kudopalooza

Win Power BI Swag with Community Kudopalooza!

Each week, complete activities and be qualified in the drawing for cool Power BI Swag.

Summit North America

Power Platform Summit North America

Register by September 5 to save $200

Virtual Launch Event

Microsoft Business Applications Virtual Launch Event

Watch the event on demand for an in-depth look at the new innovations across Dynamics 365 and the Microsoft Power Platform.

MBAS Gallery

Watch Sessions On Demand!

Continue your learning in our online communities.

Users Online
Currently online: 133 members 1,900 guests
Please welcome our newest community members: