尋找持有最多鎖定的物件
資料庫管理員經常需要識別阻礙資料庫效能的鎖定來源。
例如,您正在監視實際伺服器,以找出任何可能的瓶頸。 您懷疑可能有高度爭用的資源,而且想要了解這些物件所持有的鎖定數量。 一旦識別出最常鎖定的物件之後,就可以採取步驟來最佳化爭用物件的存取。
若要這麼做,請在 SQL Server Management Studio 中使用查詢編輯器。
尋找持有最多鎖定的物件
在查詢編輯器中,發出下列陳述式。
-- Find objects in a particular database that have the most -- lock acquired. This sample uses AdventureWorksDW2022. -- Create the session and add an event and target. IF EXISTS(SELECT * FROM sys.server_event_sessions WHERE name='LockCounts') DROP EVENT session LockCounts ON SERVER; GO DECLARE @dbid int; SELECT @dbid = db_id('AdventureWorksDW2022'); DECLARE @sql nvarchar(1024); SET @sql = ' CREATE event session LockCounts ON SERVER ADD EVENT sqlserver.lock_acquired (WHERE database_id =' + CAST(@dbid AS nvarchar) +') ADD TARGET package0.histogram( SET filtering_event_name=''sqlserver.lock_acquired'', source_type=0, source=''resource_0'')'; EXEC (@sql); GO ALTER EVENT session LockCounts ON SERVER STATE=start; GO -- Create a simple workload that takes locks. USE AdventureWorksDW2022; GO SELECT TOP 1 * FROM dbo.vAssocSeqLineItems; GO -- The histogram target output is available from the -- sys.dm_xe_session_targets dynamic management view in -- XML format. -- The following query joins the bucketizing target output with -- sys.objects to obtain the object names. SELECT name, object_id, lock_count FROM ( SELECT objstats.value('.','bigint') AS lobject_id, objstats.value('@count', 'bigint') AS lock_count FROM ( SELECT CAST(xest.target_data AS XML) LockData FROM sys.dm_xe_session_targets xest JOIN sys.dm_xe_sessions xes ON xes.address = xest.event_session_address JOIN sys.server_event_sessions ses ON xes.name = ses.name WHERE xest.target_name = 'histogram' AND xes.name = 'LockCounts' ) Locks CROSS APPLY LockData.nodes('//HistogramTarget/Slot') AS T(objstats) ) LockedObjects INNER JOIN sys.objects o ON LockedObjects.lobject_id = o.object_id WHERE o.type != 'S' AND o.type = 'U' ORDER BY lock_count desc; GO -- Stop the event session. ALTER EVENT SESSION LockCounts ON SERVER state=stop; GO
注意
上述 Transact-SQL 程式碼範例會在內部部署 SQL Server 上執行,但可能無法在 Azure SQL Database 上執行。範例的核心部分會直接涉及事件,例如 ADD EVENT sqlserver.lock_acquired
在 Azure SQL Database 上執行工作。 但是初步項目 (例如 sys.server_event_sessions
) 必須編輯至其 Azure SQL Database 對應項 (例如 sys.database_event_sessions
),才能執行範例。
如需 SQL Server 內部部署與 Azure SQL Database 之間次要差異的詳細資訊,請參閱下列文章:
當前述 Transact-SQL 指令碼中的陳述式完成後,查詢編輯器的 [結果] 索引標籤會顯示下列資料行:
- NAME
- object_id
- lock_count
另請參閱
CREATE EVENT SESSION (Transact-SQL)
ALTER EVENT SESSION (Transact-SQL)
sys.dm_xe_session_targets (Transact-SQL)
sys.dm_xe_sessions (Transact-SQL)
sys.server_event_sessions (Transact-SQL)