Login     Register

        Contact Us     Search

XLeratorDB/windowing Documentation

SQL Server moving VARP function


MovingVARP

Updated: 31 Oct 2012


Use MovingVARP to calculate the population variance of column values in an ordered resultant table, without the need for a self-join. The population Variance 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].[MovingVARP](
  <@Val, float,>
 ,<@Offset, int,>
 ,<@RowNum, int,>
 ,<@Id, tinyint,>)
GO
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 population variance 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 MovingVARP calculation. @Id allows you to specify multiple MovingVARP 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.
·         To calculate moving population variance from the beginning as a dataset or a partition, use the RunningVARP function.
·         If @RowNum is equal to 1, MovingVARP is equal to zero
·         @RowNum must be in ascending order.
·         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 from a population and we want to calculate the population variance for the previous 4 rows and the current row in a window where the x-values are sorted in ascending order.
SELECT cast(x as money) as x
,cast(wct.MovingVARP(x,4,ROW_NUMBER() OVER (ORDER BY x ASC),NULL) as money) as [VARP]
FROM (
      SELECT 1,85.2968 UNION ALL
      SELECT 2,88.2566 UNION ALL
      SELECT 3,100.1934 UNION ALL
      SELECT 4,116.3052 UNION ALL
      SELECT 5,109.6867 UNION ALL
      SELECT 6,130.3847 UNION ALL
      SELECT 7,76.5458 UNION ALL
      SELECT 8,99.5511 UNION ALL
      SELECT 9,101.5546 UNION ALL
      SELECT 10,114.318 UNION ALL
      SELECT 11,100.2686 UNION ALL
      SELECT 12,110.5982 UNION ALL
      SELECT 13,91.4181 UNION ALL
      SELECT 14,118.5804 UNION ALL
      SELECT 15,126.6649 UNION ALL
      SELECT 16,103.8977 UNION ALL
      SELECT 17,82.2819 UNION ALL
      SELECT 18,123.3369 UNION ALL
      SELECT 19,98.9415 UNION ALL
      SELECT 20,89.1731
      ) s(rn,x)
This produces the following result.
                    x                  VARP
--------------------- ---------------------
              76.5458                  0.00
              82.2819                8.2257
              85.2968               13.1747
              88.2566               18.7608
              89.1731                20.919
              91.4181               10.1151
              98.9415                 21.18
              99.5511               23.3541
             100.1934               21.2686
             100.2686               11.3087
             101.5546                0.7593
             103.8977                2.3892
             109.6867               12.5745
             110.5982               17.7149
              114.318               21.5768
             116.3052               18.2951
             118.5804               11.3039
             123.3369                18.124
             126.6649               20.6763
             130.3847               26.4834
 
 


Copyright 2008-2024 Westclintech LLC         Privacy Policy        Terms of Service