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.