Login     Register

        Contact Us     Search

XLeratorDB/windowing Documentation

SQL Server moving SUM function


MovingSUM

Updated: 31 Oct 2012


Use MovingSUM to calculate the sum of column values in an ordered resultant table, 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].[MovingSUM](
  <@Val, float,>
 ,<@Round, int,>
 ,<@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.
@Round
the number of decimals places to store the result. @Round is an expression of type int or of a type that can be implicitly converted to int.
@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 MovingSUM calculation. @Id allows you to specify multiple MovingSUM 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 a running sum from the beginning of a dataset or partition, use the RunningSUM function.
·         If @RowNum is equal to 1, MovingSUM is equal to @Val
·         @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 will calculate the moving balance for a check book comprising the 4 preceding rows and the current row. We will create a temporary table, #c, populate it with some data and then run the SELECT.
CREATE TABLE #c   (
   trn            int,
   cust_ref       varchar(5),
   date_trn       datetime,
   payee          varchar(20),
   amt_trn        money,
   PRIMARY KEY (trn)
      )
--Populate the table with some data
INSERT INTO #c VALUES (1,'DD','2011-12-23',NULL,1500)
INSERT INTO #c VALUES (2,'1200','2012-01-01','Car Leasing Company',-361.75)
INSERT INTO #c VALUES (3,'1201','2012-01-01','Mortgage Bank',-1129.23)
INSERT INTO #c VALUES (4,'DD','2012-01-08',NULL,1100)
INSERT INTO #c VALUES (5,'1202','2012-01-15','Gas Company',-108.49)
INSERT INTO #c VALUES (6,'1203','2012-01-15','Electric Company',-98.27)
INSERT INTO #c VALUES (7,'1204','2012-01-15','Telephone Company',-136.6)
INSERT INTO #c VALUES (8,'DD','2012-02-15',NULL,1100)
INSERT INTO #c VALUES (9,'1205','2012-02-01','Car Leasing Company',-361.75)
INSERT INTO #c VALUES (10,'1206','2012-02-01','Mortgage Bank',-1129.23)
INSERT INTO #c VALUES (11,'DD','2012-02-08',NULL,1100)
INSERT INTO #c VALUES (12,'1207','2012-02-15','Gas Company',-153.89)
INSERT INTO #c VALUES (13,'1208','2012-02-15','Electric Company',-121.99)
INSERT INTO #c VALUES (14,'1209','2012-02-15','Telephone Company',-138.92)
INSERT INTO #c VALUES (15,'DD','2012-02-23',NULL,1100)
INSERT INTO #c VALUES (16,'1210','2012-03-01','Car Leasing Company',-361.75)
INSERT INTO #c VALUES (17,'1211','2012-03-01','Mortgage Bank',-1129.23)
INSERT INTO #c VALUES (18,'DD','2012-03-08',NULL,1100)
INSERT INTO #c VALUES (19,'1212','2012-03-15','Gas Company',-70.79)
INSERT INTO #c VALUES (20,'1213','2012-03-15','Electric Company',-93.57)
INSERT INTO #c VALUES (21,'1214','2012-03-15','Telephone Company',-149.78)
INSERT INTO #c VALUES (22,'DD','2012-03-23',NULL,1100)
INSERT INTO #c VALUES (23,'1215','2012-04-01','Car Leasing Company',-361.75)
INSERT INTO #c VALUES (24,'1216','2012-04-01','Mortgage Bank',-1129.23)
INSERT INTO #c VALUES (25,'DD','2012-04-08',NULL,1100)
INSERT INTO #c VALUES (26,'1217','2012-04-15','Gas Company',-105.58)
INSERT INTO #c VALUES (27,'1218','2012-04-15','Electric Company',-149.36)
INSERT INTO #c VALUES (28,'1219','2012-04-15','Telephone Company',-145.35)
INSERT INTO #c VALUES (29,'DD','2012-04-23',NULL,1100)
INSERT INTO #c VALUES (30,'1220','2012-05-01','Car Leasing Company',-361.75)
INSERT INTO #c VALUES (31,'1221','2012-05-01','Mortgage Bank',-1129.23)
INSERT INTO #c VALUES (32,'DD','2012-05-08',NULL,1100)
INSERT INTO #c VALUES (33,'1222','2012-05-15','Gas Company',-96.27)
INSERT INTO #c VALUES (34,'1223','2012-05-15','Electric Company',-114.62)
INSERT INTO #c VALUES (35,'1224','2012-05-15','Telephone Company',-145.43)
INSERT INTO #c VALUES (36,'DD','2012-05-23',NULL,1100)
INSERT INTO #c VALUES (37,'1225','2012-06-01','Car Leasing Company',-361.75)
INSERT INTO #c VALUES (38,'1226','2012-06-01','Mortgage Bank',-1129.23)
INSERT INTO #c VALUES (39,'DD','2012-06-08',NULL,1100)
INSERT INTO #c VALUES (40,'1227','2012-06-15','Gas Company',-147.03)
INSERT INTO #c VALUES (41,'1228','2012-06-15','Electric Company',-130.52)
INSERT INTO #c VALUES (42,'1229','2012-06-15','Telephone Company',-147.71)
INSERT INTO #c VALUES (43,'DD','2012-06-23',NULL,1100)
INSERT INTO #c VALUES (44,'1230','2012-07-01','Car Leasing Company',-361.75)
INSERT INTO #c VALUES (45,'1231','2012-07-01','Mortgage Bank',-1129.23)
INSERT INTO #c VALUES (46,'DD','2012-07-08',NULL,1100)
--Calculate the running total
SELECT cast(convert(varchar, date_trn, 106) as char(11)) as date_trn
,cust_ref
,payee
,amt_trn
,wct.MovingSUM(amt_trn,2,4,trn,NULL) as [Moving Total]
FROM #c
--Clean up
DROP TABLE #c
 This produces the following result.
date_trn    cust_ref payee                              amt_trn           Moving Total
----------- -------- -------------------- --------------------- ----------------------
23 Dec 2011 DD       NULL                               1500.00                   1500
01 Jan 2012 1200     Car Leasing Company                -361.75                1138.25
01 Jan 2012 1201     Mortgage Bank                     -1129.23                   9.02
08 Jan 2012 DD       NULL                               1100.00                1109.02
15 Jan 2012 1202     Gas Company                        -108.49                1000.53
15 Jan 2012 1203     Electric Company                    -98.27                -597.74
15 Jan 2012 1204     Telephone Company                  -136.60                -372.59
15 Feb 2012 DD       NULL                               1100.00                1856.64
01 Feb 2012 1205     Car Leasing Company                -361.75                 394.89
01 Feb 2012 1206     Mortgage Bank                     -1129.23                -625.85
08 Feb 2012 DD       NULL                               1100.00                 572.42
15 Feb 2012 1207     Gas Company                        -153.89                 555.13
15 Feb 2012 1208     Electric Company                   -121.99                -666.86
15 Feb 2012 1209     Telephone Company                  -138.92                -444.03
23 Feb 2012 DD       NULL                               1100.00                 1785.2
01 Mar 2012 1210     Car Leasing Company                -361.75                 323.45
01 Mar 2012 1211     Mortgage Bank                     -1129.23                -651.89
08 Mar 2012 DD       NULL                               1100.00                  570.1
15 Mar 2012 1212     Gas Company                         -70.79                 638.23
15 Mar 2012 1213     Electric Company                    -93.57                -555.34
15 Mar 2012 1214     Telephone Company                  -149.78                -343.37
23 Mar 2012 DD       NULL                               1100.00                1885.86
01 Apr 2012 1215     Car Leasing Company                -361.75                 424.11
01 Apr 2012 1216     Mortgage Bank                     -1129.23                -634.33
08 Apr 2012 DD       NULL                               1100.00                 559.24
15 Apr 2012 1217     Gas Company                        -105.58                 603.44
15 Apr 2012 1218     Electric Company                   -149.36                -645.92
15 Apr 2012 1219     Telephone Company                  -145.35                -429.52
23 Apr 2012 DD       NULL                               1100.00                1799.71
01 May 2012 1220     Car Leasing Company                -361.75                 337.96
01 May 2012 1221     Mortgage Bank                     -1129.23                -685.69
08 May 2012 DD       NULL                               1100.00                 563.67
15 May 2012 1222     Gas Company                         -96.27                 612.75
15 May 2012 1223     Electric Company                   -114.62                -601.87
15 May 2012 1224     Telephone Company                  -145.43                -385.55
23 May 2012 DD       NULL                               1100.00                1843.68
01 Jun 2012 1225     Car Leasing Company                -361.75                 381.93
01 Jun 2012 1226     Mortgage Bank                     -1129.23                -651.03
08 Jun 2012 DD       NULL                               1100.00                 563.59
15 Jun 2012 1227     Gas Company                        -147.03                 561.99
15 Jun 2012 1228     Electric Company                   -130.52                -668.53
15 Jun 2012 1229     Telephone Company                  -147.71                -454.49
23 Jun 2012 DD       NULL                               1100.00                1774.74
01 Jul 2012 1230     Car Leasing Company                -361.75                 312.99
01 Jul 2012 1231     Mortgage Bank                     -1129.23                -669.21
08 Jul 2012 DD       NULL                               1100.00                 561.31
 


Copyright 2008-2024 Westclintech LLC         Privacy Policy        Terms of Service