MovingSKEW_S
Updated: 30 Jun 2013
Use MovingSKEW_S to calculate the sample skewness of column values in an ordered resultant table, without the need for a self-join. The sample skewness 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 [westclintech].[wct].[MovingSKEW_S](
<@Val, float,>
,<@Offset, int,>
,<@RowNum, int,>
,<@Id, tinyint,>
,<@Exact, bit,>)
Arguments
@Val
the value passed into the function. @Val 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 sample skewness 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 MovingSKEW_S calculation. @Id allows you to specify multiple moving sample skewness calculations within a resultant table. @Id is an expression of type tinyint or of a type that can be implicitly converted to tinyint.
@Exact
a bit value which tells the function whether or not to return a NULL value if the number of rows in the window is smaller the @Offset value. If @Exact is 'True' and the number of rows in the window is less the @Offset then a NULL is returned. @Exact is an expression of type bit or of a type that can be implicitly converted to bit.
Remarks
· If @Id is NULL then @Id = 0.
· To calculate the sample skewnesss from the beginning of a dataset or a partition, use the RunningSKEW_S function.
· To calculate the sample skewness for an entire data set or for an entire group within a data set use the SKEWNESS_S function.
· If @RowNum is equal to 1, MovingSKEW_S is equal to zero
· @RowNum must be in ascending order.
· If @Exact IS NULL then @Exact = 'True'
· 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 have 20 rows of data and we want to caculate the sample skewness of x and y over a window of 10 rows. Note that the @Id value for each MovingSKEW_S column is different. Since @Exact is NULL, NULL is returned when the window size is less than @Offset.
SELECT rn
,x
,y
,wct.MovingSKEW_S(x,10,ROW_NUMBER() OVER (ORDER BY RN), NULL, NULL) as [SKEW_S x]
,wct.MovingSKEW_S(y,10,ROW_NUMBER() OVER (ORDER BY RN), 1, NULL) as [SKEW_S y]
FROM (
SELECT 1,101,117 UNION ALL
SELECT 2,91,97 UNION ALL
SELECT 3,96,121 UNION ALL
SELECT 4,96,103 UNION ALL
SELECT 5,86,74 UNION ALL
SELECT 6,95,80 UNION ALL
SELECT 7,91,105 UNION ALL
SELECT 8,102,72 UNION ALL
SELECT 9,94,108 UNION ALL
SELECT 10,110,94 UNION ALL
SELECT 11,121,85 UNION ALL
SELECT 12,115,90 UNION ALL
SELECT 13,112,96 UNION ALL
SELECT 14,100,97 UNION ALL
SELECT 15,124,106 UNION ALL
SELECT 16,92,61 UNION ALL
SELECT 17,92,107 UNION ALL
SELECT 18,139,92 UNION ALL
SELECT 19,95,101 UNION ALL
SELECT 20,90,104
)n(rn,x,y)
This produces the following result.
rn x y SKEW_S x SKEW_S y
----------- ----------- ----------- ---------------------- ----------------------
1 101 117 NULL NULL
2 91 97 NULL NULL
3 96 121 NULL NULL
4 96 103 NULL NULL
5 86 74 NULL NULL
6 95 80 NULL NULL
7 91 105 NULL NULL
8 102 72 NULL NULL
9 94 108 NULL NULL
10 110 94 0.709070384461684 -0.265262411674905
11 121 85 1.36146445787439 0.104993410561881
12 115 90 0.749274659058095 0.266318851864608
13 112 96 0.293908599297531 -0.16363737288765
14 100 97 0.197238751736898 -0.122523512296876
15 124 106 0.178510875817704 -0.488214761604669
16 92 61 0.136126557362551 -0.997513919258227
17 92 107 0.162322630484642 -0.957122741074495
18 139 92 0.456886861121799 -1.48335843277309
19 95 101 0.469106142570146 -1.67275702228855
20 90 104 0.585697590853893 -1.70767986720321
This example uses the same data as the previous example, however @Exact has been set to 'FALSE'.
SELECT rn
,x
,y
,wct.MovingSKEW_S(x,10,ROW_NUMBER() OVER (ORDER BY RN), NULL, 'FALSE') as [SKEW_S x]
,wct.MovingSKEW_S(y,10,ROW_NUMBER() OVER (ORDER BY RN), 1, 'FALSE') as [SKEW_S y]
FROM (
SELECT 1,101,117 UNION ALL
SELECT 2,91,97 UNION ALL
SELECT 3,96,121 UNION ALL
SELECT 4,96,103 UNION ALL
SELECT 5,86,74 UNION ALL
SELECT 6,95,80 UNION ALL
SELECT 7,91,105 UNION ALL
SELECT 8,102,72 UNION ALL
SELECT 9,94,108 UNION ALL
SELECT 10,110,94 UNION ALL
SELECT 11,121,85 UNION ALL
SELECT 12,115,90 UNION ALL
SELECT 13,112,96 UNION ALL
SELECT 14,100,97 UNION ALL
SELECT 15,124,106 UNION ALL
SELECT 16,92,61 UNION ALL
SELECT 17,92,107 UNION ALL
SELECT 18,139,92 UNION ALL
SELECT 19,95,101 UNION ALL
SELECT 20,90,104
)n(rn,x,y)
This produces the following result.
rn x y SKEW_S x SKEW_S y
----------- ----------- ----------- ---------------------- ----------------------
1 101 117 NULL NULL
2 91 97 NULL NULL
3 96 121 0 -1.54539252569502
4 96 103 0 -0.129678815660363
5 86 74 -0.404796008910937 -0.864550209720429
6 95 80 -0.547871643589443 -0.179587851309798
7 91 105 -0.179812666650052 -0.384309637141165
8 102 72 -0.183091963166346 -0.0994544316100889
9 94 108 -0.124285714285718 -0.331171026292889
10 110 94 0.709070384461684 -0.265262411674905
11 121 85 1.36146445787439 0.104993410561881
12 115 90 0.749274659058095 0.266318851864608
13 112 96 0.293908599297531 -0.16363737288765
14 100 97 0.197238751736898 -0.122523512296876
15 124 106 0.178510875817704 -0.488214761604669
16 92 61 0.136126557362551 -0.997513919258227
17 92 107 0.162322630484642 -0.957122741074495
18 139 92 0.456886861121799 -1.48335843277309
19 95 101 0.469106142570146 -1.67275702228855
20 90 104 0.585697590853893 -1.70767986720321