Configure the max degree of parallelism Server Configuration Option

Applies to: yesSQL Server (all supported versions)

This topic describes how to configure the max degree of parallelism (MAXDOP) server configuration option in SQL Server by using SQL Server Management Studio, Azure Data Studio, or Transact-SQL. When an instance of SQL Server runs on a computer that has more than one microprocessor or CPU, the Database Engine detects whether parallelism can be used. The degree of parallelism sets the number of processors employed to run a single statement, for each parallel plan execution. You can use the max degree of parallelism option to limit the number of processors to use in parallel plan execution. For more detail on the limit set by max degree of parallelism (MAXDOP), see the Considerations section in this page. SQL Server considers parallel execution plans for queries, index data definition language (DDL) operations, parallel inserts, online alter column, parallel stats collection, and static and keyset-driven cursor population.

Note

SQL Server 2019 (15.x) introduced automatic recommendations for setting the MAXDOP server configuration option based on the number of processors available during the installation process. The setup user interface allows you to either accept the recommended settings or enter your own value. For more information, see Database Engine Configuration - MaxDOP page.

In Azure SQL Database and Azure SQL Managed Instance, the default MAXDOP setting for each new single database, elastic pool database and managed instance is 8. In Azure SQL Database, the MAXDOP database-scoped configuration is set to 8. In Azure SQL Managed Instance, the max degree of parallelism (MAXDOP) server configuration option is set to 8.

For more on MAXDOP in Azure SQL Database, see Configure the max degree of parallelism (MAXDOP) in Azure SQL Database.

Before You Begin

Considerations

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

  • If the affinity mask option is not set to the default, it may restrict the number of processors available to SQL Server on symmetric multiprocessing (SMP) systems.

  • Setting max degree of parallelism (MAXDOP) to 0 allows SQL Server to use all the available processors up to 64 processors. However, this is not the recommended value for most cases. For more information on the recommended values for max degree of parallelism, see the Recommendations section in this page.

  • To suppress parallel plan generation, set max degree of parallelism to 1. Set the value to a number from 1 to 32,767 to specify the maximum number of processor cores that can be used during a single query execution. If a value greater than the number of available processors is specified, the actual number of available processors is used. If the computer has only one processor, the max degree of parallelism value is ignored.

  • The max degree of parallelism limit is set per task. It is not a per request or per query limit. This means that during a parallel query execution, a single request can spawn multiple tasks up to the MAXDOP limit, and each task will use one worker and one scheduler. For more information, see the Scheduling parallel tasks section in the Thread and Task Architecture Guide.

  • You can override the max degree of parallelism server configuration value:

  • Index operations that create or rebuild an index, or that drop a clustered index, can be resource intensive. You can override the max degree of parallelism value for index operations by specifying the MAXDOP index option in the index statement. The MAXDOP value is applied to the statement at execution time and is not stored in the index metadata. For more information, see Configure Parallel Index Operations.

  • In addition to queries and index operations, this option also controls the parallelism of DBCC CHECKTABLE, DBCC CHECKDB, and DBCC CHECKFILEGROUP. You can disable parallel execution plans for these statements by using trace flag 2528. For more information, see Trace Flags (Transact-SQL).

Recommendations

Starting with SQL Server 2016 (13.x), during service startup if the Database Engine detects more than eight physical cores per NUMA node or socket at startup, soft-NUMA nodes are created automatically by default. The Database Engine places logical processors from the same physical core into different soft-NUMA nodes. The recommendations in the table below are aimed at keeping all the worker threads of a parallel query within the same soft-NUMA node. This will improve the performance of the queries and distribution of worker threads across the NUMA nodes for the workload. For more information, see Soft-NUMA.

Starting with SQL Server 2016 (13.x), use the following guidelines when you configure the max degree of parallelism server configuration value:

Server configuration Number of processors Guidance
Server with single NUMA node Less than or equal to 8 logical processors Keep MAXDOP at or below # of logical processors
Server with single NUMA node Greater than 8 logical processors Keep MAXDOP at 8
Server with multiple NUMA nodes Less than or equal to 16 logical processors per NUMA node Keep MAXDOP at or below # of logical processors per NUMA node
Server with multiple NUMA nodes Greater than 16 logical processors per NUMA node Keep MAXDOP at half the number of logical processors per NUMA node with a MAX value of 16

Note

NUMA node in the above table refers to soft-NUMA nodes automatically created by SQL Server 2016 (13.x) and higher versions, or hardware-based NUMA nodes if soft-NUMA has been disabled.
Use these same guidelines when you set the max degree of parallelism option for Resource Governor workload groups. For more information, see CREATE WORKLOAD GROUP (Transact-SQL).

From SQL Server 2008 through SQL Server 2014 (12.x), use the following guidelines when you configure the max degree of parallelism server configuration value:

Server configuration Number of processors Guidance
Server with single NUMA node Less than or equal to 8 logical processors Keep MAXDOP at or below # of logical processors
Server with single NUMA node Greater than 8 logical processors Keep MAXDOP at 8
Server with multiple NUMA nodes Less than or equal to 8 logical processors per NUMA node Keep MAXDOP at or below # of logical processors per NUMA node
Server with multiple NUMA nodes Greater than 8 logical processors per NUMA node Keep MAXDOP at 8

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.

Use SQL Server Management Studio or Azure Data Studio

In Azure Data Studio, install the Database Admin Tool Extensions for Windows extension, or use the below T-SQL method.

To configure the max degree of parallelism option

These options change the MAXDOP for the instance.

  1. In Object Explorer, right-click the desired instance and select Properties.

  2. Select the Advanced node.

  3. In the Max Degree of Parallelism box, select the maximum number of processors to use in parallel plan execution.

Use Transact-SQL

To configure the max degree of parallelism option with T-SQL

  1. Connect to the Database Engine with SQL Server Management Studio or Azure Data Studio.

  2. From the Standard bar, select New Query.

  3. Copy and paste the following example into the query window and select Execute. This example shows how to use sp_configure to configure the max degree of parallelism option to 16.

USE AdventureWorks2012 ;  
GO   
EXEC sp_configure 'show advanced options', 1;  
GO  
RECONFIGURE WITH OVERRIDE;  
GO  
EXEC sp_configure 'max degree of parallelism', 16;  
GO  
RECONFIGURE WITH OVERRIDE;  
GO  

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

Follow Up: After you configure the max degree of parallelism option

The setting takes effect immediately without restarting the server.

Degree of parallelism (DOP) feedback

Applies to: SQL Server 2022 (16.x) Preview and later

SQL Server 2022 (16.x) Preview introduced a new feature to called degree of parallelism (DOP) Feedback to improve query performance by identifying parallelism inefficiencies for repeating queries, based on elapsed time and waits. DOP feedback is part of the intelligent query processing family of features, and addresses suboptimal usage of parallelism for repeating queries. This scenario helps with optimizing resource usage and improving scalability of workloads, when excessive parallelism can cause performance issues. Instead of incurring in the pains of an all-encompassing default or manual adjustments to each query, DOP Feedback self-adjusts DOP to avoid the issues described above.

Parallelism is often beneficial for reporting and analytical queries, or queries that otherwise handle large amounts of data. Conversely, OLTP-centric queries that are executed in parallel could experience performance issues when the time spent coordinating all threads outweighs the advantages of using a parallel plan. For more information, see parallel plan execution.

  • To enable DOP feedback, enable the DOP_FEEDBACK database scoped configuration in a database.

  • The Query Store must be enabled for every database where DOP feedback is used, and in the "Read write" state. Feedback will be persisted in the sys.query_store_plan_feedback catalog view when we reach a stable degree of parallelism feedback value.

  • DOP feedback is available for queries that operate in the database compatibility level 160 (introduced with SQL Server 2022) or higher.

  • Only verified feedback is persisted. If the adjusted DOP results in a performance regression, DOP feedback will go back to the last known good DOP. In this context, a user canceled query is also perceived as a regression. The DOP feedback does not recompile plans.

  • Stable feedback is re-verified upon plan recompilation and may readjust up or down, but never above MAXDOP setting (including a MAXDOP hint).

  • To disable DOP feedback at the database level, use the ALTER DATABASE SCOPED CONFIGURATION SET DOP_FEEDBACK = OFF database scoped configuration.

  • To disable DOP feedback at the query level, use the DISABLE_DOP_FEEDBACK query hint.

Feedback implementation

DOP Feedback will identify parallelism inefficiencies for repeating queries, based on elapsed time and waits. If parallelism usage is deemed inefficient, DOP Feedback will lower the DOP for the next execution of the query, from whatever is the configured DOP, and verify if it helps.

To assess query eligibility, the adjusted query elapsed time is measured over a few executions. The total elapsed time for each query is adjusted by ignoring Buffer Latch, Buffer IO, and Network IO waits which are external to the parallel query execution. The goal of the DOP Feedback feature is to increase overall concurrency and reduce waits significantly, even if it slightly increases query elapsed time.

Only verified feedback is persisted. If the adjusted DOP results in a performance regression, DOP feedback will go back to the last known good DOP. In this context, a user canceled query is also perceived as a regression. Note that DOP Feedback doesn't recompile plans.

DOP feedback considerations

Minimum DOP for any query adjusted with DOP Feedback is 2. Serial executions are out of scope for DOP Feedback.

Feedback information can be tracked using the sys.query_store_plan_feedback catalog view.

If a query has a query plan forced through Query Store, DOP feedback can still be used for that query.

If a query uses the MAXDOP hint, either as a hard-coded query hints or through the Query Store hinting mechanism, and the MAXDOP hint is greater than 2, DOP Feedback will lower the DOP using the hinted value as the ceiling. For more information, see Hints (Transact-SQL) - Query and Query Store hints.

Extended events

The following XEs are available for the feature:

  • dop_feedback_eligible_query: Occurs when the query plan becomes eligible for DOP feedback. Additional events may fire if a recompile or SQL Server instance restart occurs.
  • dop_feedback_provided: Occurs when a DOP feedback provided data for a given query. This event contains baseline statistics when feedback provided for first time and previous feedback statistics when subsequent feedback is provided.
  • dop_feedback_validation: Occurs when validation occurs for the query runtime stats against a baseline or previous feedback stats.
  • dop_feedback_stabilized: Occurs when DOP feedback is stabilized for a query.
  • dop_feedback_reverted: Occurs when a DOP feedback is reverted. The event will fire when feedback validation fails on the first feedback provided. The system will revert back to no feedback state.
  • dop_feedback_analysis_stopped : Occurs when the DOP feedback analysis is stopped for a query.

See also

Next steps