cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
MarkSL
Helper IV
Helper IV

DAX to create a Trend line?

Hi,

 

I really want to add a Trend Line to a Line and stacked column chart, however the Analytics options aren't availabe for this type of visual.  Is it possible to create a Trend using DAX , the same as using TREND function in Excel?

 

I can add one to a standard line chart:

 

Trend on Line ChartTrend on Line Chart

 

 

 

 

 

 

 

 

 

 

 

 

But I would really like it on my Line and Stacked column chart:

 

Line and Stacked column chartLine and Stacked column chart

The formula would need to take into account any slicers which change the date range.

 

Any thoughts / tips greatly appreciated!

 

Mark

 

 

1 ACCEPTED SOLUTION

Hi @MarkSL

 

Just tested it out and the issue is with ALLSELECTED ( 'DateTable'[Date] ). It doesn't work as intended when you filter on a column other that Date, such as Month.

 

One possible fix is the change in red below.

I have restated your entire code for completeness.

 

That should work (tested a mock-up model at my end) but let me know if it doesn't

 

Oh, by the way, there is a "Combine Series" setting for trendlines that determines whether each series gets its own trend line.

 

Regards,

Owen

 

Estimated Sales =
VAR Known =
    FILTER (
        SELECTCOLUMNS (
            CALCULATETABLE ( VALUES ( 'DateTable'[Date] ), ALLSELECTED ('DateTable') ),
            "Known[X]", 'DateTable'[Date],
            "Known[Y]", [SalesDaily2]
        ),
        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 ( 'DateTable'[Date] ),
    Intercept + Slope * 'DateTable'[Date]
)

Owen Auger

Did I answer your question? Mark my post as a solution!

My Blog
Connect on Twitter
Connect on LinkedIn

View solution in original post

11 REPLIES 11
Anonymous
Not applicable

Hi all in my case I wanted to get it done in a different context than date. So below you'll find the lines that can be adjusted to any context: Just by changing the measure and the context

TrendIN(SimpleLinearRegression) =
//external measure "imonthsinrow=CALCULATE(DISTINCTCOUNT(tMasterCalendar[YearMonth]);FILTER(ALLSELECTED(tMasterCalendar);tMasterCalendar[Date]<=MAX(tMasterCalendar[Date])))"

Var i=CALCULATE(DISTINCTCOUNT(tMasterCalendar[YearMonth]);ALLSELECTED(tMasterCalendar))
//Calaculates count of month in selected period

Var avgx=CALCULATE(AVERAGEX(VALUES(tMasterCalendar[YearMonth]);[iMonthsinrow]);ALLSELECTED(tMasterCalendar))
//Calaculates avg i value on selected period

Var avgy=CALCULATE(AVERAGEX(VALUES(tMasterCalendar[YearMonth]);[IN]);ALLSELECTED(tMasterCalendar))
// Calaculates avg IN value on selected period

Var Slope=DIVIDE(
CALCULATE(SUMX(VALUES(tMasterCalendar[YearMonth]);([iMonthsinrow]-avgx)*([IN]-avgy));ALLSELECTED(tMasterCalendar));
CALCULATE(SUMX(VALUES(tMasterCalendar[YearMonth]);([iMonthsinrow]-avgx)^2);ALLSELECTED(tMasterCalendar)))
//Calculating a in y=ax+b

Var b=avgy-Slope*avgx //Calculating b in y=ax+b

Return
b+[iMonthsinrow]*Slope
OwenAuger
Super User I
Super User I

@MarkSL

There are a couple of articles I know of on linear regression with DAX which might cover what you are wanting to do:

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

https://social.technet.microsoft.com/wiki/contents/articles/32628.dax-simple-linear-regression-patte...


Owen Auger

Did I answer your question? Mark my post as a solution!

My Blog
Connect on Twitter
Connect on LinkedIn

Thanks both for the quick replies.  

 

Owen, I tried the second Dax example from your first link (Other ways to use the pattern) and I seem to have created my trend line as desired!  However, it has raised another question about the provided Trend Line provided in Analytics...

 

I first added my new calculated trend line (yellow) to the my Line chart to check that it matched the previously applied automatic trend line (dashed), but found that it sat above it and not on it:

 

pb3.png

 

So I initially thought something was not quite right.  However, when I removed the Budget line (red) from the chart, the automatic Trend line moved to sit exactly on my created trend line:

 

pb4.png

 

On looking at the automatic Trend line provided by Analytics, it doesn't ask which measure (line) on the chart you want the trend to be based on, which seems a bit odd to me?  I assume that it must be based on both measures, Sales and Budget?

 

Anyway, I don't require the Line chart as my trend line is now showing as desired on my Line and Bar chart which is what I really wanted:

 

pb5.png

 

I would be interested to hear your thoughts on the automatic Trend line moving though?

 

Thanks

 

Mark

Ah, I may have spoken to soon of success...

 

It appears that when I filter on month, to reduce the dataset, my calculated trend does not match the automatic trend.  However, if I filter on another field, such as customer, the two lines do still match??  I am very new to DAX and so am not sure why this is happening?

 

Here is the code for the calculated trend:

 

Estimated Sales = 
VAR Known =
    FILTER (
        SELECTCOLUMNS (
            ALLSELECTED ( 'DateTable'[Date] ),
            "Known[X]", 'DateTable'[Date],
            "Known[Y]", [SalesDaily2]
        ),
        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 ( 'DateTable'[Date] ),
        Intercept + Slope * 'DateTable'[Date]
    )

 

Thanks again.

Hi @MarkSL

 

Just tested it out and the issue is with ALLSELECTED ( 'DateTable'[Date] ). It doesn't work as intended when you filter on a column other that Date, such as Month.

 

One possible fix is the change in red below.

I have restated your entire code for completeness.

 

That should work (tested a mock-up model at my end) but let me know if it doesn't

 

Oh, by the way, there is a "Combine Series" setting for trendlines that determines whether each series gets its own trend line.

 

Regards,

Owen

 

Estimated Sales =
VAR Known =
    FILTER (
        SELECTCOLUMNS (
            CALCULATETABLE ( VALUES ( 'DateTable'[Date] ), ALLSELECTED ('DateTable') ),
            "Known[X]", 'DateTable'[Date],
            "Known[Y]", [SalesDaily2]
        ),
        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 ( 'DateTable'[Date] ),
    Intercept + Slope * 'DateTable'[Date]
)

Owen Auger

Did I answer your question? Mark my post as a solution!

My Blog
Connect on Twitter
Connect on LinkedIn

View solution in original post

Hi Owen, 

 

Thanks for the fantastic code! 

I used your code to create a trend line, it's working great, but only calculates a trend for the entire dataset. I have a list of facilities, and I want the trend line to dynamically update when I select different facilities using a page level filter. I'm trying to change this so it can adapt to visual filters, but not much luck, and hope you might be able to help. Thanks a lot in advane!

Cheers,

Michael 

Hi @OwenAuger

 

Brilliant, thank you very much for looking at this and finding the fix.  My calculated trend line now matches that of the automatic trend line when using all filters; Customer & Month.

 

Thanks also for alerting me to the Combine Series option.

 

Regards

 

Mark

 

 

ThomasDay
Impactful Individual
Impactful Individual

Hello @OwenAuger, I wonder if I could get a little help here on what surely seems to be an easy situation but confounding me nonetheless.

 

I'm looking to create a column in one table with the slope of trended metrics from another. 

 

  • One table (on the right) is current values of providers and associated metrics which I use for all sorts of things.  I'd like to add  a column with the slope of the trend for each provider/metric combination.  There are ~600 metrics for each of ~4000 hospitals to compute a slope for.
  • The other table (on the left) is a table of trend values...of these provider/metric combinations.  So it contains the same ~600 metrics over as many as 8 years for the same ~4000 hospitals. 
  • Each table has a Variable_Name and Provdrno.  I want to use the Provdrno AND Variable name from the row in the Right Table to give me the selection of trend values in the LEFT Table.  Seems eacy enough

TablesInModel.png

  • So I've read what seem to be the relevant posts....and tried a variety of attacks.  Here's the one that does seem promising.
TempSlope = 
VAR RowMetric = SelectedValue(HospMeasures[Variable_Name])
VAR RowProviderID = SelectedValue(HospMeasures[PROVDRNO])

VAR Known =
        SELECTCOLUMNS (
            CALCULATETABLE ( ALL(TR_MeasureTrends),  TR_MeasureTrends[PROVDRNO] = RowProviderID , Tr_MeasureTrends[Variable_Name] = RowMetric 
			),
            "Known[X]", Tr_MeasureTrends[FY_Trend] ,
            "Known[Y]", Tr_MeasureTrends[Variable_Value]
        )
VAR Count_Items =
    COUNTROWS ( Known )
VAR Sum_X =
    SUMX ( Known, VALUE(Known[X]) )
VAR Sum_X2 =
    SUMX ( Known, VALUE(Known[X]) ^ 2 )
VAR Sum_Y =
    SUMX ( Known, Known[Y] )
VAR Sum_XY =
    SUMX ( Known, VALUE(Known[X]) * Known[Y] )
VAR Average_X =
    AVERAGEX ( Known, VALUE(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
    )
RETURN
Slope

Unfortunately every row has the same value!  ugggg.....It's very mysterious.

I believe the codes does the following

  • creates VAR's for the relevant row info (ProvdrNo and Variable_Name)
  • Select columns from the trend table where I
    • clear all filters at the row level,
    • filter for the proper provdrno and variable_name
    • select the two columns I need for the slope calculation
    • convert the FY_date column to a number as required.
    • Do the calcs.

Yet every value is identical.  As I thrashed around, the table name only did not yield any values, ALLSELECTED in any form did not yield any values (Yes, that was crazy)....so I'm stumped.

 

Suggestions?  Thank you in advance,

Tom

@ThomasDay

At a glance, I can see two fixes to make:

  1. There is no need to use SELECTEDVALUE when defining RowMetric and RowProviderID, as you can access the required values by direct column references. This is by virtue of the row context you have when defining a calculated column. If you use SELECTEDVALUE, you will get blank result as there is an "unfiltered" filter context when defining a calculated column.
  2. The expression CALCULATETABLE ( ALL(TR_MeasureTrends), ... ) will always return all rows of TR_MeasureTrends, effectively ignoring the filter arguments provided to CALCULATETABLE. Get rid of the ALL and this should work as intended.
    I am assuming there are not relationships between the two tables by the way (appeared to be the case from the screenshot).

The first few rows of the corrected DAX should look like this:

TempSlope = 
VAR RowMetric = HospMeasures[Variable_Name]
VAR RowProviderID = HospMeasures[PROVDRNO]

VAR Known =
        SELECTCOLUMNS (
            CALCULATETABLE ( TR_MeasureTrends,  TR_MeasureTrends[PROVDRNO] = RowProviderID , Tr_MeasureTrends[Variable_Name] = RowMetric 
			),
            "Known[X]", Tr_MeasureTrends[FY_Trend] ,
            "Known[Y]", Tr_MeasureTrends[Variable_Value]
        )
...

Does that fix the problem?

 

Regards,

Owen


Owen Auger

Did I answer your question? Mark my post as a solution!

My Blog
Connect on Twitter
Connect on LinkedIn
ThomasDay
Impactful Individual
Impactful Individual

@OwenAuger  Yes, thank you very much

TomMartens
Super User II
Super User II

Hey,

 

depending on the complextiy of the algorithm you want to use, a proper DAX statement can be become very hard, but calculating some kind of moving average might get you started.

 

Here is a post that might provide some ideas:

https://community.powerbi.com/t5/Desktop/Moving-Average/td-p/43041

 

Regards

Tom



Did I answer your question? Mark my post as a solution, this will help others!

Proud to be a Super User!
I accept Kudos 😉
Hamburg, Germany

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS Attendee Badge

Claim Your Badge & Digital Swag!

Check out how to claim yours today!

secondImage

Are You Ready?

Test your skills now with the Cloud Skills Challenge.

Top Solution Authors