MovingCOVAR
Updated: 31 Oct 2012
Use the MovingCOVARfunction to calculate the covariance through data points in y- and x-values within a resultant table or partition, without the need for a self-join. The covariance is calculated for each value from the first value in the window to the last value in the window.If the column values are presented to the functions out of order, an error message will be generated.
Syntax
SELECT [Example].[wct].[MovingCOVAR](
<@Y, float,>
,<@X, float,>
,<@Offset, int,>
,<@RowNum, int,>
,<@Id, tinyint,>)
GO
Arguments
@Y
the y-value passed into the function. @Y is an expression of type float or of a type that can be implicitly converted to float.
@X
the x-value passed into the function. @X is an expression of type float or of a type that can be implicitly converted to float.
@Offset
specifies the window size. @Offset is an expression of type int or of a type that can be implicitly converted to int.
@RowNum
the number of the row within the group for which the sum is being calculated. If @RowNum for the current row in a set is less than or equal to the previous @RowNum and @RowNum is not equal to 1, an error message will be generated. @RowNum is an expression of type int or of a type that can be implicitly converted to int.
@Id
a unique identifier for the RunningCOVAR calculation. @Id allows you to specify multiple RunningCOVAR calculations within a resultant table. @Id is an expression of type tinyint or of a type that can be implicitly converted to tinyint.
Remarks
· If @Id is NULL then @Id = 0.
· @RowNum must be in ascending order.
· To calculate the covariance over a dataset or a partition of x- and y-values use the RunningCOVAR function.
· If @RowNum = 1 then MovingCOVAR is 0.
· To calculate a single covariance value for an entire set of data use the COVAR function.
· There may be cases where the order in which the data are returned to the function and the order in which the results are returned are different, generally due to parallelism. You can use OPTION(MAXDOP 1) or OPTION(MAXDOP 1,FORCE ORDER) to help eliminate this problem.
Example
In this example we will calculate the covariance between square footage and house prices and sort the results square footage order, setting the offset to 5, meaning that the covariance will be calculated using the data from the current row and the 5 preceding rows. We will create a temporary table, #se, populate it with some data and then run the SELECT.
--Create the temporary table
CREATE TABLE #se(
rn int,
id_lot int,
amt_sqft int,
amt_price int,
PRIMARY KEY (rn)
)
--Put some date in the table
INSERT INTO #se VALUES (1,21783,1147,393918)
INSERT INTO #se VALUES (2,94729,1313,470479)
INSERT INTO #se VALUES (3,33028,1433,512474)
INSERT INTO #se VALUES (4,59446,1724,610477)
INSERT INTO #se VALUES (5,97646,1162,388196)
INSERT INTO #se VALUES (6,44823,1813,636916)
INSERT INTO #se VALUES (7,88397,1105,374348)
INSERT INTO #se VALUES (8,13588,1555,559149)
INSERT INTO #se VALUES (9,13891,1775,623900)
INSERT INTO #se VALUES (10,90957,1585,563947)
INSERT INTO #se VALUES (11,44167,1510,529806)
INSERT INTO #se VALUES (12,75533,1628,592533)
INSERT INTO #se VALUES (13,56812,1145,408634)
INSERT INTO #se VALUES (14,12897,1632,589522)
INSERT INTO #se VALUES (15,93826,1850,668852)
INSERT INTO #se VALUES (16,74510,1867,633400)
INSERT INTO #se VALUES (17,17262,1587,552178)
INSERT INTO #se VALUES (18,30929,1809,633141)
INSERT INTO #se VALUES (19,49030,1521,555713)
INSERT INTO #se VALUES (20,33431,1195,434542)
--Calculate CORREL
SELECT id_lot
,amt_sqft
,amt_price
,wct.MovingCOVAR(amt_price,amt_sqft,5, ROW_NUMBER() OVER (ORDER BY amt_sqft),NULL) as COVAR
FROM #se
ORDER BY amt_sqft
--Clean up
DROP TABLE #se
This produces the following result.
id_lot amt_sqft amt_price COVAR
----------- ----------- ----------- ----------------------
88397 1105 374348 0
56812 1145 408634 342860
21783 1147 393918 240438.666666667
97646 1162 388196 157500.5
33431 1195 434542 508489.52
94729 1313 470479 2013107.52777778
33028 1433 512474 4587664.91666667
44167 1510 529806 7377202.83333333
49030 1521 555713 8034186.77777778
13588 1555 559149 5711850.58333333
90957 1585 563947 2915236
17262 1587 552178 860241.916666667
75533 1628 592533 634965.611111111
12897 1632 589522 514731.277777778
59446 1724 610477 1033523.5
13891 1775 623900 1636727.08333333
30929 1809 633141 2053910.58333333
44823 1813 636916 1411478.02777778
93826 1850 668852 1655476.38888889
74510 1867 633400 625968.944444445