MovingRSQ
Updated: 31 Oct 2012
Use the RunningRSQ function to calculate the square of the Pearson product moment correlation coefficient through data points in y- and x-values within a resultant table or partition, without the need for a self-join. The correlation coefficient 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].[MovingRSQ](
<@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 MovingRSQ calculation. @Id allows you to specify multiple MovingRSQ 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 square of the correlation coefficient over an entire dateset or partition of x- and y-values use the RunningRSQ function.
· If @RowNum = 1 then MovingRSQ is NULL.
· To calculated a single square of the correlation coefficient value for a set of x- and y-values, use the RSQ 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 square of the correlation coefficient in the relationship between square footage and house prices with a window of 5 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 RSQ
SELECT id_lot
,amt_sqft
,amt_price
,wct.MovingRSQ(amt_price,amt_sqft,4, ROW_NUMBER() OVER (ORDER BY amt_sqft),NULL) as RSQ
FROM #se
ORDER BY amt_sqft
--Clean up
DROP TABLE #se
This produces the following result.
id_lot amt_sqft amt_price RSQ
----------- ----------- ----------- ----------------------
88397 1105 374348 NULL
56812 1145 408634 1
21783 1147 393918 0.783257864773169
97646 1162 388196 0.368403412063324
33431 1195 434542 0.727882157885411
94729 1313 470479 0.858219817556916
33028 1433 512474 0.947832266975737
44167 1510 529806 0.946979790889771
49030 1521 555713 0.972282310016996
13588 1555 559149 0.953657577768376
90957 1585 563947 0.867549572489563
17262 1587 552178 0.4346426911753
75533 1628 592533 0.550975592643655
12897 1632 589522 0.768226450695132
59446 1724 610477 0.815145688873511
13891 1775 623900 0.846900842420089
30929 1809 633141 0.991096003827821
44823 1813 636916 0.993459323073404
93826 1850 668852 0.870912190454448
74510 1867 633400 0.307574009542869