This is the multi-page printable view of this section.
Click here to print.
Return to the regular view of this page.
CREATE RESOURCE POOL
Creates a custom resource pool and sets one or more resource pool parameters.
Creates a custom resource pool and sets one or more resource pool parameters.
Syntax
CREATE RESOURCE POOL pool-name [ FOR subcluster-spec ] [ parameter-name setting ]...
Parameters
pool-name
- The name of the resource pool. Built-in pool names cannot be used for user-defined pools.
Note
If you specify a resource pool name with uppercase letters, Vertica converts them to lowercase letters.
FOR
subcluster-spec
- Eon Mode only, specifies to associate this resource pool with a subcluster, where
subcluster-spec
is one of the following:
SUBCLUSTER
subcluster-name
: Creates the resource pool for an existing subcluster. You cannot be connected to this subcluster, otherwise Vertica returns an error.
CURRENT SUBCLUSTER
: Creates the resource pool for the subcluster that you are connected to.
If omitted, the resource pool is created globally. Attempts to create a global resource pool with the same name as a subcluster-specific resource pool return an error.
parameter-name
- The parameter to set, listed below.
setting
The value to set on parameter-name
. To reset this parameter to its default value, specify DEFAULT
.
CASCADE TO
Specifies a secondary resource pool for executing queries that exceed the
[RUNTIMECAP](#RUNTIMECAP)
setting of their assigned resource pool:
CASCADE TO secondary-pool
CPUAFFINITYMODE
Specifies whether the resource pool has exclusive or shared use of the CPUs specified in
[CPUAFFINITYSET](#CPUAFFINITYSET)
:
CPUAFFINITYMODE { SHARED | EXCLUSIVE | ANY }
-
SHARED
: Queries that run in this pool share its CPUAFFINITYSET
CPUs with other Vertica resource pools.
-
EXCLUSIVE
: Dedicates CPUAFFINITYSET
CPUs to this resource pool only, and excludes other Vertica resource pools. If CPUAFFINITYSET
is set as a percentage, then that percentage of CPU resources available to Vertica is assigned solely for this resource pool.
-
ANY
(default): Queries in this resource pool can run on any CPU, invalid if CPUAFFINITYSET
designates CPU resources.
Important
CPUAFFINITYMODE
and CPUAFFINITYSET
must be set together in the same statement.
CPUAFFINITYSET
Specifies which CPUs are available to this resource pool. All cluster nodes must have the same number of CPUs. The CPU resources assigned to this set are unavailable to general resource pools.
CPUAFFINITYSET {
'cpu-index[,...]'
| 'cpu-indexi-cpu-indexn'
| 'integer%'
| NONE
}
-
cpu-index
[,...]
: Dedicates one or more comma-delimited CPUs to this pool.
-
**``*
cpu-indexi*
-*
cpu-index*
n**
: Dedicates a range of contiguous CPU indexes to this pool
-
integer
%
: Percentage of all available CPUs to use for this pool. Vertica rounds this percentage down to include whole CPU units.
-
NONE
(default): No affinity set is assigned to this resource pool. The queries associated with this pool are executed on any CPU.
Important
CPUAFFINITYSET
and CPUAFFINITYMODE
must be set together in the same statement.
EXECUTIONPARALLELISM
Limits the number of threads used to process any single query issued in this resource pool.
EXECUTIONPARALLELISM { limit | AUTO }
-
limit
: An integer value between 1 and the number of cores. Setting this parameter to a reduced value increases throughput of short queries issued in the pool, especially if the queries are executed concurrently.
-
AUTO
or 0
(default): Vertica calculates the setting from the number of cores, available memory, and amount of data in the system. Unless memory is limited, or the amount of data is very small, Vertica sets this parameter to the number of cores on the node.
MAXCONCURRENCY
Sets the maximum number of concurrent execution slots available to the resource pool, across the cluster:
MAXCONCURRENCY { integer | NONE }
NONE
(default) specifies unlimited number of concurrent execution slots.
MAXMEMORYSIZE
The maximum size per node the resource pool can grow by borrowing memory from the
GENERAL
pool:
MAXMEMORYSIZE {
'integer%'
| 'integer{K|M|G|T}'
| NONE
}
-
integer
%
: Percentage of total memory
-
integer
{K|M|G|T}
: Amount of memory in kilobytes, megabytes, gigabytes, or terabytes
-
NONE
(default): Unlimited, pool can borrow any amount of available memory from the GENERAL
pool.
MAXQUERYMEMORYSIZE
The maximum amount of memory that this pool can allocate at runtime to process a query. If the query requires more memory than this setting, Vertica stops execution and returns an error.
Set this parameter as follows:
MAXQUERYMEMORYSIZE {
'integer%'
| 'integer{K|M|G|T}'
| NONE
}
-
integer
%
: Percentage of MAXMEMORYSIZE
for this pool.
-
integer
{K|M|G|T}
: Amount of memory in kilobytes, megabytes, gigabytes, or terabytes, up to the value of MAXMEMORYSIZE
.
-
NONE
(default): Unlimited; pool can borrow any amount of available memory from the GENERAL pool, within the limits set by MAXMEMORYSIZE
.
MEMORYSIZE
The amount of total memory available to the Vertica resource manager that is allocated to this pool per node:
MEMORYSIZE {
'integer%'
| 'integer{K|M|G|T}'
}
-
integer
%
: Percentage of total memory
-
integer
{K|M|G|T}
: Amount of memory in kilobytes, megabytes, gigabytes, or terabytes
Default: 0%. No memory allocated, the resource pool borrows memory from the
GENERAL
pool.
PLANNEDCONCURRENCY
Specifies the preferred number queries to execute concurrently in the resource pool. This setting applies to the entire cluster:
PLANNEDCONCURRENCY { num-queries | AUTO }
-
num-queries
: Integer value ≥ 1, specifies the preferred number of concurrently executing queries. When possible, query resource budgets are limited to allow this level of concurrent execution.
-
AUTO
(default): Value is calculated automatically at query runtime. Vertica sets this parameter to the lower of these two calculations, but never less than 4:
-
Number of logical cores
-
Memory divided by 2GB
For clusters where the number of logical cores differs on different nodes, AUTO
can apply differently on each node. Distributed queries run like the minimal effective planned concurrency. Single node queries run with the planned concurrency of the initiator.
Tip
Change this parameter only after evaluating performance over a period of time.
PRIORITY
Specifies priority of queries in this pool when they compete for resources in the
GENERAL
pool:
PRIORITY { integer | HOLD }
-
integer
: A negative or positive integer value, where higher numbers denote higher priority:
-
HOLD
: Sets priority to -999
. Queries in this pool are queued until
[QUEUETIMEOUT](#QUEUETIMEOUT)
is reached.
Default: 0
QUEUETIMEOUT
Species how long a request can wait for pool resources before it is rejected:
QUEUETIMEOUT { integer | NONE }
-
integer
: Maximum wait time in seconds
-
NONE
: No maximum wait time, request can be queued indefinitely.
**Default:** 300 seconds
RUNTIMECAP
Prevents runaway queries by setting the maximum time a query in the pool can execute. If a query exceeds this setting, it tries to cascade to a secondary pool:
RUNTIMECAP { 'interval' | NONE }
-
interval
: Maximum wait time expressed in the following format:
-
NONE
(default): No time limit on queries running in this pool.
To specify a value in days, provide an integer value. To provide a value less than one day, provide the interval in the format hours:minutes:seconds
. For example a value of 1:30:00
would equal 90 minutes.
If the user or session also has a RUNTIMECAP
, the shorter limit applies.
RUNTIMEPRIORITY
Determines how the resource manager should prioritize dedication of run-time resources (CPU, I/O bandwidth) to queries already running in this resource pool:
RUNTIMEPRIORITY { HIGH | MEDIUM | LOW }
Default: MEDIUM
RUNTIMEPRIORITYTHRESHOLD
Specifies in seconds a time limit in which a query must finish before the resource manager assigns to it the resource pool's RUNTIMEPRIORITY
. All queries begin running at a HIGH
priority. When a query's duration exceeds this threshold, it is assigned the RUNTIMEPRIORITY
of the resource pool.
RUNTIMEPRIORITYTHRESHOLD seconds
Default: 2
SINGLEINITIATOR
By default, set to false for backward compatibility. Do not change this setting.
Privileges
Superuser
Examples
This example shows how to create a resource pool with MEMORYSIZE
of 1800 MB.
=> CREATE RESOURCE POOL ceo_pool MEMORYSIZE '1800M' PRIORITY 10;
CREATE RESOURCE POOL
Assuming the CEO report user already exists, associate this user with the preceding resource pool using ALTER USER
statement.
=> GRANT USAGE ON RESOURCE POOL ceo_pool to ceo_user;
GRANT PRIVILEGE
=> ALTER USER ceo_user RESOURCE POOL ceo_pool;
ALTER USER
Issue the following command to confirm that the ceo_user is associated with the ceo_pool:
=> SELECT * FROM users WHERE user_name ='ceo_user';
-[ RECORD 1 ]-----+--------------------------------------------------
user_id | 45035996273733402
user_name | ceo_user
is_super_user | f
profile_name | default
is_locked | f
lock_time |
resource_pool | ceo_pool
memory_cap_kb | unlimited
temp_space_cap_kb | unlimited
run_time_cap | unlimited
all_roles |
default_roles |
search_path | "$user", public, v_catalog, v_monitor, v_internal
This exampleshows how to create and designate secondary resource pools.
=> CREATE RESOURCE POOL rp3 RUNTIMECAP '5 minutes';
=> CREATE RESOURCE POOL rp2 RUNTIMECAP '3 minutes' CASCADE TO rp3;
=> CREATE RESOURCE POOL rp1 RUNTIMECAP '1 minute' CASCADE TO rp2;
=> SET SESSION RESOURCE_POOL = rp1;
This Eon Mode example confirms the current subcluster name, then creates a resource pool for the current subcluster:
=> SELECT CURRENT_SUBCLUSTER_NAME();
CURRENT_SUBCLUSTER_NAME
-------------------------
analytics_1
(1 row)
=> CREATE RESOURCE POOL dashboard FOR SUBCLUSTER analytics_1;
CREATE RESOURCE POOL
See also
1 - Built-in pools
Vertica is preconfigured with built-in pools for various system tasks:.
Vertica is preconfigured with built-in pools for various system tasks:
For details on resource pool settings, see ALTER RESOURCE POOL.
GENERAL
Catch-all pool used to answer requests that have no specific resource pool associated with them. Any memory left over after memory has been allocated to all other pools is automatically allocated to the GENERAL pool. The MEMORYSIZE parameter of the GENERAL pool is undefined (variable), however, the GENERAL pool must be at least 1GB in size and cannot be smaller than 25% of the memory in the system.
The MAXMEMORYSIZE parameter of the GENERAL pool has special meaning; when set as a % value it represents the percent of total physical RAM on the machine that the Resource manager can use for queries. By default, it is set to 95%. MAXMEMORYSIZE governs the total amount of RAM that the Resource Manager can use for queries, regardless of whether it is set to a percent or to a specific value (for example, '10GB').
User-defined pools can borrow memory from the GENERAL pool to satisfy requests that need extra memory until the MAXMEMORYSIZE parameter of that pool is reached. If the pool is configured to have MEMORYSIZE equal to MAXMEMORYSIZE, it cannot borrow any memory from the GENERAL pool. When multiple pools request memory from the GENERAL pool, they are granted access to general pool memory according to their priority setting. In this manner, the GENERAL pool provides some elasticity to account for point-in-time deviations from normal usage of individual resource pools.
Vertica recommends reducing the GENERAL pool MAXMEMORYSIZE if your catalog uses over 5 percent of overall memory. You can calculate what percentage of GENERAL pool memory the catalog uses as follows:
=> WITH memory_use_metadata AS (SELECT node_name, memory_size_kb FROM resource_pool_status WHERE pool_name='metadata'),
memory_use_general AS (SELECT node_name, memory_size_kb FROM resource_pool_status WHERE pool_name='general')
SELECT m.node_name, ((m.memory_size_kb/g.memory_size_kb) * 100)::NUMERIC(4,2) pct_catalog_usage
FROM memory_use_metadata m JOIN memory_use_general g ON m.node_name = g.node_name;
node_name | pct_catalog_usage
------------------+-------------------
v_vmart_node0001 | 0.41
v_vmart_node0002 | 0.37
v_vmart_node0003 | 0.36
(3 rows)
BLOBDATA
Controls resource usage for in-memory blobs. In-memory blobs are objects used by a number of the machine learning SQL functions. You should adjust this pool if you plan on processing large machine learning workloads. For information about tuning the pool, see Tuning for machine learning.
If a query using the BLOBDATA pool exceeds its query planning budget, then it spills to disk. For more information about tuning your query budget, see Query budgeting.
DBD
Controls resource usage for Database Designer processing. Use of this pool is enabled by configuration parameter DBDUseOnlyDesignerResourcePool, by default set to false.
By default, QUEUETIMEOUT is set to 0 for this pool. When resources are under pressure, this setting causes the DBD to time out immediately, and not be queued to run later. Database Designer then requests the user to run the designer later, when resources are more available.
Important
Do not change QUEUETIMEOUT or any DBD resource pool parameters.
JVM
Controls Java Virtual Machine resources used by Java User Defined Extensions. When a Java UDx starts the JVM, it draws resources from the those specified in the JVM resource pool. Vertica does not reserve memory in advance for the JVM pool. When needed, the pool can expand to 10% of physical memory or 2 GB of memory, whichever is smaller. If you are buffering large amounts of data, you may need to increase the size of the JVM resource pool.
You can adjust the size of your JVM resource pool by changing its configuration settings. Unlike other resource pools, the JVM resource pool does not release resources until a session is closed.
Tracks memory allocated for catalog data and storage data structures. This pool increases in size as Vertica metadata consumes additional resources. Memory assigned to the METADATA pool is subtracted from the GENERAL pool, enabling the Vertica resource manager to make more effective use of available resources. If the METADATA resource pool reaches 75% of the GENERAL pool, Vertica stops updating METADATA memory size and displays a warning message in vertica.log
. You can enable or disable the METADATA pool with configuration parameter EnableMetadataMemoryTracking.
If you created a "dummy" or "swap" resource pool to protect resources for use by your operating system, you can replace that pool with the METADATA pool.
Users cannot change the parameters of the METADATA resource pool.
RECOVERY
Used by queries issued when recovering another node of the database. The MAXCONCURRENCY parameter is used to determine how many concurrent recovery threads to use. You can use the PLANNEDCONCURRENCY parameter (by default, set to twice the MAXCONCURRENCY
) to tune how to apportion memory to recovery queries.
See Tuning for recovery.
REFRESH
Used by queries issued by
PROJECTION_REFRESHES
operations. Refresh does not currently use multiple concurrent threads; thus, changes to the MAXCONCURRENCY values have no effect.
See Scenario: Tuning for Refresh.
SYSQUERY
Runs queries against all system monitoring and catalog tables. The SYSQUERY pool reserves resources for system table queries so that they are never blocked by contention for available resources.
TM
The Tuple Mover (TM) pool. You can set the MAXCONCURRENCY parameter for the TM pool to allow concurrent TM operations.
See Tuning tuple mover pool settings.
2 - Built-in resource pools configuration
To view the current and default configuration for built-in resource pools, query the system tables RESOURCE_POOLS and RESOURCE_POOL_DEFAULTS, respectively.
To view the current and default configuration for built-in resource pools, query the system tables RESOURCE_POOLS and RESOURCE_POOL_DEFAULTS, respectively. The sections below provide this information, and also indicate which built-in pool parameters can be modified with ALTER RESOURCE POOL:
GENERAL
Parameter |
Settings |
MEMORYSIZE |
Empty / cannot be set |
MAXMEMORYSIZE |
The maximum memory to use for all resource pools, one of the following:
MAXMEMORYSIZE {
'integer%'
| 'integer{K|M|G|T}'
}
integer % : Percentage of total system RAM, must be ≥ 25%
Caution
Setting this parameter to 100% generates a warning of potential swapping.
integer {K|M|G|T} : Amount of memory in kilobytes, megabytes, gigabytes, or terabytes, must be ≥ 1GB
For example, if your node has 64GB of memory, setting MAXMEMORYSIZE to 50% allocates half of available memory. Thus, the maximum amount of memory available to all resource pools is 32GB.
Default: 95%
|
MAXQUERYMEMORYSIZE |
The maximum amount of memory allocated by this pool to process any query:
MAXQUERYMEMORYSIZE {
'integer%'
| 'integer{K|M|G|T}'
}
-
integer % : Percentage of MAXMEMORYSIZE for this pool.
-
integer {K|M|G|T} : Amount of memory in kilobytes, megabytes, gigabytes, or terabytes
|
EXECUTIONPARALLELISM |
Default: AUTO |
PRIORITY |
Default: 0 |
RUNTIMEPRIORITY |
Default: Medium |
RUNTIMEPRIORITYTHRESHOLD |
Default: 2 |
QUEUETIMEOUT |
Default: 00:05 (minutes) |
RUNTIMECAP |
Prevents runaway queries by setting the maximum time a query in the pool can execute. If a query exceeds this setting, it tries to cascade to a secondary pool:
RUNTIMECAP { ' interval ' | NONE }
|
PLANNEDCONCURRENCY |
The number of concurrent queries you expect to run against the resource pool, an integer ≥ 4. If set to AUTO (default), Vertica automatically sets PLANNEDCONCURRENCY at query runtime, choosing the lower of these two values:
-
Number of cores
-
Memory/2GB
Important
In systems with a large number of cores, the default AUTO setting of PLANNEDCONCURRENCY is liable to be too low. In this case, set the parameter to the actual number of cores:
ALTER RESOURCE POOL general PLANNEDCONCURRENCY #cores ;
Default: AUTO
|
MAXCONCURRENCY |
Default: Empty
Caution
Must be set ≥ 1, otherwise Vertica generates a warning that system queries might be unable to execute.
|
SINGLEINITIATOR |
Default: False.
Important
Included for backwards compatibility. Do not change.
|
CPUAFFINITYSET |
Default: Empty |
CPUAFFINITYMODE |
Default: ANY |
CASCADETO |
Default: Empty |
BLOBDATA
Parameter |
Default Setting |
MEMORYSIZE |
0% |
MAXMEMORYSIZE |
10 |
MAXQUERYMEMORYSIZE |
Empty / cannot be set |
EXECUTIONPARALLELISM |
PRIORITY |
RUNTIMEPRIORITY |
RUNTIMEPRIORITYTHRESHOLD |
QUEUETIMEOUT |
RUNTIMECAP |
NONE |
PLANNEDCONCURRENCY |
AUTO |
MAXCONCURRENCY |
Empty / cannot be set |
SINGLEINITIATOR |
CPUAFFINITYSET |
CPUAFFINITYMODE |
ANY / cannot be set |
CASCADETO |
Empty / cannot be set |
DBD
Parameter |
Default Setting |
MEMORYSIZE |
0% |
MAXMEMORYSIZE |
Unlimited |
MAXQUERYMEMORYSIZE |
Empty / cannot be set |
EXECUTIONPARALLELISM |
AUTO |
PRIORITY |
0 |
RUNTIMEPRIORITY |
MEDIUM |
RUNTIMEPRIORITYTHRESHOLD |
0 |
QUEUETIMEOUT |
0 |
RUNTIMECAP |
NONE |
PLANNEDCONCURRENCY |
AUTO |
MAXCONCURRENCY |
NONE |
SINGLEINITIATOR |
True
Important
Included for backwards compatibility. Do not change.
|
CPUAFFINITYSET |
Empty / cannot be set |
CPUAFFINITYMODE |
ANY / cannot be set |
CASCADETO |
Empty / cannot be set |
JVM
Parameter |
Default Setting |
MEMORYSIZE |
0% |
MAXMEMORYSIZE |
10% of memory or 2 GB, whichever is smaller |
MAXQUERYMEMORYSIZE |
Empty / cannot be set |
EXECUTIONPARALLELISM |
AUTO |
PRIORITY |
0 |
RUNTIMEPRIORITY |
MEDIUM |
RUNTIMEPRIORITYTHRESHOLD |
2 |
QUEUETIMEOUT |
00:05 (minutes) |
RUNTIMECAP |
NONE |
PLANNEDCONCURRENCY |
AUTO |
MAXCONCURRENCY |
Empty / cannot be set |
SINGLEINITIATOR |
FALSE
Important
Included for backwards compatibility. Do not change.
|
CPUAFFINITYSET |
Empty / cannot be set |
CPUAFFINITYMODE |
ANY / cannot be set |
CASCADETO |
Empty / cannot be set |
Parameter |
Default Setting |
MEMORYSIZE |
0% |
MAXMEMORYSIZE |
Unlimited |
MAXQUERYMEMORYSIZE |
Empty / cannot be set |
EXECUTIONPARALLELISM |
AUTO |
PRIORITY |
108 |
RUNTIMEPRIORITY |
HIGH |
RUNTIMEPRIORITYTHRESHOLD |
0 |
QUEUETIMEOUT |
0 |
RUNTIMECAP |
NONE |
PLANNEDCONCURRENCY |
AUTO |
MAXCONCURRENCY |
0 |
SINGLEINITIATOR |
FALSE.
Important
Included for backwards compatibility. Do not change.
|
CPUAFFINITYSET |
Empty / cannot be set |
CPUAFFINITYMODE |
ANY / cannot be set |
CASCADETO |
Empty / cannot be set |
RECOVERY
Parameter |
Default Setting |
MEMORYSIZE |
0% |
MAXMEMORYSIZE |
The maximum size per node the resource pool can grow by borrowing memory from the
GENERAL pool:
MAXMEMORYSIZE {
'integer%'
|
'integer{K|M|G|T}' |
NONE
}
-
integer % : Percentage of total memory
-
integer {K|M|G|T} : Amount of memory in kilobytes, megabytes, gigabytes, or terabytes
-
NONE (default): Unlimited, pool can borrow any amount of available memory from the GENERAL pool.
Caution
Setting must resolve to ≥ 25%. Otherwise, Vertica generates a warning that system queries might be unable to execute.
|
MAXQUERYMEMORYSIZE |
Empty / cannot be set |
EXECUTIONPARALLELISM |
AUTO |
PRIORITY |
One of the following:
-
Enterprise Mode: 107
-
Eon Mode: 110
Caution
Change these settings only under guidance from Vertica technical support.
|
RUNTIMEPRIORITY |
MEDIUM |
RUNTIMEPRIORITYTHRESHOLD |
60 |
QUEUETIMEOUT |
00:05 (minutes) |
RUNTIMECAP |
NONE |
PLANNEDCONCURRENCY |
AUTO |
MAXCONCURRENCY |
By default, set as follows:
( numberCores / 2) + 1
Thus, given a system with four cores, MAXCONCURRENCY has a default setting of 3.
Note
0 or NONE (unlimited) are invalid settings.
|
SINGLEINITIATOR |
True.
Important
Included for backwards compatibility. Do not change.
|
CPUAFFINITYSET |
Empty / cannot be set |
CPUAFFINITYMODE |
ANY / cannot be set |
CASCADETO |
Empty / cannot be set |
REFRESH
Parameter |
Default Setting |
MEMORYSIZE |
0% |
MAXMEMORYSIZE |
NONE (unlimited) |
MAXQUERYMEMORYSIZE |
Empty / cannot be set |
EXECUTIONPARALLELISM |
AUTO |
PRIORITY |
-10 |
RUNTIMEPRIORITY |
MEDIUM |
RUNTIMEPRIORITYTHRESHOLD |
60 |
QUEUETIMEOUT |
00:05 (minutes) |
RUNTIMECAP |
NONE (unlimited) |
PLANNEDCONCURRENCY |
AUTO (4) |
MAXCONCURRENCY |
3
This parameter must be set ≥ 1.
|
SINGLEINITIATOR |
True.
Important
Included for backwards compatibility. Do not change.
|
CPUAFFINITYSET |
Empty / cannot be set |
CPUAFFINITYMODE |
ANY / cannot be set |
CASCADETO |
Empty / cannot be set |
SYSQUERY
Parameter |
Default Setting |
MEMORYSIZE |
1G
Caution
Setting must resolve to ≥ 20M, otherwise Vertica generates a warning that system queries might be unable to execute, and diagnosing problems might be difficult.
|
MAXMEMORYSIZE |
Empty (unlimited) |
MAXQUERYMEMORYSIZE |
Empty / cannot be set |
EXECUTIONPARALLELISM |
AUTO |
PRIORITY |
110 |
RUNTIMEPRIORITY |
HIGH |
RUNTIMEPRIORITYTHRESHOLD |
0 |
QUEUETIMEOUT |
00:05 (minutes) |
RUNTIMECAP |
NONE |
PLANNEDCONCURRENCY |
AUTO |
MAXCONCURRENCY |
Empty
Caution
Must be set ≥ 1, otherwise Vertica generates a warning that system queries might be unable to execute.
|
SINGLEINITIATOR |
False.
Important
Included for backwards compatibility. Do not change.
|
CPUAFFINITYSET |
Empty / cannot be set |
CPUAFFINITYMODE |
CASCADETO |
TM
Parameter |
Default Setting |
MEMORYSIZE |
5% (of the GENERAL pool's MAXMEMORYSIZE setting) + 2GB
Important
You can estimate the optimal amount of RAM for the TM resource pool as follows:
GbRAM / (6 * #table-cols ) > 10
where #table-cols is the number of columns in the largest database table. For example, given a 100-column table, MEMORYSIZE needs least 6GB of RAM:
6144MB / (6 * 100) = 10.24
|
MAXMEMORYSIZE |
Unlimited |
MAXQUERYMEMORYSIZE |
Empty / cannot be set |
EXECUTIONPARALLELISM |
AUTO |
PRIORITY |
105 |
RUNTIMEPRIORITY |
MEDIUM |
RUNTIMEPRIORITYTHRESHOLD |
60 |
QUEUETIMEOUT |
00:05 (minutes) |
RUNTIMECAP |
NONE |
PLANNEDCONCURRENCY |
7 |
MAXCONCURRENCY |
Sets across all nodes the maximum number of concurrent execution slots available to TM pool. In databases created in Vertica releases ≥9.3, the default value is 7. In databases created in earlier versions, the default is 3.This setting specifies the maximum number of merges that can occur simultaneously on multiple threads.
Note
0 or NONE (unlimited) are invalid settings.
|
SINGLEINITIATOR |
True
Important
Included for backwards compatibility. Do not change.
|
CPUAFFINITYSET |
Empty / cannot be set |
CPUAFFINITYMODE |
ANY / cannot be set |
CASCADETO |
Empty / cannot be set |