September 9, 2013 at 5:16 am
I have the following data.
RowId DateStamp prevStatus CurrentStatus
1 6/1/2012 null 8
2 6/2/2012 8 9
3 6/8/2012 9 8
4 6/10/2012 8 9
5 6/12/2012 9 8
6 6/16/2012 8 9
7 6/19/2012 9 8
Based on the above data I need to calculate the date difference between the status change between 8 to 8,the time diff between two current status 8. Time diff between rowid 1 and 3,3 and 5 ,5 and 7...
Can anyone help me with the query?
Thanks.
September 9, 2013 at 7:04 am
Something like this should work:
DECLARE @test-2 TABLE
(
RowID INT,
DateStamp DATE,
PrevStatus INT,
CurrentStatus INT
);
INSERT INTO @test-2
(RowID, DateStamp, PrevStatus, CurrentStatus)
VALUES
(1, '6/1/2012', NULL, 8),
(2, '6/2/2012', 8, 9),
(3, '6/8/2012', 9, 8),
(4, '6/10/2012', 8, 9),
(5, '6/12/2012', 9, 8),
(6, '6/16/2012', 8, 9),
(7, '6/19/2012', 9, 8);
WITH data
AS (
SELECT
*,
ROW_NUMBER() OVER (PARTITION BY T.CurrentStatus ORDER BY T.DateStamp) AS rowNo
FROM
@test-2 AS T
)
SELECT
*,
DATEDIFF(DAY, D1.DateStamp, D2.DateStamp) AS StatusDateDiff
FROM
data AS D1
LEFT JOIN data AS D2
ON D1.rowNo = D2.rowNo - 1 AND
D1.CurrentStatus = D2.CurrentStatus
Please note how I provided the data in way that allows for testing.
Jack Corbett
Consultant - Straight Path Solutions
Check out these links on how to get faster and more accurate answers:
Forum Etiquette: How to post data/code on a forum to get the best help
Need an Answer? Actually, No ... You Need a Question
September 9, 2013 at 8:03 am
Since you are on SQL 2012, new Windowing Functionality is available too. Here is a solution based on that. Note you may want to add in columns and/or handle missing endpoint(s).
;WITH a AS (SELECT datestamp AS datestart, currentstatus, lead(datestamp,2) OVER(ORDER BY datestamp) AS dateend
FROM @test-2)
SELECT DATEDIFF(dd, datestart, dateend) AS dateinterval
FROM a
WHERE currentstatus = 8
AND dateend IS NOT NULL
Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
September 10, 2013 at 4:40 am
DECLARE @test-2 TABLE
(
RowID INT,
DateStamp DATE,
PrevStatus INT,
CurrentStatus INT
);
INSERT INTO @test-2
(RowID, DateStamp, PrevStatus, CurrentStatus)
VALUES
(1, '6/1/2012', NULL, 8),
(2, '6/2/2012', 8, 9),
(3, '6/8/2012', 9, 8),
(4, '6/10/2012', 8, 9),
(5, '6/12/2012', 9, 8),
(6, '6/16/2012', 8, 9),
(7, '6/19/2012', 9, 8);
SELECT * INTO #TEST1 FROM
(
SELECT *
FROM @test-2
WHERE currentstatus = 8
AND PrevStatus IS NOT NULL
)A
select * from #TEST1
;WITH CTE AS
(
SELECT *, ROW_NUMBER() OVER (ORDER BY DateStamp) AS RowNumber
FROM #TEST1
)
SELECT A.RowID,B.rowid,DATEDIFF(dd, A.DateStamp, B.DateStamp) as 'DATEPART'
FROM CTE A
JOIN CTE B
ON A.RowNumber = B.RowNumber - 1
DROP TABLE #TEST1
September 10, 2013 at 7:22 pm
My personal preference is to do this with a CROSS APPLY:
WITH SampleData AS (
SELECT RowID, DateStamp=CAST(DateStamp AS DATE), PrevStatus, CurrentStatus
FROM (VALUES
(1, '6/1/2012', NULL, 8),
(2, '6/2/2012', 8, 9),
(3, '6/8/2012', 9, 8),
(4, '6/10/2012', 8, 9),
(5, '6/12/2012', 9, 8),
(6, '6/16/2012', 8, 9),
(7, '6/19/2012', 9, 8)) a(RowID, DateStamp, PrevStatus, CurrentStatus))
SELECT a.RowID, a.DateStamp, PrevStatus, CurrentStatus
,ElapsedDays=DATEDIFF(day, b.DateStamp, a.DateStamp)
FROM SampleData a
CROSS APPLY (
SELECT TOP 1 DateStamp
FROM SampleData b
WHERE a.CurrentStatus = b.CurrentStatus AND b.DateStamp < a.DateStamp
ORDER BY b.DateStamp DESC) b
WHERE a.CurrentStatus = 8
ORDER BY a.RowID;
At least it would have been in SQL versions earlier than 2012. TheSQLGuru's solution for SQL 2012 is probably faster. Haven't had the chance to test it yet myself as I just got 2012 this week. Soon though.
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
Viewing 5 posts - 1 through 4 (of 4 total)
You must be logged in to reply to this topic. Login to reply