In SQL Server BOL, it said @@TRANCOUNT returns the number of BEGIN TRANSACTION statements that have occurred on the
current connection. Also, it said the open_tran column of sys.sysprocesses returns the number of open transactions for the process. So you may intuitively think that if that transaction count value of a process is greater than 1, it should be an explicit nested transaction.
However, explicit nested transactions are not the only reason why the transaction
count can be greater than 1 during execution of a DML statement. Consider the following example:
IF EXISTS (SELECT 1 FROM sys.objects WHERE [type] = 'U' AND name = 'T1') DROP TABLE T1;
GO
CREATE TABLE T1
(
Col1 int
);
GO
-- INSERT
INSERT INTO T1
--SELECT @@TRANCOUNT;
SELECT open_tran FROM sys.sysprocesses WHERE spid = @@SPID;
-- returns 2
SELECT Col1 FROM T1;
-- UPDATE
UPDATE T1 SET
Col1 = --@@TRANCOUNT
(SELECT open_tran FROM sys.sysprocesses WHERE spid = @@SPID)
WHERE Col1 = 2;
-- returns 2
SELECT Col1 FROM T1;
-- DELETE
DELETE
FROM T1
WHERE Col1 = --@@TRANCOUNT
(SELECT open_tran FROM sys.sysprocesses WHERE spid = @@SPID)
-- returns nothing (as @@TRANCOUNT / sys.sysprocesses open_tran = 2)
SELECT Col1 FROM T1;
-- INSERT within Explicit Transaction
BEGIN TRAN
INSERT INTO T1
--SELECT @@TRANCOUNT;
SELECT open_tran FROM sys.sysprocesses WHERE spid = @@SPID;
COMMIT
-- Still returns 2
SELECT Col1 FROM T1;
-- UPDATE within Explicit Transaction
BEGIN TRAN
UPDATE T1 SET
Col1 = --@@TRANCOUNT
(SELECT open_tran FROM sys.sysprocesses WHERE spid = @@SPID)
WHERE Col1 = 2;
COMMIT
-- Still returns 2
SELECT Col1 FROM T1;
-- DELETE within Explicit Transaction
BEGIN TRAN
DELETE
FROM T1
WHERE Col1 = --@@TRANCOUNT
(SELECT open_tran FROM sys.sysprocesses WHERE spid = @@SPID)
COMMIT
-- returns nothing (as @@TRANCOUNT / sys.sysprocesses open_tran = 2)
SELECT Col1 FROM T1;
This shows that during execution of a DML statement, there will be more than one opened transactions
reported. The results are the same for @@TRANCOUNT, open_tran column from sys.sysprocesses, or the open_transaction_count column
from the sys.dm_exec_requests.
Effectively, in addition to the one transaction always associated with any DML statement, there is another nested transaction opened internally by SQL Server, lasting for the duration of DML statement’s execution. To be clear, the second transaction is open only while a DML statement is executing. Such situation can be easily observed especially during Process Blocking.
2015-07-26
2015-07-15
CHECKDB on an Explicit Snapshot
Beginning with SQL 2005, DBCC CHECKDB creates a hidden snapshot
on the same volume as the database – you have no control over where it’s
placed. If you’re running CHECKDB at the same time that your server has
a heavy workload the snapshot can run out of space and you’ll get an
error showing that CHECKDB didn’t complete. In order to overcome this problem, you can create your own database snapshot on a drive that has enough space and
run CHECKDB against that snapshot. CHECKDB will know that its running
against a snapshot and won’t create another one. Below is an example:
CREATE DATABASE TestDB_Snapshot ON
(
NAME = TestDB,
FILENAME = 'C:\TestDB.ss'
) AS SNAPSHOT OF TestDB;
GO
DBCC CHECKDB (TestDB_Snapshot) WITH NO_INFOMSGS;
GO
CREATE DATABASE TestDB_Snapshot ON
(
NAME = TestDB,
FILENAME = 'C:\TestDB.ss'
) AS SNAPSHOT OF TestDB;
GO
DBCC CHECKDB (TestDB_Snapshot) WITH NO_INFOMSGS;
GO
2015-07-14
Check Dependent Objects
In order to check the dependent objects being referenced by a specified object, e.g. to find the referenced tables of a stored procedure, previously we can used the sp_depends system builtin stored procedure. However, if the dependent objects (e.g. table) are created after the referencing object (e.g. stored procedure), sp_depends cannot find out such dependency. Started from SQL2008, there are two new DMFs (sys.dm_sql_referenced_entities and sys.dm_sql_referencing_entities) which overcome such problem. Let's have a try in the following example:
USE TempDB
GO
DROP TABLE TestTable
GO
CREATE TABLE dbo.TestTable
( ID INT,
Name VARCHAR(100))
GO
-- referencing usp1 NOT created yet
DROP PROC usp2
GO
CREATE PROCEDURE dbo.usp2
AS
EXEC dbo.usp1
GO
DROP PROC usp1
GO
CREATE PROCEDURE dbo.usp1
AS
SELECT ID, Name
FROM TestTable
GO
SELECT * FROM sys.dm_sql_referencing_entities ('dbo.usp1', 'OBJECT');
SELECT * FROM sys.dm_sql_referenced_entities ('dbo.usp1', 'OBJECT');
SELECT * FROM sys.dm_sql_referenced_entities ('dbo.usp2', 'OBJECT');
USE TempDB
GO
DROP TABLE TestTable
GO
CREATE TABLE dbo.TestTable
( ID INT,
Name VARCHAR(100))
GO
-- referencing usp1 NOT created yet
DROP PROC usp2
GO
CREATE PROCEDURE dbo.usp2
AS
EXEC dbo.usp1
GO
DROP PROC usp1
GO
CREATE PROCEDURE dbo.usp1
AS
SELECT ID, Name
FROM TestTable
GO
SELECT * FROM sys.dm_sql_referencing_entities ('dbo.usp1', 'OBJECT');
SELECT * FROM sys.dm_sql_referenced_entities ('dbo.usp1', 'OBJECT');
SELECT * FROM sys.dm_sql_referenced_entities ('dbo.usp2', 'OBJECT');
2015-07-03
Get current stored proc name and params list
Inside a stored procedure, it can get the current stored procedure name and its parameters list by the follow statements:
DECLARE @names varchar(MAX) = OBJECT_NAME(@@PROCID) + ' ';
SELECT @names += name + ',' FROM sys.parameters WHERE [object_id] = @@PROCID ORDER BY parameter_id;
DECLARE @names varchar(MAX) = OBJECT_NAME(@@PROCID) + ' ';
SELECT @names += name + ',' FROM sys.parameters WHERE [object_id] = @@PROCID ORDER BY parameter_id;
Subscribe to:
Posts (Atom)