SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Sql Query


Sql Query

Author
Message
sql_novice_2007
sql_novice_2007
Say Hey Kid
Say Hey Kid (686 reputation)Say Hey Kid (686 reputation)Say Hey Kid (686 reputation)Say Hey Kid (686 reputation)Say Hey Kid (686 reputation)Say Hey Kid (686 reputation)Say Hey Kid (686 reputation)Say Hey Kid (686 reputation)

Group: General Forum Members
Points: 686 Visits: 726
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.
Jack Corbett
  Jack Corbett
SSC-Forever
SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)

Group: General Forum Members
Points: 45787 Visits: 14925
Something like this should work:

DECLARE @test TABLE
(
RowID INT,
DateStamp DATE,
PrevStatus INT,
CurrentStatus INT
);

INSERT INTO @test
(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 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

Applications Developer

Don't let the good be the enemy of the best. -- Paul Fleming
At best you can say that one job may be more secure than another, but total job security is an illusion. -- Rod at work

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
How to Post Performance Problems
Crosstabs and Pivots or How to turn rows into columns Part 1
Crosstabs and Pivots or How to turn rows into columns Part 2
TheSQLGuru
TheSQLGuru
SSC-Dedicated
SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)

Group: General Forum Members
Points: 33089 Visits: 8680
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)
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
alekya
alekya
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 178
DECLARE @test TABLE
(
RowID INT,
DateStamp DATE,
PrevStatus INT,
CurrentStatus INT
);

INSERT INTO @test
(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
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
dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18295 Visits: 6431
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 mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search