MCOV_q
Updated: 30 September 2013
Use MCOV_q to calculate the covariance matrix of a de-normalized matrix.
The covariance of a matrix (A) is calculated by subtracting the column mean (µ) from each element in a column, calculating XTX and then dividing the result by n-1, where n is the number of rows. For example:
Syntax
SELECT * FROM [wctMath].[wct].[MCOV_q](
<@Matrix_RangeQuery, nvarchar(max),>)
Arguments
@Matrix_RangeQuery
the SELECT statement, as text, used to determine the matrix to be used in this function. The SELECT statement specifies the column names from the table or view or can be used to enter the matrix values directly. Data returned from the @Matrix_RangeQuery select must be of the type float or of a type that implicitly converts to float.
Return Types
TABLE (
[RowNum] [int] NULL,
[ColNum] [int] NULL,
[ItemValue] [float] NULL
Remarks
· Use the MCOV function for simpler queries.
· Use MCOVN_q for a table in 3rd normal form.
· If the array contains NULL, then NULL will be returned.
· The function returns an error if the array contains a non-numeric value.
· If the supplied input is a vector, then result will be the (sample) variance.
Examples
In this example, we calculate the matrix covariance directly from the SELECT statement.
SELECT *
FROM wct.MCOV_q('SELECT * FROM (VALUES (1,1,1,1,1,1,1,1),(2,3,4,5,6,7,8,9),(4,9,16,25,36,49,61,81))n(x1,x2,x3,x4,x5,x6,x7,x8)')
Here are the first few rows of the result table.
Let's put several matrices into a table and calculate the covariance matrix for each. We will use CROSS APPLY to calculate to the covariance matrix for matrix. Note that we have to convert the Matrix identifier (which is defined as int) to a varchar to include it in the where clause of the @Matrix_RangeQuery. This would not be necessary in the MCOV function.
SET NOCOUNT ON
CREATE TABLE #c(
Matrix int,
rn int,
x1 float,
x2 float,
x3 float,
PRIMARY KEY (Matrix, rn)
)
INSERT INTO #c VALUES (100,1,-11,-41,36)
INSERT INTO #c VALUES (100,2,-31,41,-47)
INSERT INTO #c VALUES (100,3,48,-38,33)
INSERT INTO #c VALUES (100,4,8,44,-10)
INSERT INTO #c VALUES (101,1,39,6,-7)
INSERT INTO #c VALUES (101,2,33,-49,16)
INSERT INTO #c VALUES (101,3,14,29,13)
INSERT INTO #c VALUES (101,4,35,-38,-50)
INSERT INTO #c VALUES (101,5,9,-32,-25)
INSERT INTO #c VALUES (102,1,29,49,-17)
INSERT INTO #c VALUES (102,2,35,28,28)
INSERT INTO #c VALUES (102,3,-34,-29,-49)
INSERT INTO #c VALUES (102,4,0,-5,0)
INSERT INTO #c VALUES (102,5,-17,14,24)
INSERT INTO #c VALUES (102,6,44,3,-23)
SELECT n.MATRIX
,k.*
FROM (SELECT DISTINCT MATRIX FROM #c)n
CROSS APPLY wct.MCOV_q('SELECT x1,x2,x3 FROM #c WHERE MATRIX = ' + cast(n.Matrix as varchar(max)) + ' ORDER by rn')k
DROP TABLE #c
Here are the first few rows of the resultant table.