Suchen der Objekte, die über die meisten Sperren verfügenFind the Objects That Have the Most Locks Taken on Them

Dieses Thema gilt für: JaSQL ServerJaAzure SQL-DatenbankkeineAzure SQL Data Warehouse keine Parallel DatawarehouseTHIS TOPIC APPLIES TO: yesSQL ServeryesAzure SQL DatabasenoAzure SQL Data Warehouse noParallel Data Warehouse

Datenbankadministratoren müssen oft die Quelle von Sperren identifizieren, die die Datenbankleistung beeinträchtigen.Database administrators often need to identify the source of locks that are hindering database performance.

Sie überwachen z. B. den Produktionsserver auf alle möglichen Engpässe.For example, you are monitoring your production server for any possible bottlenecks. Sie erwarten einen starken Wettbewerb um die Ressourcen und würden daher gern ermitteln, wie viele Sperren für diese Objekte gelten.You suspect that there might be highly contested resources, and would like to know how many locks are taken on those objects. Nachdem die am häufigsten gesperrten Objekte ermittelt sind, können Sie Schritte zur Optimierung des Zugangs auf die im Wettbewerb befindlichen Objekte ergreifen.Once the most frequently locked objects are identified, steps can be taken to optimize access to the contended objects.

Verwenden Sie hierzu den Abfrage-Editor in SQL Server Management StudioSQL Server Management Studio.To do this, use Query Editor in SQL Server Management StudioSQL Server Management Studio.

So suchen Sie die Objekte, die über die meisten Sperren verfügenTo find the objects that have the most locks

  1. Führen Sie im Abfrage-Editor die folgenden Anweisungen aus.In Query Editor, issue the following statements.

    -- Find objects in a particular database that have the most  
    -- lock acquired. This sample uses AdventureWorksDW2012.  
    -- 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('AdventureWorksDW2012')  
    
    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 AdventureWorksDW2012  
    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  
    

    Nach Abschluss der Anweisungen in dieser Prozedur werden auf der Registerkarte Ergebnisse des Abfrage-Editors die folgenden Spalten angezeigt:After the statements in this procedure finish, the Results tab of Query Editor displays the following columns:

  • namename

  • object_idobject_id

  • lock_countlock_count

Siehe auchSee Also

CREATE EVENT SESSION (Transact-SQL) CREATE EVENT SESSION (Transact-SQL)
ALTER EVENT SESSION (Transact-SQL) ALTER EVENT SESSION (Transact-SQL)
sys.dm_xe_session_targets (Transact-SQL) sys.dm_xe_session_targets (Transact-SQL)
sys.dm_xe_sessions (Transact-SQL) sys.dm_xe_sessions (Transact-SQL)
sys.server_event_sessions (Transact-SQL)sys.server_event_sessions (Transact-SQL)