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)
 Finding Date Difference

Author  Topic 

ArunPhilip
Starting Member

21 Posts

Posted - 2012-02-13 : 10:58:17
Hi Everyone,

I am trying to find the date difference on a column in one of my tables. The table has 6 coulmns ID, DateSubmitted, RequestID, RequestType, SubmittedBy and Status.

I would like to calculate the time difference between two rows of the table by passing a requestID. Attaching the query that i tried,
SELECT DATEDIFF(Minute, prev.DateSubmitted, curr.DateSubmitted) FROM Status_History curr   
INNER JOIN Status_History prev ON prev.ID = curr.ID - 1 WHERE prev.DateSubmitted =
(SELECT MAX(maxtbl.DateSubmitted) FROM Status_History maxtbl WHERE maxtbl.ID = curr.ID - 1
AND maxtbl.DateSubmitted < curr.DateSubmitted) and curr.RequestID='MR-201227135933'


Thanking all in advance,
Arun

X002548
Not Just a Number

15586 Posts

Posted - 2012-02-13 : 11:03:45
Which 2 rows?



Brett

8-)

Hint: Want your questions answered fast? Follow the direction in this link
http://weblogs.sqlteam.com/brettk/archive/2005/05/25/5276.aspx


Want to help yourself?

http://msdn.microsoft.com/en-us/library/ms130214.aspx

http://weblogs.sqlteam.com/brettk/

http://brettkaiser.blogspot.com/


Go to Top of Page

ArunPhilip
Starting Member

21 Posts

Posted - 2012-02-13 : 11:12:16
Sorry for not being clear. The DateSubmitted gets its value as the status changes,

So when the Status of the ticket is open i'd have a datesubmitted value, then when the status changes to inprogress i'd have the datesubmitted field set to the time when the status was changed. I'd like to calculate the time taken for ticket to be closed.

E.g.

Date Submitted Status
2012-02-07 14:36:56.920 Open
2012-02-08 10:51:59.823 Inprogress
2012-02-09 08:22:24.297 Build
2012-02-09 08:22:34.813 Closed

I am not able to use the row number concept to get to the result.
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2012-02-13 : 11:19:19
isnt this enough?

SELECT RequestID,DATEDIFF(minute,MAX(CASE WHEN Status='Open' THEN DateSubmitted END),MAX(CASE WHEN Status='Closed' THEN DateSubmitted END)) AS CallDuration
FROM table
GROUP BY RequestID


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

ArunPhilip
Starting Member

21 Posts

Posted - 2012-02-13 : 11:28:54
Yes it does give me the entire time taken for the ticket. I also wanted to calculate the time difference between each status change (I missed out on mentioning this in my last post, my apologies). Like time taken from open to inprogress, inprogress to build and so on.
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2012-02-13 : 11:56:08
quote:
Originally posted by ArunPhilip

Yes it does give me the entire time taken for the ticket. I also wanted to calculate the time difference between each status change (I missed out on mentioning this in my last post, my apologies). Like time taken from open to inprogress, inprogress to build and so on.


for that use like


SELECT t.*,
DATEDIFF(minute,(SELECT TOP 1 DateSubmitted FROM table WHERE RequestID = t.RequestID AND DateSubmitted < t.DateSubmitted ORDER BY DateSubmitted DESC),t.DateSubmitted) AS TimeDiff
FROM table t


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page

ArunPhilip
Starting Member

21 Posts

Posted - 2012-02-13 : 12:00:01
That is just perfect. Thanks everyone
Go to Top of Page

visakh16
Very Important crosS Applying yaK Herder

52326 Posts

Posted - 2012-02-13 : 12:11:45
welcome


------------------------------------------------------------------------------------------------------
SQL Server MVP
http://visakhm.blogspot.com/

Go to Top of Page
   

- Advertisement -