設定 locks 伺服器組態選項Configure the locks Server Configuration Option

適用於: 是SQL Server 否Azure SQL Database 否Azure Synapse Analytics (SQL DW) 否平行處理資料倉儲 APPLIES TO: yesSQL Server noAzure SQL Database noAzure Synapse Analytics (SQL DW) noParallel Data Warehouse

此主題描述如何使用 ,在 SQL ServerSQL Server 中設定 SQL Server Management StudioSQL Server Management Studio locks Transact-SQLTransact-SQL伺服器組態選項。This topic describes how to configure the locks server configuration option in SQL ServerSQL Server by using SQL Server Management StudioSQL Server Management Studio or Transact-SQLTransact-SQL. locks 選項會設定可用鎖定的最大數目,藉此限制 SQL Server Database EngineSQL Server Database Engine 用於鎖定的記憶體數量。The locks option sets the maximum number of available locks, thereby limiting the amount of memory the SQL Server Database EngineSQL Server Database Engine uses for them. 預設值為 0,允許 Database EngineDatabase Engine 根據變更系統需求,動態配置與取消配置鎖定結構。The default setting is 0, which allows the Database EngineDatabase Engine to allocate and deallocate lock structures dynamically, based on changing system requirements.

重要

未來的 Microsoft SQL Server 版本將移除這項功能。This feature will be removed in a future version of Microsoft SQL Server. 請勿在新的開發工作中使用此功能,並且儘速修改使用此功能的應用程式。Do not use this feature in new development work, and modify applications that currently use this feature as soon as possible.

本主題內容In This Topic

開始之前Before You Begin

建議Recommendations

  • 此選項是進階選項,只有具經驗的資料庫管理員或通過認證的 SQL ServerSQL Server 專業人員才可變更。This option is an advanced option and should be changed only by an experienced database administrator or certified SQL ServerSQL Server professional.

  • 如果伺服器啟動時是將 locks 設為 0,則鎖定管理員會從 Database EngineDatabase Engine 取得足夠的記憶體,以供 2,500 個鎖定結構的初始集區使用。When the server is started with locks set to 0, the lock manager acquires sufficient memory from the Database EngineDatabase Engine for an initial pool of 2,500 lock structures. 當鎖定集區耗盡時,就會再為集區取得額外的記憶體。As the lock pool is exhausted, additional memory is acquired for the pool.

    一般而言,如果鎖定集區所需的記憶體多於 Database EngineDatabase Engine 記憶體集區可提供的數量,而且還有更多的電腦記憶體可用 (尚未達到 max server memory 臨界值) 的話, Database EngineDatabase Engine 會動態配置記憶體,以滿足鎖定要求。Generally, if more memory is required for the lock pool than is available in the Database EngineDatabase Engine memory pool, and more computer memory is available (the max server memory threshold has not been reached), the Database EngineDatabase Engine allocates memory dynamically to satisfy the request for locks. 然而,如果配置該記憶體會造成作業系統層級的分頁 (例如,如果另一個應用程式與 SQL ServerSQL Server 執行個體在同一部電腦上執行而且它正在使用該記憶體),就無法再配置鎖定空間。However, if allocating that memory would cause paging at the operating system level (for example, if another application is running on the same computer as an instance of SQL ServerSQL Server and using that memory), more lock space is not allocated. 動態鎖定集區所取得的記憶體不會超過 Database EngineDatabase Engine配置記憶體的 60%。The dynamic lock pool does not acquire more than 60 percent of the memory allocated to the Database EngineDatabase Engine. 當鎖定集區達到 Database EngineDatabase Engine執行個體所取得之記憶體的 60%,或電腦上沒有多餘的記憶體可用時,之後的鎖定要求都會產生錯誤。After the lock pool has reached 60 percent of the memory acquired by an instance of the Database EngineDatabase Engine, or no more memory is available on the computer, further requests for locks generate an error.

    SQL ServerSQL Server 動態地使用鎖定,是建議的設定。Allowing SQL ServerSQL Server to use locks dynamically is the recommended configuration. 但是,您可以設定 locks ,並覆寫 SQL ServerSQL Server 動態配置鎖定資源的功能。However, you can set locks and override the ability of SQL ServerSQL Server to allocate lock resources dynamically. locks 設為 0 以外的數值時, Database EngineDatabase Engine 所能配置的鎖定無法超過 locks中指定的值。When locks is set to a value other than 0, the Database EngineDatabase Engine cannot allocate more locks than the value specified in locks. 如果 SQL ServerSQL Server 顯示訊息表示已超過可用的鎖定個數,就應增加這個值。Increase this value if SQL ServerSQL Server displays a message that you have exceeded the number of available locks. 因為每個鎖定都會耗用記憶體 (每個鎖定 96 個位元組),所以增加這個值可能需要增加伺服器專用的記憶體數量。Because each lock consumes memory (96 bytes per lock), increasing this value can require increasing the amount of memory dedicated to the server.

  • locks 選項也會影響發生鎖定擴大的時機。The locks option also affects when lock escalation occurs. locks 設為 0 時,鎖定擴大會在目前的鎖定結構所用的記憶體達到 Database EngineDatabase Engine 記憶體集區的 40% 時發生。When locks is set to 0, lock escalation occurs when the memory used by the current lock structures reaches 40 percent of the Database EngineDatabase Engine memory pool. locks 未設為 0 時,鎖定擴大會在鎖定個數達到 locks指定數值的 40% 時發生。When locks is not set to 0, lock escalation occurs when the number of locks reaches 40 percent of the value specified for locks.

安全性Security

權限Permissions

不含參數或只含第一個參數之 sp_configure 上的執行權限預設會授與所有使用者。Execute permissions on sp_configure with no parameters or with only the first parameter are granted to all users by default. 以同時設定兩個參數的 sp_configure 來變更組態選項或執行 RECONFIGURE 陳述式時,使用者必須取得 ALTER SETTINGS 伺服器層級權限。To execute sp_configure with both parameters to change a configuration option or to run the RECONFIGURE statement, a user must be granted the ALTER SETTINGS server-level permission. 系統管理員 (sysadmin)serveradmin 固定伺服器角色會隱含 ALTER SETTINGS 權限。The ALTER SETTINGS permission is implicitly held by the sysadmin and serveradmin fixed server roles.

使用 SQL Server Management StudioUsing SQL Server Management Studio

若要設定 locks 選項To configure the locks option

  1. 在 [物件總管] 中,以滑鼠右鍵按一下伺服器,然後選取 [屬性] 。In Object Explorer, right-click a server and select Properties.

  2. 按一下 [進階] 節點。Click the Advanced node.

  3. [平行處理原則] 下,輸入所需的 locks 選項值。Under Parallelism, type the desired value for the locks option.

    使用 locks 選項來設定可用鎖定的最大數目,從而限制 SQL ServerSQL Server 用於鎖定的記憶體數量。Use the locks option to set the maximum number of available locks, thereby limiting the amount of memory SQL ServerSQL Server uses for them.

使用 Transact-SQLUsing Transact-SQL

若要設定 locks 選項To configure the locks option

  1. 連接到 Database EngineDatabase EngineConnect to the Database EngineDatabase Engine.

  2. 在標準列中,按一下 [新增查詢]From the Standard bar, click New Query.

  3. 複製下列範例並將其貼到查詢視窗中,然後按一下 [執行]Copy and paste the following example into the query window and click Execute. 此範例示範如何使用 sp_configure 設定 locks 選項的值,將可供所有使用者使用的鎖定數目設定為 20000This example shows how to use sp_configure to set the value of the locks option to set the number of locks available for all users to 20000.

Use AdventureWorks2012 ;  
GO  
sp_configure 'show advanced options', 1;  
GO  
RECONFIGURE;  
GO  
sp_configure 'locks', 20000;  
GO  
RECONFIGURE;  
GO  

如需詳細資訊,請參閱 伺服器設定選項 (SQL Server)伺服器組態選項。For more information, see Server Configuration Options (SQL Server).

後續操作:設定鎖定選項之後Follow Up: After you configure the locks option

伺服器必須重新啟動之後,設定才能生效。The server must be restarted before the setting can take effect.

另請參閱See Also

RECONFIGURE (Transact-SQL) RECONFIGURE (Transact-SQL)
伺服器組態選項 (SQL Server) Server Configuration Options (SQL Server)
sp_configure (Transact-SQL)sp_configure (Transact-SQL)