How find open transaction statements?

  • 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

    Online Trainer For SQL DBA and Developer @RedBushTechnologies with 18 yrs exp.

  • 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, MVP, M.Sc (Comp Sci)
    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
  • 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, MVP, M.Sc (Comp Sci)
    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
  • 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.

    Online Trainer For SQL DBA and Developer @RedBushTechnologies with 18 yrs exp.

  • 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, MVP, M.Sc (Comp Sci)
    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
  • Thanks for second query but it also won't show the open transaction as I explained in my previous post.

    Online Trainer For SQL DBA and Developer @RedBushTechnologies with 18 yrs exp.

  • 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, MVP, M.Sc (Comp Sci)
    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
  • 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[/url]

  • 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, MVP, M.Sc (Comp Sci)
    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
  • 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.

    Online Trainer For SQL DBA and Developer @RedBushTechnologies with 18 yrs exp.

  • I think you need to start again,

    What is the REAL problem you are having ?

    Is your client app leaving transactions open ? , transactions should (in an ideal world) be short lived.

    The begin Transaction statement itself is an irrelevance surly you are more interested in the CRUD statements that have happened within the transaction.

    How have you got into the state of not knowing if to commit or rollback ?, it doesnt make a lot of sense to me.



    Clear Sky SQL
    My Blog[/url]

  • Actually a part of it is happening in REAL and a part of it just came to my mind. Whats real is my application is calling some proc and the code in procs is sth like this:

    Begin tran

    INSERT

    INSERT

    INSERT

    Commit

    This is because I want all 3 inserts to happen together or none should happen.So I used transaction. The frequency of calling these proc is high(sometimes multiple calls in 1 second). No there are some SELECT procs which uses the table in which inserts are happening. So we are facing blocking. So if I use DMV's, I dont see a way to know which statements are open.

    the another part just came to my mind.If by any chance, the transactions are open for a long time and I have to decide to commit or rollback them, i'll need to see actual statements. May be it's more of thought.

    But I still belive SQL Server should provide a way to see Open SQL transactions irrespective of when they started running and irrespective of if I ran another statements after the open transaction. And I should be able able to get it any time i.e. without running a trace.

    I wish too much 🙂

    Online Trainer For SQL DBA and Developer @RedBushTechnologies with 18 yrs exp.

  • SureshS_DBA (9/16/2010)


    So if I use DMV's, I dont see a way to know which statements are open.

    Well you can see the latest statements from an open transaction, but not a historical list

    But I still belive SQL Server should provide a way to see Open SQL transactions irrespective of when they started running and irrespective of if I ran another statements after the open transaction. And I should be able able to get it any time i.e. without running a trace.

    So go log a feature request:

    http://connect.microsoft.com/

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    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
  • Thanks for a long followup Gail....

    Online Trainer For SQL DBA and Developer @RedBushTechnologies with 18 yrs exp.

  • SureshS_DBA (9/16/2010)


    Thanks for a long followup Gail....

    That was unnecessary.

    Try this link to identify the causes of blocking

    http://www.sql-server-performance.com/tips/blocking_p1.aspx



    Clear Sky SQL
    My Blog[/url]

Viewing 15 posts - 1 through 15 (of 21 total)

You must be logged in to reply to this topic. Login to reply