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.

 All Forums
 SQL Server 2000 Forums
 SQL Server Development (2000)
 Query to find consecutive dates

Author  Topic 

sudipbh
Starting Member

3 Posts

Posted - 2008-04-17 : 07:12:48
Hello all,

Here is one scenario that: I need one query based on one table which is having data like:

RequestId Dept Date
1001 1 10/10/2008 9:30
1001 2 10/10/2008 9:31
1001 1 10/10/2008 11:40
1001 3 10/10/2008 11:55

I 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

SwePeso
Patron Saint of Lost Yaks

30421 Posts

Posted - 2008-04-17 : 07:19:46
Cross post
http://www.sqlteam.com/forums/topic.asp?TOPIC_ID=101166



E 12°55'05.25"
N 56°04'39.16"
Go to Top of Page

RyanRandall
Master Smack Fu Yak Hacker

1074 Posts

Posted - 2008-04-17 : 07:21:11
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

/* Results
RequestId Dept Date MinutesSincePreviousEntry
----------- ----------- ----------------------- -------------------------
1001 1 2008-10-10 09:30:00.000 NULL
1001 2 2008-10-10 09:31:00.000 1
1001 1 2008-10-10 11:40:00.000 129
1001 3 2008-10-10 11:55:00.000 15
*/



Ryan Randall
Solutions are easy. Understanding the problem, now, that's the hard part.
Go to Top of Page

RyanRandall
Master Smack Fu Yak Hacker

1074 Posts

Posted - 2008-04-17 : 07:23:21
quote:
Cross post

Grrr

Ryan Randall
Solutions are easy. Understanding the problem, now, that's the hard part.
Go to Top of Page
   

- Advertisement -