SEMI-covariance matrix in VBA - Help needed!

-Arsenal-

New Member
Joined
Jun 19, 2010
Messages
10
Hello, I am new to VBA and I want to write a code that computes the semi-covariance matrix of my return data..

The semicovariance between two stocks (i and j) is calculated as below:

average of: (min(Ri - avg(Ri), 0) * (min(Rj - avg(Rj), 0)

where Ri and Rj are the return observations of stocks i and j respectively..

Using Excel functions, I have calculated the semicovariance between stocks i and j using the following formula:

=AVERAGE((IF(Ri-avg(Ri)<0;Ri-avg(Ri);0)*IF(Rj - avg(Rj)<0;Rj - avg(Rj);0))

Now I have 7 stocks and I would like to write a VBA code that calculates the semicovariance MATRIX between the 7 stocks. I know how to write the code for the regular covariance matrix, but that was easy because I can call the Excel function "Covar" directly...

This is my code for the regular covariance matrix:
---------------------------
Option Base 1

Function VarCovar(rng As Range) As Variant
Dim i As Integer
Dim j As Integer
Dim numCols As Integer
numCols = rng.Columns.Count
Dim matrix() As Double
ReDim matrix(numCols, numCols)

For i = 1 To numCols
For j = 1 To numCols
matrix(i, j) = Application.WorksheetFunction.Covar(rng.Columns(i), rng.Columns(j))
Next j
Next i
VarCovar = matrix
End Function
---------------------------

Can anyone help me with suggestions for a SEMIcovariance matrix VBA code??

Thank you in advance
 

Excel Facts

Can you AutoAverage in Excel?
There is a drop-down next to the AutoSum symbol. Open the drop-down to choose AVERAGE, COUNT, MAX, or MIN
With data (4 series instead of 7) generated with help of RAND function in Cells B2:E11
Excel Workbook
ABCDE
1Series -->1234
21.2423.3974.8624.92
31.8673.1384.0415.7
42.3963.6593.1756.527
53.1292.1276.2016.292
61.4825.1554.2735.933
71.3495.366.8286.125
82.8414.3555.2447.739
94.8354.2128.4957.197
104.7686.7268.87610.406
111.2567.6718.5265.65
12
130.2322990.255529
14
150.5529840.2322990.4554690.495077
160.2322990.9573050.6490480.400123
170.4554690.6490481.5960720.508207
180.4950770.4001230.5082070.528775
...

The semi-covariance of Series 1 with Series 2 using your formula:
#VALUE!
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note that the result is different if the ",0" is left off of the IF function:
#VALUE!
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Then substituting :
INDEX(B:B,ROW(B$11)
for:
B2:B11
and substituting:
INDEX($B$2:$E$11,0,ROW(A1))
for:
C2:C11
results in:
#VALUE!
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
This formula is copied down and over.
You are probably only interested in the Cells with Bold font.

What are you trying to accomplish by converting this to CODE?
Do you need to do that?
 
Upvote 0
Thanks a lot for your help :), I appreciate the effort... However, I know how it's done manually.. I need to code it in Vba because I will have to do this 150 times as a rolling window analysis...

Can you help me?

Thanks
 
Upvote 0
This can be converted to code.

The semi-covariance matrix could be rearranged to fit in Row 2 to the right of the data.
The semi-covariance matrix could be calculated either with each Cell Formula pasted in and then converted to values, or by converting it to Code.

Say that a new row of data comes in at Row 2 and moves the existing Rows 2 to 11 down to 3 to 12, along with the semi-covariance matrix to the right in Row 2.
The semi-covariance matrix could be calculated again for Rows 2 to 11.

The same macro that brings in the new data could shift everything down a row and calculate the semi-covariances again.

If the number of series will change, this would be more easily adjustable if the semi-covariance matrix is in a row were entirely calculated with Code instead of Cell Formulas.

Alternatively, if you already have the complete series of data, you can rearrange the semi-covariance formulas into rows, and copy down the columns, and code is not really needed.
 
Last edited:
Upvote 0
Thanks, actually there is more to it than the semicovariance matrix because I will have to optimize portfolio weights 150 times... That's why I would prefer to code it as it involves calling the solver 150 times...

However, I know how to call it from vba.. My problem is writing the code for the semicovariance matrix.. If you could show me, that would solve my problem right away :)
 
Upvote 0
It is simpler to paste a formula in than it is to convert the formula to Code.
This should get you started with the matrix.
The data, 7 series with 10 rows, is on Sheet1 (named "A" here).
The Semi-covariance matrix goes on Sheet2.
The Code would not paste this formula:

{=AVERAGE(IF(A!B$2:B$11-AVERAGE(A!B$2:B$11)<0,A!B$2:B$11-AVERAGE(A!B$2:B$11),0)*IF(INDEX(A!$B$2:$H$11,0,ROW(A1))-AVERAGE(INDEX(A!$B$2:$H$11,0,ROW(A1)))<0,INDEX(A!$B$2:$H$11,0,ROW(A1))-AVERAGE(INDEX(A!$B$2:$H$11,0,ROW(A1)))),0)}

But the Code does paste this formula, where A!B$2:B$11 is substituted with a Named Formula "Kolumn".
#VALUE!
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Excel Workbook
NameRefers To
Kolumn=A!B$2:B$11
Workbook Defined Names

The Named Formula is redefined every time the macro is run, in case a Row is inserted in the data.

Code:
Sub SemiCoVariance()
ActiveWorkbook.Names.Add Name:="Kolumn", RefersToR1C1:="=A!R2C:R11C"
Range("B2").FormulaArray = "=AVERAGE(IF(Kolumn-AVERAGE(Kolumn)<0,Kolumn-AVERAGE(Kolumn),0)*IF(INDEX(A!$B$2:$H$11,0,ROW(A1))-AVERAGE(INDEX(A!$B$2:$H$11,0,ROW(A1)))<0,INDEX(A!$B$2:$H$11,0,ROW(A1))-AVERAGE(INDEX(A!$B$2:$H$11,0,ROW(A1)))),0)"
Range("B2").AutoFill Range("B2").Resize(7, 1)
Range("B2").Resize(7, 1).AutoFill Range("B2").Resize(7, 7)
End Sub
Excel Workbook
ABCDEFGH
1Series -->1234567
21.243.44.864.927.567.899.38
31.873.144.045.77.286.698.06
42.43.663.186.537.789.4110.65
53.132.136.26.296.9410.087.89
61.485.164.275.935.666.889.65
71.355.366.836.135.947.6912.04
82.844.365.247.7410.7410.810.1
94.844.218.57.29.748.299.47
104.776.738.8810.4110.4413.399.47
111.267.678.535.6510.3711.2710.86
A
Excel Workbook
ABCDEFGH
1Semi-CoV -->1234567
20.5537590.2321640.4562590.4957650.6300990.6939680.153866
30.2321640.9569590.6492970.4007380.5299810.51120.688849
40.4562590.6492971.5972370.5095240.7913410.9951450.368782
50.4957650.4007380.5095240.5298360.5170180.6599350.273956
60.6300990.5299810.7913410.5170181.3922681.1865740.418989
70.6939680.51120.9951450.6599351.1865741.5620080.487182
80.1538660.6888490.3687820.2739560.4189890.4871820.607619
Sheet2
<<<<<<<<<<<<<<<<<<<<<<<<
In Post #2 it was not necessary to do this substitution:
Then substituting :
INDEX(B:B,ROW(B$11)
for:
B2:B11<<<<<<<<<<<<<<<<<<<<<<<<
 
Upvote 0

Forum statistics

Threads
1,223,958
Messages
6,175,628
Members
452,661
Latest member
Nonhle

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