Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 123»»»

How find open transaction statements? Expand / Collapse
Author
Message
Posted Thursday, September 16, 2010 3:57 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, July 1, 2014 3:34 AM
Points: 378, Visits: 886
Hi All
Yes , I know we have DBCC opentran, DBCC inputbuffer,sys.dm_tran_active_transactions,sys.dm_exec_requests and many other which might help to get the sql statements which are still open. But I really couldn't put them all together to get the sql statement I wanted.
sys.dm_tran_active_transactions --only gives transaction_ID
DBCC opentran-Only Gives SPID of open transaction.
DBCC inputbuffer-Gives last statement run by the SPID but What if The same SPID ran many statements after the transaction that remained open?

sys.dm_exec_requests --Only gives SQL_HANDLE for last ran statement for a given SPID.

Although sys.syscacheObjects have the sql which is still open but it doesn't have any transaction_id or spid, So I can't get the statement from here by putting any join.
It will be great to know if there is way to get open transaction statements.
Thanks




-----Table Proc Index Performance TSQL &&%$#@*(#@$%.......------------
Deep Into SQL Jungle
Post #987056
Posted Thursday, September 16, 2010 4:25 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 3:52 PM
Points: 42,849, Visits: 35,978
Does this help?

SELECT * 
FROM sys.dm_tran_active_transactions tat
INNER JOIN sys.dm_exec_requests er ON tat.transaction_id = er.transaction_id
CROSS APPLY sys.dm_exec_sql_text(er.sql_handle)

Just note that it is possible for connections to have open transactions but not to be running any commands.



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #987066
Posted Thursday, September 16, 2010 4:38 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 3:52 PM
Points: 42,849, Visits: 35,978
Also try this one:

SELECT * 
FROM sys.dm_tran_session_transactions tst INNER JOIN sys.dm_exec_connections ec ON tst.session_id = ec.session_id
CROSS APPLY sys.dm_exec_sql_text(ec.most_recent_sql_handle)




Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #987080
Posted Thursday, September 16, 2010 4:42 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, July 1, 2014 3:34 AM
Points: 378, Visits: 886
Thanks for respons Gail but this query won't retun the open transation statement. e.g.

Suppose I runthis query:
begin tran
update employee set is_active=1

Nowit is an open transaction since it i not committed or rollback as of now.
Now if Irun the query shared by you, nowhere it will show me in 'text' column the statemet 'update employee set is_active=1'.
So i won't know which statemet is causing the open transaction.


-----Table Proc Index Performance TSQL &&%$#@*(#@$%.......------------
Deep Into SQL Jungle
Post #987083
Posted Thursday, September 16, 2010 4:44 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 3:52 PM
Points: 42,849, Visits: 35,978
Try the second query that I posted. When I tried that out on my own server, it returned one row with the expected session_id and T-SQL statement.


Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #987085
Posted Thursday, September 16, 2010 4:46 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, July 1, 2014 3:34 AM
Points: 378, Visits: 886
Thanks for second query but it also won't show the open transaction as I explained in my previous post.

-----Table Proc Index Performance TSQL &&%$#@*(#@$%.......------------
Deep Into SQL Jungle
Post #987086
Posted Thursday, September 16, 2010 5:01 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 3:52 PM
Points: 42,849, Visits: 35,978
Did you test it? On my 2008 server it's returning exactly what you asked for.

Test: Open 2 management studio windows.

Window 1: Connect to AdventureWorks and run
BEGIN TRANSACTION 
UPDATE HumanResources.Employee
SET SalariedFlag = 0
WHERE BusinessEntityID = 42



Window 2: Run the second transaction script that I posted: (I've reduced the number of columns to keep it clear)
SELECT ec.session_id, tst.is_user_transaction, st.text 
FROM sys.dm_tran_session_transactions tst
INNER JOIN sys.dm_exec_connections ec ON tst.session_id = ec.session_id
CROSS APPLY sys.dm_exec_sql_text(ec.most_recent_sql_handle) st



Session_id and last run statement for the open transaction. If you want things like login name, join in sys.dm_exec_sessions (joins on session_id)



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass



  Post Attachments 
Transaction 1.png (1,374 views, 8.89 KB)
Transaction 2.png (1,371 views, 19.03 KB)
Post #987099
Posted Thursday, September 16, 2010 5:07 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Yesterday @ 4:50 AM
Points: 1,949, Visits: 8,315
SureshS_DBA (9/16/2010)
Thanks for second query but it also won't show the open transaction as I explained in my previous post.


What Gail showed will work if the "Begin Tran" statement is within the presently executing batch.

If you execute it as a separate batch , then it wont and cant.
SQLServer does not record a history of previous commands, maybe you should look at setting up a trace ?
Would that help?




Clear Sky SQL
My Blog
Kent user group
Post #987110
Posted Thursday, September 16, 2010 5:13 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 3:52 PM
Points: 42,849, Visits: 35,978
Dave Ballantyne (9/16/2010)
What Gail showed will work if the "Begin Tran" statement is within the presently executing batch.


What it will show is the last batch executed by a session that still has an open transaction at the time the query is run. So if you run the following on one connection:

Batch 1: Begin transaction
Batch 2: Insert ...
Batch 3: Delete ...

and then from another connection run that query, it'll show the Delete statement as that's the last batch that the connection with the open transaction ran.



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #987116
Posted Thursday, September 16, 2010 5:38 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, July 1, 2014 3:34 AM
Points: 378, Visits: 886
Dave/Gail, whetever you guys said is true. SQL Server doesn't record history of tranactions and in second session i can only see the last statementran by 1st sesson.
But what surprises me is tha my open transaction is not history. It still is causing blocking on my table and you always don't keep running a trace.
So imagine a scenario where there are 3 open transation in one of my sesson, then there are some more transactions ran in same session. Now I am not sure whether I should commit or rollback these transction. How can I decide that without looking at transction statement???
I understand that it may not be possible in sql sever as of now, but I believe it is a fairly reasonble requirement which should ave implemned that I am always able to see my open transaction staements.


-----Table Proc Index Performance TSQL &&%$#@*(#@$%.......------------
Deep Into SQL Jungle
Post #987130
« Prev Topic | Next Topic »

Add to briefcase 123»»»

Permissions Expand / Collapse