November 5, 2012 at 4:49 am
I have a website visit log. Unfortunately for a while, a version of the software was recording the date 1753 as the visit date - but not all the time, so there are runs of correct dates and 1753's interspersed. As there is an identity column, I can interpolate a date - I have a correction script - to run a recursive CTE to update the 1753's with an increment after the previous correct date. (The users are happy with this suggested date fix, as in most cases it will get the right day, if not the right time)
All works well on my limited test data
The problem is, running on (a copy of) the real table (millions of rows) - gives a MAXRECURSION error - even when I set OPTION MAXRECURSION as 32767.
What I want to do is identiy the runs of 1753's where there are more than 32K consecutive rows and manually fix a couple in the middle of those runs, thus reducing the maximum run of wrong dates to less than 32K - so update script will work.
Here is my limited test script:
CREATE TABLE WebRequest (
ID INT IDENTITY(1,1) PRIMARY KEY,
VisitDate DATETIME )
CREATE NONCLUSTERED INDEX IX_WebVisitDate ON WebRequest(VisitDate);
DECLARE @TestDate DATETIME = '2009-06-01'
DECLARE @WrongDate DATETIME = '1753-01-01'
INSERT INTO WebRequest (VisitDate)
SELECT @TestDate UNION ALL
SELECT DATEADD(ss, 3, @TestDate) UNION ALL
SELECT DATEADD(ss, 6, @TestDate) UNION ALL
SELECT DATEADD(ss, 9, @TestDate) UNION ALL
SELECT DATEADD(ss, 10, @TestDate) UNION ALL
SELECT @WrongDate UNION ALL
SELECT DATEADD(mi, 3, @TestDate) UNION ALL
SELECT DATEADD(mi, 4, @TestDate) UNION ALL
SELECT DATEADD(mi, 5, @TestDate) UNION ALL
SELECT @WrongDate UNION ALL
SELECT @WrongDate UNION ALL
SELECT @WrongDate UNION ALL
SELECT DATEADD(mi,10, @TestDate) UNION ALL
SELECT DATEADD(mi, 11, @TestDate) UNION ALL
SELECT DATEADD(mi, 15, @TestDate) UNION ALL
SELECT @WrongDate UNION ALL
SELECT @WrongDate UNION ALL
SELECT DATEADD(mi,16, @TestDate) UNION ALL
SELECT DATEADD(mi, 17, @TestDate) UNION ALL
SELECT DATEADD(mi, 18, @TestDate);
GO
BEGIN TRAN VisitTran;
DECLARE @CutOffDate DATETIME = '2009-01-01';
SELECT * FROM WebRequest ORDER BY ID;
; WITH RecursiveCTE(ID, Updated, NewDate) AS (
SELECT W1.ID, W1.VisitDate, DATEADD(ms, 300, W2.VisitDate) AS NewDate
FROM dbo.WebRequest AS W1
JOIN dbo.WebRequest AS W2 ON W2.ID = W1.ID -1
WHERE W1.VisitDate < @CutOffDate
AND W2.VisitDate > @CutOffDate
UNION ALL
SELECT W3.ID, W3.VisitDate, DATEADD(ms, 300, C.NewDate) AS NewDate
FROM dbo.WebRequest AS W3
JOIN RecursiveCTE AS C ON C.ID = W3.ID -1
WHERE W3.VisitDate < @CutOffDate
)
UPDATE WR
SET WR.VisitDate = C.NewDate
FROM WebRequest AS WR
JOIN RecursiveCTE AS C ON C.ID = WR.ID
-- OPTION (MAXRECURSION 32767)
SELECT * FROM WebRequest ORDER BY ID;
ROLLBACK TRAN VisitTran;
And here is my code for finding where the ranges of 1753s start, and their length
DECLARE @CutOffDate DATETIME = '2009-01-01';
;WITH CountPrevWrongDates (ID, VisitDate) AS
(
SELECT W1.ID, W1.VisitDate
FROM dbo.WebRequest AS W1
JOIN dbo.WebRequest AS W2 ON W2.ID = W1.ID - 1
WHERE W1.VisitDate < @CutOffDate
AND W2.VisitDate < @CutOffDate
UNION ALL
SELECT W3.ID, C.VisitDate
FROM dbo.WebRequest as W3
JOIN CountPrevWrongDates AS C ON W3.ID = C.ID -1
WHERE W3.VisitDate < @CutOffDate
)
SELECT C1.ID,COUNT(C1.ID) AS RunLength
FROM CountPrevWrongDates AS C1
JOIN CountPrevWrongDates AS C2 ON C1.ID = C2.ID -1
GROUP BY C1.ID
OPTION (MAXRECURSION 32767);
GO
But of course this itself is a recursive CTE, so blows the MAXRECURSION lmit.
Catch-22!!
November 5, 2012 at 5:16 am
You don't need to use recursion to find the ranges of 1753s starts and their lengths. Try this instead
DECLARE @CutOffDate DATETIME = '2009-01-01';
WITH CTE AS (
SELECT ID, VisitDate,
ROW_NUMBER() OVER(ORDER BY ID) -
ROW_NUMBER() OVER(PARTITION BY CASE WHEN VisitDate < @CutOffDate THEN 1 ELSE 0 END ORDER BY ID) AS rnDiff
FROM WebRequest)
SELECT MIN(ID) AS StartID,
COUNT(*) AS RunLength
FROM CTE
WHERE VisitDate < @CutOffDate
GROUP BY rnDiff
ORDER BY StartID;
____________________________________________________
Deja View - The strange feeling that somewhere, sometime you've optimised this query before
How to get the best help on a forum
http://www.sqlservercentral.com/articles/Best+Practices/61537November 5, 2012 at 5:24 am
Brilliant, and it runs on the full-sized table in only 4 seconds.
Thank-you. Problem solved. 😀
November 5, 2012 at 10:58 am
Mark-101232 (11/5/2012)
You don't need to use recursion to find the ranges of 1753s starts and their lengths. Try this instead
DECLARE @CutOffDate DATETIME = '2009-01-01';
WITH CTE AS (
SELECT ID, VisitDate,
ROW_NUMBER() OVER(ORDER BY ID) -
ROW_NUMBER() OVER(PARTITION BY CASE WHEN VisitDate < @CutOffDate THEN 1 ELSE 0 END ORDER BY ID) AS rnDiff
FROM WebRequest)
SELECT MIN(ID) AS StartID,
COUNT(*) AS RunLength
FROM CTE
WHERE VisitDate < @CutOffDate
GROUP BY rnDiff
ORDER BY StartID;
Nicely done, Mark.
--Jeff Moden
Change is inevitable... Change for the better is not.
November 5, 2012 at 12:43 pm
Jeff Moden (11/5/2012)
Mark-101232 (11/5/2012)
You don't need to use recursion to find the ranges of 1753s starts and their lengths. Try this instead
DECLARE @CutOffDate DATETIME = '2009-01-01';
WITH CTE AS (
SELECT ID, VisitDate,
ROW_NUMBER() OVER(ORDER BY ID) -
ROW_NUMBER() OVER(PARTITION BY CASE WHEN VisitDate < @CutOffDate THEN 1 ELSE 0 END ORDER BY ID) AS rnDiff
FROM WebRequest)
SELECT MIN(ID) AS StartID,
COUNT(*) AS RunLength
FROM CTE
WHERE VisitDate < @CutOffDate
GROUP BY rnDiff
ORDER BY StartID;
Nicely done, Mark.
Many thanks!
____________________________________________________
Deja View - The strange feeling that somewhere, sometime you've optimised this query before
How to get the best help on a forum
http://www.sqlservercentral.com/articles/Best+Practices/61537Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply