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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

Drawing trend line with categorical X axis [DAX]

Hi, I have a simple table:

RankPrice
110
215
33
457
523
641
712
835
921

TREND1.png

I´d like to write a measure that returns a trend line. 

 

I´ve read several posts but none helped.

https://community.powerbi.com/t5/Desktop/DAX-to-create-a-Trend-line/m-p/398438/highlight/true#M18188...

https://community.powerbi.com/t5/Desktop/Trend-line-x-axis/m-p/218665#M96973

https://xxlbi.com/blog/simple-linear-regression-in-dax/

 

This measure:

Simple linear regression = 
VAR Known =
    FILTER (
        SELECTCOLUMNS (
            CALCULATETABLE( VALUES( 'Table'[Rank] ); ALLSELECTED ( 'Table'[Rank] ) );
            "Known[X]"; 'Table'[Rank];
            "Known[Y]"; SUM( 'Table'[Price] )
        );
        AND (
            NOT ( ISBLANK ( Known[X] ) );
            NOT ( ISBLANK ( Known[Y] ) )
        )
    )
VAR Count_Items =
    COUNTROWS ( Known )
VAR Sum_X =
    SUMX ( Known; Known[X] )
VAR Sum_X2 =
    SUMX ( Known; Known[X] ^ 2 )
VAR Sum_Y =
    SUMX ( Known; Known[Y] )
VAR Sum_XY =
    SUMX ( Known; Known[X] * Known[Y] )
VAR Average_X =
    AVERAGEX ( Known; Known[X] )
VAR Average_Y =
    AVERAGEX ( Known; Known[Y] )
VAR Slope =
    DIVIDE (
        Count_Items * Sum_XY - Sum_X * Sum_Y;
        Count_Items * Sum_X2 - Sum_X ^ 2
    )
VAR Intercept =
    Average_Y - Slope * Average_X
RETURN
    SUMX (
        DISTINCT ( 'Table'[Rank] );
        Intercept + Slope * 'Table'[Rank]
    )

Returns the same line:

TREND2.png

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @amitchandak, thanks for the tip, it helped me get the answer.

 

ALL(Known) does not work because you can´t use ALL with a table expression.

 

VAR Sum_X =
    SUMX ( ALL ( Known ); Known[X] )

 

 

So I created two calculated columns:

 

Rank_2 = 'Table'[Rank] * 'Table'[Rank]
Rank_Price = 'Table'[Rank] * 'Table'[Price]

 

TREND11.png

And used the measure with the table reference:

 

Simple linear regression = 
VAR Count_Items =
    CALCULATE( COUNTROWS ( 'Table' ); ALL( 'Table' ) )
VAR Sum_X =
    SUMX ( ALL( 'Table' ); 'Table'[Rank] )
VAR Sum_X2 =
    SUMX (  ALL( 'Table' ); 'Table'[Rank_2] )
VAR Sum_Y =
    SUMX (  ALL( 'Table' ); 'Table'[Price] )
VAR Sum_XY =
    SUMX (  ALL( 'Table' ); 'Table'[Rank_Price] )
VAR Average_X =
    AVERAGEX (  ALL( 'Table' ); 'Table'[Rank] )
VAR Average_Y =
    AVERAGEX (  ALL( 'Table' ); 'Table'[Price] )
VAR Slope =
    DIVIDE (
        Count_Items * Sum_XY - Sum_X * Sum_Y;
        Count_Items * Sum_X2 - Sum_X ^ 2
    )
VAR Intercept =
    Average_Y - Slope * Average_X
RETURN
    SUMX (
        DISTINCT ( 'Table'[Rank] );
        Intercept + Slope * 'Table'[Rank]
    )

 

 

yayyay

 

Edit: Corrected measure, now works ok.

View solution in original post

2 REPLIES 2
amitchandak
Super User
Super User

@Anonymous . Check your formula, put values in table visual, and check. I think it taking row context.

Where possible put all(known) at place known and check

Anonymous
Not applicable

Hi @amitchandak, thanks for the tip, it helped me get the answer.

 

ALL(Known) does not work because you can´t use ALL with a table expression.

 

VAR Sum_X =
    SUMX ( ALL ( Known ); Known[X] )

 

 

So I created two calculated columns:

 

Rank_2 = 'Table'[Rank] * 'Table'[Rank]
Rank_Price = 'Table'[Rank] * 'Table'[Price]

 

TREND11.png

And used the measure with the table reference:

 

Simple linear regression = 
VAR Count_Items =
    CALCULATE( COUNTROWS ( 'Table' ); ALL( 'Table' ) )
VAR Sum_X =
    SUMX ( ALL( 'Table' ); 'Table'[Rank] )
VAR Sum_X2 =
    SUMX (  ALL( 'Table' ); 'Table'[Rank_2] )
VAR Sum_Y =
    SUMX (  ALL( 'Table' ); 'Table'[Price] )
VAR Sum_XY =
    SUMX (  ALL( 'Table' ); 'Table'[Rank_Price] )
VAR Average_X =
    AVERAGEX (  ALL( 'Table' ); 'Table'[Rank] )
VAR Average_Y =
    AVERAGEX (  ALL( 'Table' ); 'Table'[Price] )
VAR Slope =
    DIVIDE (
        Count_Items * Sum_XY - Sum_X * Sum_Y;
        Count_Items * Sum_X2 - Sum_X ^ 2
    )
VAR Intercept =
    Average_Y - Slope * Average_X
RETURN
    SUMX (
        DISTINCT ( 'Table'[Rank] );
        Intercept + Slope * 'Table'[Rank]
    )

 

 

yayyay

 

Edit: Corrected measure, now works ok.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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