Please start any new threads on our new
site at https://forums.sqlteam.com. We've got lots of great SQL Server
experts to answer whatever question you can come up with.
Author |
Topic |
sudipbh
Starting Member
3 Posts |
Posted - 2008-04-17 : 07:09:17
|
Hello all,Here is one scenario that: I need one query based on one table which is having data like:RequestId Dept Date1001 1 10/10/2008 9:301001 2 10/10/2008 9:311001 1 10/10/2008 11:401001 3 10/10/2008 11:55I have to find out the difference between 2 consecutive dates like:diffenrece between (10/10/2008 9:30 and 10/10/2008 9:31) then (10/10/2008 9:31 and 10/10/2008 11:40) and so on.I have to do it using SQL query only in SQl server 2005.There is no primary key field in the table and i can't create one extra columns also.Can anyone help me with this? urgent.Thanks & Regards,Sudip |
|
RyanRandall
Master Smack Fu Yak Hacker
1074 Posts |
Posted - 2008-04-17 : 07:22:27
|
Here's one way... --Preparation (you may not need some of this if you have it already)declare @t table (RequestId int, Dept int, Date datetime)insert @t select 1001, 1, '10/10/2008 9:30'union all select 1001, 2, '10/10/2008 9:31'union all select 1001, 1, '10/10/2008 11:40'union all select 1001, 3, '10/10/2008 11:55'--Query (the bit you need)select *, datediff(minute, (select top 1 Date from @t where Date < a.Date order by Date desc), Date) as MinutesSincePreviousEntry from @t a /* ResultsRequestId Dept Date MinutesSincePreviousEntry----------- ----------- ----------------------- -------------------------1001 1 2008-10-10 09:30:00.000 NULL1001 2 2008-10-10 09:31:00.000 11001 1 2008-10-10 11:40:00.000 1291001 3 2008-10-10 11:55:00.000 15*/ Ryan Randall Solutions are easy. Understanding the problem, now, that's the hard part. |
 |
|
sudipbh
Starting Member
3 Posts |
Posted - 2008-04-17 : 07:56:48
|
Thanks very much for the solution. |
 |
|
johnsql
Posting Yak Master
161 Posts |
Posted - 2008-05-29 : 10:06:11
|
quote: Originally posted by RyanRandall Here's one way... --Preparation (you may not need some of this if you have it already)declare @t table (RequestId int, Dept int, Date datetime)insert @t select 1001, 1, '10/10/2008 9:30'union all select 1001, 2, '10/10/2008 9:31'union all select 1001, 1, '10/10/2008 11:40'union all select 1001, 3, '10/10/2008 11:55'--Query (the bit you need)select *, datediff(minute, (select top 1 Date from @t where Date < a.Date order by Date desc), Date) as MinutesSincePreviousEntry from @t a /* ResultsRequestId Dept Date MinutesSincePreviousEntry----------- ----------- ----------------------- -------------------------1001 1 2008-10-10 09:30:00.000 NULL1001 2 2008-10-10 09:31:00.000 11001 1 2008-10-10 11:40:00.000 1291001 3 2008-10-10 11:55:00.000 15*/ Ryan Randall Solutions are easy. Understanding the problem, now, that's the hard part.
Is there some way to solve the problem using JOIN clause?Thanks. |
 |
|
RyanRandall
Master Smack Fu Yak Hacker
1074 Posts |
Posted - 2008-05-29 : 10:16:25
|
Here's one way...select a.RequestId, a.Dept, a.Date, datediff(minute, max(b.Date), a.Date) as MinutesSincePreviousEntryfrom @t a left outer join @t b on a.Date > b.Date group by a.RequestId, a.Dept, a.Date order by a.Date Ryan Randall Solutions are easy. Understanding the problem, now, that's the hard part. |
 |
|
TG
Master Smack Fu Yak Hacker
6065 Posts |
Posted - 2008-05-29 : 10:18:53
|
And another way:--Preparation (you may not need some of this if you have it already)declare @t table (RequestId int, Dept int, Date datetime)insert @t select 1001, 1, '10/10/2008 9:30'union all select 1001, 2, '10/10/2008 9:31'union all select 1001, 1, '10/10/2008 11:40'union all select 1001, 3, '10/10/2008 11:55' ;with cte (requestid, dept, date, rn)as (select RequestId, Dept, Date, row_number() over (order by Date)from @t)select a.requestid, a.dept, a.date, datediff(minute, b.date, a.date) MinutesSincePreviousEntryfrom cte aleft join cte b on b.rn+1=a.rn/* Resultsrequestid dept date MinutesSincePreviousEntry----------- ----------- ----------------------- -------------------------1001 1 2008-10-10 09:30:00.000 NULL1001 2 2008-10-10 09:31:00.000 11001 1 2008-10-10 11:40:00.000 1291001 3 2008-10-10 11:55:00.000 15*/ Be One with the OptimizerTG |
 |
|
visakh16
Very Important crosS Applying yaK Herder
52326 Posts |
Posted - 2008-05-29 : 12:59:03
|
Another Method:-SELECT t.RequestId,t.Dept,t.Date,DATEDIFF(mi,t.Date,t1.NextDate) AS MinutesSincePreviousEntryFROM Table tOUTER APPLY (SELECT MIN(Date) AS NextDate FROM Table WHERE Date > t.Date) t1 |
 |
|
|
|
|
|
|