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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
ElliotP
Post Prodigy
Post Prodigy

Correlation between same column, different items for time periods

Afternoon,

 

I'm trying to find the correlation between the [close] column values of the 'StockbarDataExample' table for different companies in the 'StockSymbolExchangeCode' column.

 

I'm not sure how to compare the two time series given they share the same column for values.

 

Pbix & Source Link: https://1drv.ms/f/s!At8Q-ZbRnAj8iF5lSSIdn2oi2tGj

1 ACCEPTED SOLUTION

@ElliotP

In this sort of "pairwise comparison" scenario, where you have multiple entities in the same table (in this case distinguished by StockSymbolCurrencyI would normally follow the below steps.

My modifed copy of your pbix is here:
https://www.dropbox.com/s/y9h2ncitj46ee6a/PowerBiForumExample2%20Owen%20edit.pbix?dl=0

 

  1. Create a copy of the entity dimension table, in your case a copy of ReferenceTable which I would call ReferenceTableComparison
  2. Create a relationship between StockBarDatExample and ReferenceTableComparison, but make it inactive
  3. Create the appropriate value measure that will be used for the company selected in ReferenceTable. For testing purposes I created
    Average Close = 
    AVERAGE ( StockBarDatExample[close] )
  4. Create the same measure for the Comparison Company, which activates the inactive relationship, and clears the filter on ReferenceTable:
    Average Close Comparison =
    CALCULATE (
        [Average Close],
        ALL ( ReferenceTable ),
        USERELATIONSHIP ( StockBarDatExample[StockSymbolCurrency], ReferenceTableComparison[StockSymbolCurrency] )
    )
  5. You can then selected Company & Comparison Company using slicers, and use Average Close & Average Close Comparison together in visuals.
  6. The Pearson Correlation Coefficient can be calculated using a method similar to that used here. This relies on having the above two measures set up.
    Here is the measure I tested with your data:
    Pearson Correlation Coefficient = 
    VAR DateTimes =
        // Create a table of date/times where both stocks have a Close value
        FILTER (
            SUMMARIZE ( StockBarDatExample, DateTable[DateKey], TimeTable[Column1] ), // Date & Time columns
            AND (
                NOT ( ISBLANK ( [Average Close] ) ),
                NOT ( ISBLANK ( [Average Close Comparison] ) )
            )
        )
    // Construct table of pairs of Close values
    VAR Known =
        SELECTCOLUMNS (
            DateTimes,
            "Known[X]", [Average Close],
            "Known[Y]", [Average Close Comparison]
        )
    // Calculate correlation coefficient
    VAR Count_Items =
        COUNTROWS ( Known )
    VAR Average_X =
        AVERAGEX ( Known, Known[X] )
    VAR Average_X2 =
        AVERAGEX ( Known, Known[X] ^ 2 )
    VAR Average_Y =
        AVERAGEX ( Known, Known[Y] )
    VAR Average_Y2 =
        AVERAGEX ( Known, Known[Y] ^ 2 )
    VAR Average_XY =
        AVERAGEX ( Known, Known[X] * Known[Y] )
    VAR CorrelationCoefficient =
        DIVIDE (
            Average_XY
                - Average_X * Average_Y,
            SQRT ( ( Average_X2 - Average_X ^ 2 ) * ( Average_Y2 - Average_Y ^ 2 ) )
        )
    RETURN
        CorrelationCoefficient

The test report page in the above pbix looks like this:image.png

 

 

 

Hopefully that helps. 🙂

 

Regards,

Owen


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

View solution in original post

7 REPLIES 7
v-shex-msft
Community Support
Community Support

HI @ElliotP,

 

You can use below formula to get diff between two legend:

Diff = 
VAR c1 =
    FIRSTNONBLANK ( ALL ( ReferenceTable[CompanyName] ), [CompanyName] )
VAR c2 =
    LASTNONBLANK ( ALL ( ReferenceTable[CompanyName] ), [CompanyName] )
RETURN
    ABS (
        CALCULATE (
            SUM ( StockBarDatExample[close] ),
            ReferenceTable[CompanyName] = c1
        )
            - CALCULATE (
                SUM ( StockBarDatExample[close] ),
                ReferenceTable[CompanyName] = c2
            )
    )

AFAIK, current line chart not support use multiple value field and legend at same time, I'd like to suggest you use 'line and clustered column chart' to instead.

15.PNG

 

 

Regards,

Xiaoxin Sheng

 

Community Support Team _ Xiaoxin
If this post helps, please consider accept as solution to help other members find it more quickly.

@v-shex-msftThanks for the response.

 

I'm not trying to calculate the difference between the different company's closes, but I think the principles might be able to work. I would like to be able to calculate the correlation between the time series data for each company; but I'm unable to at the moment as both time series values are in the same column ([close]), but they two time series are distinguishable by the 'StockSymbolCurrency' column string value.

 

The idea of using variables to seperate the time series values before returning a correlation figure is interesting, but I'm not sure how to get each variable to filter over subsequent different string values in the 'StockSymbolCurrency' column.

 

@ElliotP

In this sort of "pairwise comparison" scenario, where you have multiple entities in the same table (in this case distinguished by StockSymbolCurrencyI would normally follow the below steps.

My modifed copy of your pbix is here:
https://www.dropbox.com/s/y9h2ncitj46ee6a/PowerBiForumExample2%20Owen%20edit.pbix?dl=0

 

  1. Create a copy of the entity dimension table, in your case a copy of ReferenceTable which I would call ReferenceTableComparison
  2. Create a relationship between StockBarDatExample and ReferenceTableComparison, but make it inactive
  3. Create the appropriate value measure that will be used for the company selected in ReferenceTable. For testing purposes I created
    Average Close = 
    AVERAGE ( StockBarDatExample[close] )
  4. Create the same measure for the Comparison Company, which activates the inactive relationship, and clears the filter on ReferenceTable:
    Average Close Comparison =
    CALCULATE (
        [Average Close],
        ALL ( ReferenceTable ),
        USERELATIONSHIP ( StockBarDatExample[StockSymbolCurrency], ReferenceTableComparison[StockSymbolCurrency] )
    )
  5. You can then selected Company & Comparison Company using slicers, and use Average Close & Average Close Comparison together in visuals.
  6. The Pearson Correlation Coefficient can be calculated using a method similar to that used here. This relies on having the above two measures set up.
    Here is the measure I tested with your data:
    Pearson Correlation Coefficient = 
    VAR DateTimes =
        // Create a table of date/times where both stocks have a Close value
        FILTER (
            SUMMARIZE ( StockBarDatExample, DateTable[DateKey], TimeTable[Column1] ), // Date & Time columns
            AND (
                NOT ( ISBLANK ( [Average Close] ) ),
                NOT ( ISBLANK ( [Average Close Comparison] ) )
            )
        )
    // Construct table of pairs of Close values
    VAR Known =
        SELECTCOLUMNS (
            DateTimes,
            "Known[X]", [Average Close],
            "Known[Y]", [Average Close Comparison]
        )
    // Calculate correlation coefficient
    VAR Count_Items =
        COUNTROWS ( Known )
    VAR Average_X =
        AVERAGEX ( Known, Known[X] )
    VAR Average_X2 =
        AVERAGEX ( Known, Known[X] ^ 2 )
    VAR Average_Y =
        AVERAGEX ( Known, Known[Y] )
    VAR Average_Y2 =
        AVERAGEX ( Known, Known[Y] ^ 2 )
    VAR Average_XY =
        AVERAGEX ( Known, Known[X] * Known[Y] )
    VAR CorrelationCoefficient =
        DIVIDE (
            Average_XY
                - Average_X * Average_Y,
            SQRT ( ( Average_X2 - Average_X ^ 2 ) * ( Average_Y2 - Average_Y ^ 2 ) )
        )
    RETURN
        CorrelationCoefficient

The test report page in the above pbix looks like this:image.png

 

 

 

Hopefully that helps. 🙂

 

Regards,

Owen


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

Hi @OwenAuger,

Thank you for posting this dashboard!

I am trying to do something similar with multiple stocks. Your appraoch looks promising however I think the result you are getting is not correct in your example I believe the correlation should be 0.97714 instead of 0.94. It seems to be linked to the issue discussed in this thread 

 
When adjusting some of the underlying calculations I get the correct results for some of them but not for all. (for instance 
VAR Average_X2IF(COUNTROWS(Known)<>1,AVERAGEX(Known, Known[X] ^ 2 )) ) gives the expected result but the same adjustment on VAR Average_XY is not working.
Do you have any idea how to fix the calculation?
 
I have been looking into it but cannot wrap my head around it..
 
Léo

 

Hi @leo-community 

Thanks for your reply on this topic 🙂
My original reply created a measure that calculation the correlation coefficient based only on records where X and Y are both nonblank.

With that assumption, I believe the correlation coefficient of 0.94 is correct (can be tested by pasting data to Excel, removing rows where either X or Y is blank, and applying the CORREL function).

 

For your particular case, I'm not sure where the calculation is going wrong. It could possibly relate to how the Known table is constructed. Known should include only the rows to be included in the correlation coefficient calculation.

 

Could you post some more detail, even dummy data in a PBIX that illustrates when the calculation doesn't produce the expected result?

 

Regards,

Owen


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

@OwenAugerThank you so much, that's amazing.

 

As an extension, from an idea, would it be possible to do this for a large number of comparisions? I get the feeling that might be better done with python and then exploring the resultant table and data from that instead of trying to use a tabular model to achieve that?

You're welcome 🙂

There's nothing to stop you having an arbitrary number of stocks in your source table...and you could use a matrix visual to show the correlation of every combination, or use that Correlation Plot custom visual. Or create your own R visual I guess

 

Perhaps performance might be better if you prepare the data with python (or R?) rather than computing on the fly - though don't have much experience with that myself.


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
Twitter
LinkedIn

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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