ALTER EXTERNAL RESOURCE POOL (Transact-SQL)

THIS TOPIC APPLIES TO: yesSQL Server (starting with 2016)noAzure SQL DatabasenoAzure SQL Data Warehouse noParallel Data Warehouse

Applies to: SQL Server 2016 R Services (In-Database) and SQL Server 2017 Machine Learning Services (In-Database)

Changes a Resource Governor external pool that specifies resources that can be used by external processes.

  • For R Services (In-Database) in SQL Server 2016, the external pool governs rterm.exe, BxlServer.exe, and other processes spawned by them.

  • For Machine Learning Services (In-Database) in SQL Server 2017, the external pool governs the R processes listed for the previous version, as well as python.exe, BxlServer.exe, and other processes spawned by them.

    Topic link icon Transact-SQL Syntax Conventions.

Syntax

ALTER EXTERNAL RESOURCE POOL { pool_name | "default" }
[ WITH (
    [ MAX_CPU_PERCENT = value ]
    [ [ , ] AFFINITY CPU =
            {
                AUTO
              | ( <cpu_range_spec> )
              | NUMANODE = (( <NUMA_node_id> )
            } ]   
    [ [ , ] MAX_MEMORY_PERCENT = value ]
    [ [ , ] MAX_PROCESSES = value ]
    )
]
[ ; ]

<CPU_range_spec> ::=
{ CPU_ID | CPU_ID  TO CPU_ID } [ ,...n ]

Arguments

{ pool_name | "default" }
Is the name of an existing user-defined external resource pool or the default external resource pool that is created when SQL Server is installed. "default" must be enclosed by quotation marks ("") or brackets ([]) when used with ALTER EXTERNAL RESOURCE POOL to avoid conflict with DEFAULT, which is a system reserved word.

MAX_CPU_PERCENT =value
Specifies the maximum average CPU bandwidth that all requests in the external resource pool can receive when there is CPU contention. value is an integer with a default setting of 100. The allowed range for value is from 1 through 100.

AFFINITY {CPU = AUTO | ( <CPU_range_spec> ) | NUMANODE = (<NUMA_node_range_spec>)}
Attach the external resource pool to specific CPUs. The default value is AUTO.

AFFINITY CPU = ( <CPU_range_spec> ) maps the external resource pool to the SQL Server CPUs identified by the given CPU_IDs. When you use AFFINITY NUMANODE = ( <NUMA_node_range_spec> ), the external resource pool is affinitized to the SQL Server physical CPUs that correspond to the given NUMA node or range of nodes.

MAX_MEMORY_PERCENT =value
Specifies the total server memory that can be used by requests in this external resource pool. value is an integer with a default setting of 100. The allowed range for value is from 1 through 100.

MAX_PROCESSES =value
Specifies the maximum number of processes allowed for the external resource pool. Specify 0 to set an unlimited threshold for the pool, which is thereafter bound only by computer resources. The default is 0.

Remarks

The Database Engine implements the resource pool when you execute the ALTER RESOURCE GOVERNOR RECONFIGURE statement.

For general information about resource pools, see Resource Governor Resource Pool, sys.resource_governor_external_resource_pools (Transact-SQL), and sys.dm_resource_governor_external_resource_pool_affinity (Transact-SQL).

For information specific to the use of external resource pools to govern machine learning jobs, see Resource governance for machine learning in SQL Server...

Permissions

Requires CONTROL SERVER permission.

Examples

The following statement changes an external pool, restricting the CPU usage to 50 percent and the maximum memory to 25 percent of the available memory on the computer.

ALTER EXTERNAL RESOURCE POOL ep_1
WITH (
    MAX_CPU_PERCENT = 50
    , AFFINITY CPU = AUTO
    , MAX_MEMORY_PERCENT = 25
);
GO
ALTER RESOURCE GOVERNOR RECONFIGURE;
GO

See also

Resource governance for machine learning in SQL Server

external scripts enabled Server Configuration Option

CREATE EXTERNAL RESOURCE POOL (Transact-SQL)

DROP EXTERNAL RESOURCE POOL (Transact-SQL)

ALTER RESOURCE POOL (Transact-SQL)

CREATE WORKLOAD GROUP (Transact-SQL)

Resource Governor Resource Pool

ALTER RESOURCE GOVERNOR (Transact-SQL)