Dela via


Configure the max worker threads Server Configuration Option

This topic describes how to configure the max worker threads server configuration option in SQL Server by using SQL Server Management Studio or Transact-SQL. The max worker threads option configures the number of worker threads that are available to SQL Server processes. SQL Server uses the native thread services of the operating systems so that one or more threads support each network that SQL Server supports simultaneously, another thread handles database checkpoints, and a pool of threads handles all users. The default value for max worker threads is 0. This enables SQL Server to automatically configure the number of worker threads at startup. The default setting is best for most systems. However, depending on your system configuration, setting max worker threads to a specific value sometimes improves performance.

In This Topic

  • Before you begin:

    Limitations and Restrictions

    Recommendations

    Security

  • To configure the max worker threads option, using:

    SQL Server Management Studio

    Transact-SQL

  • Follow Up:  After you configure the max worker threads option

Before You Begin

Limitations and Restrictions

  • When the actual number of query requests is less than the amount set in max worker threads, one thread handles each query request. However, if the actual number of query request exceeds the amount set in max worker threads, SQL Server pools the worker threads so that the next available worker thread can handle the request.

Recommendations

  • This option is an advanced option and should be changed only by an experienced database administrator or certified SQL Server technician.

  • Thread pooling helps optimize performance when large numbers of clients are connected to the server. Usually, a separate operating system thread is created for each query request. However, with hundreds of connections to the server, using one thread per query request can consume large amounts of system resources. The max worker threads option enables SQL Server to create a pool of worker threads to service a larger number of query requests, which improves performance.

  • The following table shows the automatically configured number of max worker threads for various combinations of CPUs and versions of SQL Server.

    Number of CPUs

    32-bit computer

    64-bit computer

    <= 4 processors

    256

    512

    8 processors

    288

    576

    16 processors

    352

    704

    32 processors

    480

    960

    64 processors

    736

    1472

    128 processors

    4224

    4480

    256 processors

    8320

    8576

    Note

    For recommendations on using more than 64 CPUs, refer to Best Practices for Running SQL Server on Computers That Have More Than 64 CPUs.

    Warning

    We recommend 1024 as the maximum number of worker threads for an instance of SQL Server that is running on a 32-bit computer.

  • When all worker threads are active with long running queries, SQL Server might appear unresponsive until a worker thread completes and becomes available. Although this is not a defect, it can sometimes be undesirable. If a process appears to be unresponsive and no new queries can be processed, then connect to SQL Server using the dedicated administrator connection (DAC), and kill the process. To prevent this, increase the number of max worker threads.

The max worker threads server configuration option does not take into account threads that are required for all the system tasks such as Availibility Groups, Service Broker, Lock Manager, and others. If the number of threads configured are being exceeded, the following query will provide information about the system tasks that have spawned the additional threads.

SELECT
s.session_id,
r.command,
r.status,
r.wait_type,
r.scheduler_id,
w.worker_address,
w.is_preemptive,
w.state,
t.task_state,
t.session_id,
t.exec_context_id,
t.request_id
FROM sys.dm_exec_sessions AS s
INNERJOIN sys.dm_exec_requests AS r
    ON s.session_id = r.session_id
INNER JOIN sys.dm_os_tasks AS t
    ON r.task_address = t.task_address
INNER JOIN sys.dm_os_workers AS w
    ON t.worker_address = w.worker_address
WHERE s.is_user_process = 0;

Security

Permissions

Execute permissions on sp_configure with no parameters or with only the first parameter are granted to all users by default. 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. The ALTER SETTINGS permission is implicitly held by the sysadmin and serveradmin fixed server roles.

Arrow icon used with Back to Top link[Top]

Using SQL Server Management Studio

To configure the max worker threads option

  1. In Object Explorer, right-click a server and select Properties.

  2. Click the Processors node.

  3. In the Max worker threads box, type or select a value from 128 through 32767.

    Use the max worker threads option to configure the number of worker threads available to SQL Server processes. The default setting for max worker threads is best for most systems. However, depending on your system configuration, setting max worker threads to a smaller value sometimes improves performance.

Arrow icon used with Back to Top link[Top]

Using Transact-SQL

To configure the max worker threads option

  1. Connect to the Database Engine.

  2. From the Standard bar, click New Query.

  3. Copy and paste the following example into the query window and click Execute. This example shows how to use sp_configure to configure the max worker threads option to 900.

EXEC sp_configure 'show advanced options', 1;
GO
RECONFIGURE ;
GO
EXEC sp_configure 'max worker threads', 900 ;
GO
RECONFIGURE;
GO

For more information, see Server Configuration Options (SQL Server).

Arrow icon used with Back to Top link[Top]

Follow Up: After you configure the max worker threads option

The change will take effect immediately without requiring the Database Engine to restart.

Arrow icon used with Back to Top link[Top]

See Also

Reference

RECONFIGURE (Transact-SQL)

sp_configure (Transact-SQL)

Concepts

Server Configuration Options (SQL Server)

Diagnostic Connection for Database Administrators