Results 1 to 7 of 7

Thread: Standard deviation of correlation matrix
Thanks Thanks: 0 Likes Likes: 0

  1. #1
    Board Regular
    Join Date
    Jul 2016
    Posts
    59
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Standard deviation of correlation matrix

    I am looking to get the standard deviation of each correlation coefficient in a matrix.

    The matrix is complete (as in each pairwise correlation in included twice) but i want the standard deviation including only each coefficient once.

    The matrix will vary in size and can be quite large so i dont want to have to select the cells i need manually. Is there a way to do this?

    As an example with the below matrix i would want the std dev of only the underlined values:

    1.00 0.27 0.46 0.51 0.56
    0.27 1.00 0.47 0.42 0.33
    0.46 0.47 1.00 0.56 0.53
    0.51 0.42 0.56 1.00 0.56
    0.56 0.33 0.53 0.56 1.00

  2. #2
    Board Regular
    Join Date
    Dec 2018
    Location
    Poland
    Posts
    203
    Post Thanks / Like
    Mentioned
    5 Post(s)
    Tagged
    1 Thread(s)

    Default Re: Standard deviation of correlation matrix

    Hi,
    How to finger out which values take to std dev. calculation? You remove duplicates from the matrix and what is left you want to calculate std dev for them? Why you did not underline value 1.00?

  3. #3
    MrExcel MVP shg's Avatar
    Join Date
    May 2008
    Location
    The Great State of Texas
    Posts
    21,612
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    14 Thread(s)

    Default Re: Standard deviation of correlation matrix

    Change the formula in those cells so they return blanks on and above the main diagonal. Blanks are ignored by STDEV.

  4. #4
    Board Regular XOR LX's Avatar
    Join Date
    Jul 2012
    Location
    Turin, Italy
    Posts
    4,517
    Post Thanks / Like
    Mentioned
    5 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Standard deviation of correlation matrix

    Or, array formula**:

    =STDEV(IF(COLUMN(A1:E5)>ROW(A1:E5),A1:E5))


    **Array formulas are not entered in the same way as 'standard' formulas. Instead of pressing just ENTER, you first hold down CTRL and SHIFT, and only then press ENTER. If you've done it correctly, you'll notice Excel puts curly brackets {} around the formula (though do not attempt to manually insert these yourself).
    Last edited by XOR LX; Aug 16th, 2019 at 03:35 PM.
    Advanced Excel Techniques: http://excelxor.com/

  5. #5
    MrExcel MVP Eric W's Avatar
    Join Date
    Aug 2015
    Location
    Bountiful, UT
    Posts
    8,661
    Post Thanks / Like
    Mentioned
    42 Post(s)
    Tagged
    5 Thread(s)

    Default Re: Standard deviation of correlation matrix

    Try:

    ABCDEFGHIJ
    110.270.460.510.560.10089
    20.2710.470.420.33
    30.460.4710.560.53
    40.510.420.5610.56
    50.560.330.530.561
    6
    7
    8
    9
    10
    1110.270.460.510.560.10089
    120.2710.470.420.33
    130.460.4710.560.53
    140.510.420.5610.56
    150.560.330.530.561

    Sheet18



    Array Formulas
    CellFormula
    G1{=STDEV(IF(ROW(A1:E5)>COLUMN(A1:E5),A1:E5))}
    J11{=STDEV(IF(ROW(D11:H15)-ROW(D11)>COLUMN(D11:H15)-COLUMN(D11),D11:H15))}
    Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
    Note: Do not try and enter the {} manually yourself



    If your array starts in A1 (or B2, C3, D4, etc.) you can use the array formula in G1. If the array starts somewhere else, you need to adjust the formula as shown in J11.
    Cheers,
    Eric

    When you eliminate the impossible, whatever remains, however improbable, must be the truth.

    -Posting guidelines, forum rules, terms of use, FAQs, BB codes, See how to search the forum
    -Post a screen shot with the HTML Maker

  6. #6
    Board Regular
    Join Date
    Jul 2016
    Posts
    59
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Standard deviation of correlation matrix

    Thanks Eric, your solution works great.

    And just as a response to other suggestions that could have worked: For other calculation i do use the entire matrix so couldn't remove or blank those values out, and i didn't want to have 2 separate matrices if i could avoid it.

  7. #7
    MrExcel MVP Eric W's Avatar
    Join Date
    Aug 2015
    Location
    Bountiful, UT
    Posts
    8,661
    Post Thanks / Like
    Mentioned
    42 Post(s)
    Tagged
    5 Thread(s)

    Default Re: Standard deviation of correlation matrix

    Glad we could help.

Some videos you may like

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •