Standard deviation of correlation matrix

gt213

Board Regular
Joined
Jul 5, 2016
Messages
61
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.000.270.460.510.56
0.271.000.470.420.33
0.460.471.000.560.53
0.510.420.561.000.56
0.560.330.530.561.00

<colgroup><col span="5"></colgroup><tbody>
</tbody>
 

Excel Facts

Square and cube roots
The =SQRT(25) is a square root. For a cube root, use =125^(1/3). For a fourth root, use =625^(1/4).
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?
 
Upvote 0
Change the formula in those cells so they return blanks on and above the main diagonal. Blanks are ignored by STDEV.
 
Upvote 0
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:
Upvote 0
Try:


Book1
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
Cell Formulas
RangeFormula
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))}
Press CTRL+SHIFT+ENTER to enter array formulas.


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.
 
Upvote 0
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.
 
Upvote 0

Forum statistics

Threads
1,214,520
Messages
6,120,011
Members
448,935
Latest member
ijat

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top