April 6, 2017 at 3:44 am
I have the following dataset:
CREATE TABLE #mytable (
PartNum varchar(50),
DueDate datetime,
RequirementFlag tinyint,
Quantity decimal(22,8))
INSERT INTO #mytable
(PartNum, DueDate, RequirementFlag, Quantity)
SELECT '00-5472',20/03/2017,1,-261.00000000 UNION ALL
SELECT '00-5472',29/03/2017,1,-270.00000000 UNION ALL
SELECT '00-5472',05/04/2017,1,-270.00000000 UNION ALL
SELECT '00-5472',05/04/2017,1,-270.00000000 UNION ALL
SELECT '00-5472',06/04/2017,0,-1500.00000000 UNION ALL
SELECT '00-5472',10/04/2017,1,-270.00000000 UNION ALL
SELECT '00-5472',10/04/2017,1,-6.00000000 UNION ALL
SELECT '00-5472',11/04/2017,1,-30.00000000 UNION ALL
SELECT '00-5472',11/04/2017,1,-120.00000000 UNION ALL
SELECT '00-5472',12/04/2014,1,-540.00000000 UNION ALL
SELECT '00-5472',13/04/2017,1,-120.00000000 UNION ALL
SELECT '00-5472',18/04/2017,1,-30.00000000 UNION ALL
SELECT '00-5472',04/05/2017,1,-200.00000000 UNION ALL
SELECT '00-5472',04/05/2017,1,-200.00000000 UNION ALL
SELECT '00-5472',04/05/2017,1,-200.00000000 UNION ALL
SELECT '00-5472',04/05/2017,1,-200.00000000;
I want to produce a running total per line but I cannot get what I am looking for.
I am creating this as a View on a table called PartDtl1 on my database.
Here is what I have tried so far:
SELECT TOP (100) PERCENT PartNum, DueDate, RequirementFlag, Quantity,
(SELECT SUM(Quantity) AS Expr1
FROM dbo.View_PartDtl1 AS b
WHERE (PartNum = a.PartNum) AND (DueDate <= a.DueDate)) AS Balance
FROM dbo.View_PartDtl1 AS a
WHERE (PartNum = '00-5472')
ORDER BY PartNum, DueDate, Quantity
This works to a point but returns a running total per DueDate not per line.
Can anyone assist?
Roberto
April 6, 2017 at 5:03 am
Always ensure you test your code before posting it. For your dates, you are inserting the expression [day] / [month] / [year] (where / means divide). As you're dividing all these much smaller numbers by 2017 across the board, they all equate to 0, causing a date inserted of 01-01-1900.
Fix SQL:CREATE TABLE #mytable (
PartNum varchar(50),
DueDate datetime,
RequirementFlag tinyint,
Quantity decimal(22,8));
GO
INSERT INTO #mytable (PartNum, DueDate, RequirementFlag, Quantity)
SELECT '00-5472','20/03/2017',1,-261.00000000 UNION ALL
SELECT '00-5472','29/03/2017',1,-270.00000000 UNION ALL
SELECT '00-5472','05/04/2017',1,-270.00000000 UNION ALL
SELECT '00-5472','05/04/2017',1,-270.00000000 UNION ALL
SELECT '00-5472','06/04/2017',0,-1500.00000000 UNION ALL
SELECT '00-5472','10/04/2017',1,-270.00000000 UNION ALL
SELECT '00-5472','10/04/2017',1,-6.00000000 UNION ALL
SELECT '00-5472','11/04/2017',1,-30.00000000 UNION ALL
SELECT '00-5472','11/04/2017',1,-120.00000000 UNION ALL
SELECT '00-5472','12/04/2014',1,-540.00000000 UNION ALL
SELECT '00-5472','13/04/2017',1,-120.00000000 UNION ALL
SELECT '00-5472','18/04/2017',1,-30.00000000 UNION ALL
SELECT '00-5472','04/05/2017',1,-200.00000000 UNION ALL
SELECT '00-5472','04/05/2017',1,-200.00000000 UNION ALL
SELECT '00-5472','04/05/2017',1,-200.00000000 UNION ALL
SELECT '00-5472','04/05/2017',1,-200.00000000;
GO
I'm not entirely sue what it is you want though. The SQL you've provided would provide a running total, so what is it you're after? Can you provide your expected output.
Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does.
Larnu.uk
April 6, 2017 at 5:47 am
It seems you have an issue with duplicate records for PartNum, DueDate, Quantity).
This should do the trick
WITH cteBaseData AS (
SELECT
PartNum
, DueDate
, RequirementFlag
, Quantity
, rn = ROW_NUMBER() OVER (PARTITION BY PartNum ORDER BY DueDate)
FROM #mytable
WHERE PartNum = '00-5472'
)
, cteOrderedData AS (
SELECT
PartNum
, DueDate
, RequirementFlag
, Quantity
, RunningTotal = CAST(cteBaseData.Quantity AS decimal(22,8))
, rn
FROM cteBaseData
WHERE rn = 1
UNION ALL
SELECT
curRow.PartNum
, curRow.DueDate
, curRow.RequirementFlag
, curRow.Quantity
, RunningTotal = CAST(prevRow.RunningTotal + curRow.Quantity AS decimal(22,8))
, curRow.rn
FROM cteBaseData AS curRow
INNER JOIN cteOrderedData AS prevRow
ON curRow.rn = prevRow.rn +1
)
SELECT
cteOrderedData.PartNum
, cteOrderedData.DueDate
, cteOrderedData.RequirementFlag
, cteOrderedData.Quantity
, cteOrderedData.RunningTotal
FROM cteOrderedData
ORDER BY rn;
April 6, 2017 at 7:09 am
Take a look at this article: http://www.sqlservercentral.com/articles/T-SQL/68467/
If you're able to work with 2012 or something more recent, you would just need an OVER() clause.
April 6, 2017 at 12:13 pm
DROP TABLE IF EXISTS #mytable;
GO
CREATE TABLE #mytable (
PartNum varchar(50),
DueDate datetime,
RequirementFlag tinyint,
Quantity decimal(22,8));
GO
INSERT INTO #mytable (PartNum, DueDate, RequirementFlag, Quantity)
VALUES ('00-5472','20170320',1,-261.00000000 )
, ('00-5472','20170329',1,-270.00000000 )
, ('00-5472','20170405',1,-270.00000000 )
, ('00-5472','20170405',1,-270.00000000 )
, ('00-5472','20170406',0,-1500.00000000 )
, ('00-5472','20170410',1,-270.00000000 )
, ('00-5472','20170410',1,-6.00000000 )
, ('00-5472','20170411',1,-30.00000000 )
, ('00-5472','20170411',1,-120.00000000 )
, ('00-5472','20140412',1,-540.00000000 )
, ('00-5472','20170413',1,-120.00000000 )
, ('00-5472','20170418',1,-30.00000000 )
, ('00-5472','20170504',1,-200.00000000 )
, ('00-5472','20170504',1,-200.00000000 )
, ('00-5472','20170504',1,-200.00000000 )
, ('00-5472','20170504',1,-200.00000000 );
GO
SELECT m.PartNum
, m.DueDate
, m.RequirementFlag
, m.Quantity
, Sum(m.Quantity) OVER (PARTITION BY m.PartNum ORDER BY m.DueDate ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW ) RunningTotal
FROM #mytable m
April 6, 2017 at 12:23 pm
Joe Torre - Thursday, April 6, 2017 12:13 PM
DROP TABLE IF EXISTS #mytable;
GO
CREATE TABLE #mytable (
PartNum varchar(50),
DueDate datetime,
RequirementFlag tinyint,
Quantity decimal(22,8));
GO
INSERT INTO #mytable (PartNum, DueDate, RequirementFlag, Quantity)
VALUES ('00-5472','20170320',1,-261.00000000 )
, ('00-5472','20170329',1,-270.00000000 )
, ('00-5472','20170405',1,-270.00000000 )
, ('00-5472','20170405',1,-270.00000000 )
, ('00-5472','20170406',0,-1500.00000000 )
, ('00-5472','20170410',1,-270.00000000 )
, ('00-5472','20170410',1,-6.00000000 )
, ('00-5472','20170411',1,-30.00000000 )
, ('00-5472','20170411',1,-120.00000000 )
, ('00-5472','20140412',1,-540.00000000 )
, ('00-5472','20170413',1,-120.00000000 )
, ('00-5472','20170418',1,-30.00000000 )
, ('00-5472','20170504',1,-200.00000000 )
, ('00-5472','20170504',1,-200.00000000 )
, ('00-5472','20170504',1,-200.00000000 )
, ('00-5472','20170504',1,-200.00000000 );
GO
SELECT m.PartNum
, m.DueDate
, m.RequirementFlag
, m.Quantity
, Sum(m.Quantity) OVER (PARTITION BY m.PartNum ORDER BY m.DueDate ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW ) RunningTotal
FROM #mytable m
This is a SQL 2008 board, so I assume that the OP is using SQL 2008.
That means that the OVER() clause cannot be framed with ROWS, and the default RANGE is used. This will thus create incorrect results rows have the same PartNum, DueDate, Quantuty combination.
April 6, 2017 at 4:45 pm
Sorry, missed that:
This works in 2008:
IF Object_Id(N'tempdb.dbo.#mytable','U') IS NOT NULL
DROP TABLE #mytable;
GO
CREATE TABLE #mytable (
ID int IDENTITY,
PartNum varchar(50),
DueDate datetime,
RequirementFlag tinyint,
Quantity decimal(22,8));
GO
INSERT INTO #mytable (PartNum, DueDate, RequirementFlag, Quantity)
VALUES ('00-5472','20170320',1,-261.00000000 )
, ('00-5472','20170329',1,-270.00000000 )
, ('00-5472','20170405',1,-270.00000000 )
, ('00-5472','20170405',1,-270.00000000 )
, ('00-5472','20170406',0,-1500.00000000 )
, ('00-5472','20170410',1,-270.00000000 )
, ('00-5472','20170410',1,-6.00000000 )
, ('00-5472','20170411',1,-30.00000000 )
, ('00-5472','20170411',1,-120.00000000 )
, ('00-5472','20140412',1,-540.00000000 )
, ('00-5472','20170413',1,-120.00000000 )
, ('00-5472','20170418',1,-30.00000000 )
, ('00-5472','20170504',1,-200.00000000 )
, ('00-5472','20170504',1,-200.00000000 )
, ('00-5472','20170504',1,-200.00000000 )
, ('00-5472','20170504',1,-200.00000000 );
GO
DECLARE @rt money;
SELECT m.ID
, m.PartNum
, m.DueDate
, m.RequirementFlag
, m.Quantity
, (SELECT Sum(Quantity) FROM #mytable WHERE ID<=m.ID) RunningTotal
FROM #mytable m
GROUP BY m.ID
, m.PartNum
, m.DueDate
, m.RequirementFlag
, m.Quantity;
April 6, 2017 at 7:54 pm
Joe Torre - Thursday, April 6, 2017 4:45 PMSorry, missed that:
This works in 2008:
IF Object_Id(N'tempdb.dbo.#mytable','U') IS NOT NULL
DROP TABLE #mytable;
GO
CREATE TABLE #mytable (
ID int IDENTITY,
PartNum varchar(50),
DueDate datetime,
RequirementFlag tinyint,
Quantity decimal(22,8));
GO
INSERT INTO #mytable (PartNum, DueDate, RequirementFlag, Quantity)
VALUES ('00-5472','20170320',1,-261.00000000 )
, ('00-5472','20170329',1,-270.00000000 )
, ('00-5472','20170405',1,-270.00000000 )
, ('00-5472','20170405',1,-270.00000000 )
, ('00-5472','20170406',0,-1500.00000000 )
, ('00-5472','20170410',1,-270.00000000 )
, ('00-5472','20170410',1,-6.00000000 )
, ('00-5472','20170411',1,-30.00000000 )
, ('00-5472','20170411',1,-120.00000000 )
, ('00-5472','20140412',1,-540.00000000 )
, ('00-5472','20170413',1,-120.00000000 )
, ('00-5472','20170418',1,-30.00000000 )
, ('00-5472','20170504',1,-200.00000000 )
, ('00-5472','20170504',1,-200.00000000 )
, ('00-5472','20170504',1,-200.00000000 )
, ('00-5472','20170504',1,-200.00000000 );
GO
DECLARE @rt money;
SELECT m.ID
, m.PartNum
, m.DueDate
, m.RequirementFlag
, m.Quantity
, (SELECT Sum(Quantity) FROM #mytable WHERE ID<=m.ID) RunningTotal
FROM #mytable m
GROUP BY m.ID
, m.PartNum
, m.DueDate
, m.RequirementFlag
, m.Quantity;
Ah, be careful, Joe. Look at the execution plan for that. You see two legs. One has a row count of 16 (the number of rows in the table) and the other has a row count of 136, which is 1+2+3+4+ ... 15+16 or (X2+X)/2, otherwise known as a "half Cartesian product" and more commonly known as a "Triangular Join.
You can read about the devastating effect on performance and memory IO (logical reads) at the following URL:
http://www.sqlservercentral.com/articles/T-SQL/61539/
A WHILE loop would run faster and with less IO than a Triangular Join. Of course, you should resort to such things only if you take great exception to using unconventional methods like the "Quirky Update", which still beats even the new methods found in 2012.
http://www.sqlservercentral.com/articles/T-SQL/68467/
--Jeff Moden
Change is inevitable... Change for the better is not.
April 7, 2017 at 12:21 am
Thom A - Thursday, April 6, 2017 5:03 AMAlways ensure you test your code before posting it. For your dates, you are inserting the expression [day] / [month] / [year] (where / means divide). As you're dividing all these much smaller numbers by 2017 across the board, they all equate to 0, causing a date inserted of 01-01-1900.Fix SQL:
CREATE TABLE #mytable (
PartNum varchar(50),
DueDate datetime,
RequirementFlag tinyint,
Quantity decimal(22,8));
GO
INSERT INTO #mytable (PartNum, DueDate, RequirementFlag, Quantity)
SELECT '00-5472','20/03/2017',1,-261.00000000 UNION ALL
SELECT '00-5472','29/03/2017',1,-270.00000000 UNION ALL
SELECT '00-5472','05/04/2017',1,-270.00000000 UNION ALL
SELECT '00-5472','05/04/2017',1,-270.00000000 UNION ALL
SELECT '00-5472','06/04/2017',0,-1500.00000000 UNION ALL
SELECT '00-5472','10/04/2017',1,-270.00000000 UNION ALL
SELECT '00-5472','10/04/2017',1,-6.00000000 UNION ALL
SELECT '00-5472','11/04/2017',1,-30.00000000 UNION ALL
SELECT '00-5472','11/04/2017',1,-120.00000000 UNION ALL
SELECT '00-5472','12/04/2014',1,-540.00000000 UNION ALL
SELECT '00-5472','13/04/2017',1,-120.00000000 UNION ALL
SELECT '00-5472','18/04/2017',1,-30.00000000 UNION ALL
SELECT '00-5472','04/05/2017',1,-200.00000000 UNION ALL
SELECT '00-5472','04/05/2017',1,-200.00000000 UNION ALL
SELECT '00-5472','04/05/2017',1,-200.00000000 UNION ALL
SELECT '00-5472','04/05/2017',1,-200.00000000;
GOI'm not entirely sue what it is you want though. The SQL you've provided would provide a running total, so what is it you're after? Can you provide your expected output.
Thom:
Thank you for the reply.
You're right my SQL Code does give me a running total but because I have duplicate dates I don't get a running totol per row but rather per date - I am trying to achieve a running total per row.
Thank you.
April 7, 2017 at 1:47 am
DesNorton - Thursday, April 6, 2017 5:47 AMIt seems you have an issue with duplicate records for PartNum, DueDate, Quantity).This should do the trick
WITH cteBaseData AS (
SELECT
PartNum
, DueDate
, RequirementFlag
, Quantity
, rn = ROW_NUMBER() OVER (PARTITION BY PartNum ORDER BY DueDate)
FROM #mytable
WHERE PartNum = '00-5472'
)
, cteOrderedData AS (
SELECT
PartNum
, DueDate
, RequirementFlag
, Quantity
, RunningTotal = CAST(cteBaseData.Quantity AS decimal(22,8))
, rn
FROM cteBaseData
WHERE rn = 1UNION ALL
SELECT
curRow.PartNum
, curRow.DueDate
, curRow.RequirementFlag
, curRow.Quantity
, RunningTotal = CAST(prevRow.RunningTotal + curRow.Quantity AS decimal(22,8))
, curRow.rn
FROM cteBaseData AS curRow
INNER JOIN cteOrderedData AS prevRow
ON curRow.rn = prevRow.rn +1)
SELECT
cteOrderedData.PartNum
, cteOrderedData.DueDate
, cteOrderedData.RequirementFlag
, cteOrderedData.Quantity
, cteOrderedData.RunningTotal
FROM cteOrderedData
ORDER BY rn;
DesNorton:
Thank you for the response.
You're SQL code works and I achieve the Running Total per line - however I need to remove the first where clause WHERE PartNum = '00-5472'
so that I capture the full dataset.
If I remove this where clause I receive a maximum recursion error.
Can you assist?
Roberto.
April 7, 2017 at 5:00 am
robertopmorris - Friday, April 7, 2017 1:47 AMDesNorton:Thank you for the response.
You're SQL code works and I achieve the Running Total per line - however I need to remove the first where clauseWHERE PartNum = '00-5472'
so that I capture the full dataset.If I remove this where clause I receive a maximum recursion error.
Can you assist?
Roberto.
Take a look at the article pointed to by Luis. That will give you a much more elegant solution.
Luis Cazares - Thursday, April 6, 2017 7:09 AMTake a look at this article: http://www.sqlservercentral.com/articles/T-SQL/68467/
If you're able to work with 2012 or something more recent, you would just need an OVER() clause.
If you want to stick with the recursive CTE, yow can use the code below.
WITH cteBaseData AS (
SELECT
PartNum
, DueDate
, RequirementFlag
, Quantity
, rn = ROW_NUMBER() OVER (PARTITION BY PartNum ORDER BY DueDate)
FROM #mytable
--WHERE PartNum = '00-5472' -- Removed, and added to the join below for the full resultset
)
, cteOrderedData AS (
SELECT
PartNum
, DueDate
, RequirementFlag
, Quantity
, RunningTotal = CAST(cteBaseData.Quantity AS decimal(22,8))
, rn
FROM cteBaseData
WHERE rn = 1
UNION ALL
SELECT
curRow.PartNum
, curRow.DueDate
, curRow.RequirementFlag
, curRow.Quantity
, RunningTotal = CAST(prevRow.RunningTotal + curRow.Quantity AS decimal(22,8))
, curRow.rn
FROM cteBaseData AS curRow
INNER JOIN cteOrderedData AS prevRow
ON curRow.PartNum = prevRow.PartNum -- Added the extra join here for the full resultset
AND curRow.rn = prevRow.rn +1
)
SELECT
cteOrderedData.PartNum
, cteOrderedData.DueDate
, cteOrderedData.RequirementFlag
, cteOrderedData.Quantity
, cteOrderedData.RunningTotal
FROM cteOrderedData
ORDER BY PartNum, rn
OPTION (MAXRECURSION 300); -- NOTE: OPTION (MAXRECURSION 0) removes the limits, but you could end up putting massive pressure on your server.
April 7, 2017 at 6:42 am
There's a simple option that can be set that will "solve the error message", but the performance may be problematic. Use this with caution:
OPTION (MAXRECURSION 0)
This would need to be positioned at the end of your final SELECT, after any WHERE clause or ORDER BY. I strongly recommend you read Jeff Moden's post above as he addresses the problem.
Steve (aka sgmunson) 🙂 🙂 🙂
Rent Servers for Income (picks and shovels strategy)
April 7, 2017 at 7:04 am
robertopmorris - Friday, April 7, 2017 1:47 AMYou're SQL code works and I achieve the Running Total per line - however I need to remove the first where clauseWHERE PartNum = '00-5472'
so that I capture the full dataset.If I remove this where clause I receive a maximum recursion error.
Can you assist?
Roberto.
Heh.... that's what I thought. Multiple Part Numbers. Do you want the running total to start over when the part number changes or continue? Also, how many rows are there in the table for this and how often do you have to do the running total?
I ask because the RBAR nature of the recursive CTE is going to be as slow as a WHILE loop and more resource intensive and I want to create a demo table to show you a MUCH faster way that will handle a million rows in just several seconds..
--Jeff Moden
Change is inevitable... Change for the better is not.
April 7, 2017 at 2:04 pm
Jeff:
Thanks for the response.
There are about 16,000 to 20,000 rows in the data set in total currently.
I want the running total to start over on change of PartNum - there are around 10,000 Parts and this number is ever increasing - by around 2,000 per annum.
The running total needs to be run once or twice a day - rarely three times.
The current SQL code returns the results very quickly - less than 5 seconds - but only gives a running total per date because the data set contains multiple entries for the same Part on the same date - we need to view this data row by row and have the running total displayed likewise.
I hope this makes sense.
Thank you in advance.
Roberto.
April 7, 2017 at 8:27 pm
robertopmorris - Friday, April 7, 2017 2:04 PMJeff:Thanks for the response.
There are about 16,000 to 20,000 rows in the data set in total currently.
I want the running total to start over on change of PartNum - there are around 10,000 Parts and this number is ever increasing - by around 2,000 per annum.
The running total needs to be run once or twice a day - rarely three times.
The current SQL code returns the results very quickly - less than 5 seconds - but only gives a running total per date because the data set contains multiple entries for the same Part on the same date - we need to view this data row by row and have the running total displayed likewise.
I hope this makes sense.Thank you in advance.
Roberto.
Did you read the article that we mentioned before?
Viewing 15 posts - 1 through 15 (of 18 total)
You must be logged in to reply to this topic. Login to reply