It was 3am in the morning and I was asleep and enjoying a delightful dream (I knew it was a dream because I was surrounded by drifting clouds, singing angels and hundreds of softly humming SQL Servers where the hardware had been sensibly provisioned and all code carefully optimised) when I was rudely awoken by a Service Desk call informing me that the systems were unresponsive. A quick check and I could see that everything was being blocked a particular transaction. My suspicion was that someone had run a script which had opened a transaction and then toddled off home without checking that either the script had finished or closed the transaction that it had opened.
My guess was right and killing the transaction got the cogs turning again.
For a little lunchtime quickie today I thought I’d share with you all a little script that I wrote to give me details on all open transactions that I’ve got on an instance. It made my life easier at 3am to see what mischief our culprit had been upto and hopefully you’ll find it useful too.
The below code can also be found in our GitHub repository
/****************************************************************** Author: David Fowler Revision date: 07/02/2018 Version: 1 Description: Display details on all open transaction on the instance © www.sqlundercover.com MIT License Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions: The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software. THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. ******************************************************************/SELECT SessionTrans.session_id ,ActiveTrans.transaction_begin_time ,DATEDIFF(SECOND,ActiveTrans.transaction_begin_time,GETDATE()) AS Duration_Seconds ,CASE ActiveTrans.transaction_state WHEN 0 THEN 'Uninitialised' WHEN 1 THEN 'Not Started' WHEN 2 THEN 'Active' WHEN 3 THEN 'Ended' WHEN 4 THEN 'Commit Initiated' WHEN 5 THEN 'Prepared' WHEN 6 THEN 'Commited' WHEN 7 THEN 'Rolling Back' WHEN 8 THEN 'Rolled Back' ELSE CAST(ActiveTrans.transaction_state AS VARCHAR) END AS TransactionState ,sessions.login_name ,sessions.host_name ,sessions.program_name ,DB_NAME(sessions.database_id) AS DBName ,SQLText.text AS LastCommand FROM sys.dm_tran_session_transactions SessionTrans JOIN sys.dm_tran_active_transactions ActiveTrans ON SessionTrans.transaction_id = ActiveTrans.transaction_id JOIN sys.dm_exec_sessions Sessions ON Sessions.session_id = SessionTrans.session_id JOIN sys.dm_exec_connections connections ON Connections.session_id = Sessions.session_id CROSS APPLY sys.dm_exec_sql_text(Connections.most_recent_sql_handle) SQLText