ALTER SERVICE CLASS statement
The ALTER SERVICE CLASS statement alters the definition of a service class.
Invocation
This statement can be embedded in an application program or issued through the use of dynamic SQL statements. It is an executable statement that can be dynamically prepared only if DYNAMICRULES run behavior is in effect for the package (SQLSTATE 42509).
Authorization
- SQLADM authority, only if every alteration clause is a COLLECT clause
- WLMADM authority
- DBADM authority
Syntax
- 1 The same clause must not be specified more than once (SQLSTATE 42613).
- 2 The ADMISSION QUEUE ORDER clause is valid only for a service subclass (SQLSTATE 5U043).
- 3 The DEGREE SCALEBACK DEFAULT option is valid only for a service subclass (SQLSTATE 5U043).
- 4 The MAXIMUM DEGREE DEFAULT option is valid only for a service subclass (SQLSTATE 5U043).
- 5 The COLLECT REQUEST METRICS clause is valid only for a service superclass (SQLSTATE 05U44).
- 6 The REQUEST EXECUTETIME AND UOW LIFETIME HISTOGRAM TEMPLATE clauses are valid only for a service subclass (SQLSTATE 05U43).
- 7 The DETAILS keyword is the minimum to be specified, followed by the option separated by a comma.
Description
-
service-class-name
- Identifies the service class that is to be altered. This is a one-part name. It is an SQL identifier (either ordinary or delimited).The service-class-name must identify a service class that exists in the database (SQLSTATE 42704). To alter a service subclass, the service-superclass-name must be specified using the UNDER clause.
- UNDER service-superclass-name
- This clause is used only for altering a service subclass. The service-superclass-name identifies the service superclass of the service subclass and must identify a service superclass that exists in the database (SQLSTATE 42704).
- Specifies the number of CPU shares that the workload manager (WLM) dispatcher
allocates to this service class when work is executing within this service class, and whether the
service class is allowed to exceed this number when other service classes in the same scope are not
using their full entitlement.
- HARD
- The service class is not allowed to exceed its CPU share entitlement.
- SOFT
- The service class is allowed to exceed its CPU share entitlement when other service classes are not using their full entitlements.
Note: To use CPU shares with WLM dispatcher, you must enable the wlm_disp_cpu_shares database manager configuration parameter. - CPU LIMIT
- Specifies the maximum percentage of the CPU resources that the WLM dispatcher can assign to this service class. Valid values for the integer-constant are integers between 1 and 100. You can also specify CPU LIMIT NONE to indicate that there is no CPU limit.
- ACTIVITY SORTMEM LIMIT
-
Specifies the maximum percentage of the configured shared sort memory (SHEAPTHRES_SHR) that individual queries executing in the service class are allowed to consume. Queries requiring more memory than the configured limit will have individual per-operator SORTHEAP values reduced at runtime. Memory requests that exceed the limit will be throttled. Valid values for the integer-constant are integers ranging between 10 and 100. You can also specify NONE to indicate there is no activity sort memory limit. The default is NONE.
The effective sort memory limit for a query will be the most restrictive of the limit defined at the subclass, superclass and database via the ACT_SORTMEM_LIMIT database configuration parameter. The sort memory limit applied to an activity is determined when the activity is first admitted for execution. The applied sort memory limit will not change if a query is remapped at runtime to a different service subclass.
The activity sort memory limit will only be enforced for queries that are managed by the adaptive workload manager. If the adaptive workload manager is disabled (WLM_ADMISSION_CTRL database config parameter is set to NO,) or a query bypasses the adaptive workload manager, no sort memory limit is applied to the query regardless of which service class it runs in.
Note: Setting an activity sort memory limit too low may result in reduced performance for queries. - MINIMUM RESOURCE SHARE integer-constant PERCENT
- Specifies the percentage of entitled resources managed by WLM adaptive admission control that is held in reserve for the service class when other service classes exceed their admission resource entitlement. Valid values for the integer-constant are integers 0 - 100.
- ADMISSION QUEUE ORDER
- Specifies the queue order for activities queued by WLM adaptive admission control.
- FIFO
- Requests are queued in a first-in first-out order. This is the default.
- LATENCY
- The position of a request in the queue is based on its estimated execution time (that is, its latency) relative to the amount of time that has elapsed since it joined the queue.
- DEGREE SCALEBACK
- Specifies whether work running in this service class may have its degree scaled back. Queries
set to DEGREE ANY may have their actual runtime degree scaled back by the database manager based on
current CPU loads.
Scaling back the degree for service classes running simple queries may result in less contention and improved throughput. Disabling degree scale back for service classes with complex queries can help ensure more consistent and predictable response times. A setting of DEFAULT means a service subclass inherits its DEGREE SCALEBACK setting from the parent superclass. The DEFAULT setting is only applicable to service subclasses. The default setting for a service superclass is ON. The default value for a service subclass is DEFAULT.
- MAXIMUM DEGREE
- Specifies the maximum runtime degree of parallelism for activities running in this service
class. The MAXIMUM DEGREE DEFAULT option is only valid for a service subclass (SQLSTATE 5U043).
- DEFAULT
- This service subclass should inherit its maximum degree value from its parent superclass. This setting is only applicable to service subclass.
- NONE
- This service class does not specify a maximum runtime degree for assigned applications. The actual runtime degree is determined as the lower of the value of max_querydegree configuration parameter, the value set by SET RUNTIME DEGREE command, the SQL statement compilation degree and the MAXIMUM DEGREE value set on the Workload. degree
- Specifies the maximum degree of parallelism for this service class. Valid values are 1 to 32767. The actual runtime degree is determined as the lower of this degree, the value of max_querydegree configuration parameter, the value set by SET RUNTIME DEGREE command, the SQL statement compilation degree and the MAXIMUM DEGREE set on the Workload.
- PREFETCH PRIORITY
- This parameter controls the priority with which agents in the service class can submit their
prefetch requests:
- HIGH
- Prefetch requests are submitted to the high priority queue.
- MEDIUM
- Prefetch requests are submitted to the medium low priority queue.
- LOW
- Prefetch requests are submitted to the low priority queue.
- DEFAULT
- The default value is DEFAULT, which is internally mapped to MEDIUM for service superclasses. If DEFAULT is specified for a service subclass, it inherits the PREFETCH PRIORITY of its parent superclass.
Prefetchers empty the priority queue in order from high to low. Agents in the service class submit their prefetch requests at the PREFETCH PRIORITY level when the next activity begins. If PREFETCH PRIORITY is altered after a prefetch request is submitted, the request priority does not change. PREFETCH PRIORITY cannot be altered for a default subclass (SQLSTATE 5U032).
- OUTBOUND CORRELATOR
- Specifies whether or not to associate threads from this service class to an external workload
manager service class.If OUTBOUND CORRELATOR is set to a string-constant for the service superclass and OUTBOUND CORRELATOR NONE is set for a service subclass, the service subclass inherits the OUTBOUND CORRELATOR of its parent.
- OUTBOUND CORRELATOR NONE
- For a service superclass, specifies that there is no external workload manager service class association with this service class, and for a service subclass, specifies that the external workload manager service class association is the same as its parent.
- OUTBOUND CORRELATOR string-constant
- Specifies the string-constant that is to be used as a correlator to associate threads from this service class to an external workload manager service class. The external workload manager must be active (SQLSTATE 5U030). The external workload manager should be set up to recognize the value of the specified string constant.
- BUFFERPOOL PRIORITY
- This parameter controls the bufferpool priority (HIGH, MEDIUM, or LOW) of pages fetched by
activities in this service class. If DEFAULT is specified for a service subclass, it inherits the
BUFFERPOOL PRIORITY from its parent superclass. Other values are not valid (SQLSTATE 42615).
Pages fetched by activities in a service class with higher bufferpool priority are less likely to be swapped out than pages fetched by activities in a service class with lower bufferpool priority. BUFFERPOOL PRIORITY cannot be altered for a default subclass (SQLSTATE 5U032).
- COLLECT ACTIVITY DATA
- Specifies that
information about each activity that executes in this service class is to be sent to any active
activities event monitor when the activity completes.
-
alter-collect-activity-data-clause
-
- ON COORDINATOR MEMBER
- Specifies that activity data is to be collected only at the coordinator member of the activity.
- ON ALL MEMBERS
- Specifies that activity data is to be collected at all members where the activity is processed. On remote members, a record for the activity may be captured multiple times as the activity comes and goes on those members. If the AND VALUES clause is specified, activity input values will be collected only for the members of the coordinator.
- WITHOUT DETAILS
- Specifies that data about each activity that executes in the service class is to be sent to any active activities event monitor, when the activity completes execution. Details about statement, compilation environment, and section environment data are not sent.
-
- WITH DETAILS
- Specifies that statement and compilation environment data is to be sent to any active activities event monitor, for those activities that have them. Section environment data is not sent.
- SECTION
- Specifies that statement, compilation environment, section environment data, and section actuals
are to be sent to any active activities event monitor for those activities that have them.
DETAILS must be specified if SECTION is specified. Section
actuals will be collected on any partition where the activity data is collected.
- INCLUDE ACTUALS BASE
- Specifies that section actuals should also be collected on any partition where the activity data
is collected. For section actuals to be collected, either INCLUDE ACTUALS clause must be specified
or the section_actuals database configuration parameter must be set.
The effective setting for the collection of section actuals is the combination of the INCLUDE ACTUALS clause (specified on the WORK ACTION, SERVICE CLASS, or WORKLOAD), the section_actuals database configuration parameter, and the <collectsectionactuals> setting specified on the WLM_SET_CONN_ENV routine. For example, if INCLUDE ACTUALS BASE is specified, yet the section_actuals database configuration parameter value is NONE and <collectsectionactuals> is set to NONE, then the effective setting for the collection of section actuals is BASE.
BASE specifies that the following actuals should be enabled and collected during the activity's execution:- Basic operator cardinality counts
- Statistics for each object referenced (DML statements only)
- AND VALUES
- Specifies that input data values are to be sent to any active activities event monitor, for those activities that have them. This data does not include SQL statements that are compiled by using the REOPT ALWAYS bind option.
- NONE
- Specifies that activity data should not be collected for each activity that executes in this service class.
-
- COLLECT AGGREGATE ACTIVITY DATA
- Specifies that aggregate activity data should be captured for this service class and sent to
the statistics event monitor, if one is
active. This information is collected periodically on an interval that is specified
by the wlm_collect_int database configuration parameter. The default is COLLECT
AGGREGATE ACTIVITY DATA BASE.
- BASE
- Specifies that basic aggregate activity data should be captured for this service class and sent
to the statistics event monitor, if one is
active. Basic aggregate activity data includes:
- Estimated activity cost high watermark
- Rows returned high watermark
- Temporary table space usage high watermarkNote: Only activities that have an SQLTEMPSPACE threshold applied to them participate in this high watermark.
- Activity life time histogram
- Activity queue time histogram
- Activity execution time histogram
- EXTENDED
- Specifies that all aggregate activity data should be captured for this service class and sent to
the statistics event monitor, if one is
active. This includes all basic aggregate activity data plus:
- Activity data manipulation language (DML) estimated cost histogram
- Activity DML inter-arrival time histogram
- NONE
- Specifies that no aggregate activity data should be captured for this service class.
- COLLECT AGGREGATE REQUEST DATA
- Specifies that aggregate request data should be captured for this service class and sent to
the statistics event monitor, if one is
active. This information is collected periodically on an interval specified by the
wlm_collect_int database configuration parameter.
The default is COLLECT AGGREGATE REQUEST DATA NONE. The
COLLECT AGGREGATE REQUEST DATA clause is valid only for a service subclass.
- BASE
- Specifies that basic aggregate request data should be captured for this service class and sent to the statistics event monitor, if one is active.
- NONE
- Specifies that no aggregate request data should be captured for this service class.
- COLLECT AGGREGATE UNIT OF WORK DATA
- Specifies that aggregate unit of work data is to be captured for this service class and sent to
the statistics event monitor, if one is active. This information is collected periodically on an
interval that is specified by the wlm_collect_int database configuration
parameter. The default, when COLLECT AGGREGATE UNIT OF WORK DATA is specified, is COLLECT AGGREGATE
UNIT OF WORK DATA BASE.
- BASE
- Specifies that basic aggregate unit of work data is to be captured for this service class and
sent to the statistics event monitor, if one is active. Basic aggregate unit of work data includes:
- Unit of work lifetime histogram
- NONE
- Specifies that no aggregate unit of work data is to be collected for this service class.
- COLLECT REQUEST METRICS
- Specifies that monitor metrics should be collected for any request submitted by a connection
that is associated with the specified service superclass and sent to the statistics and unit of work
event monitors, if active. The default is COLLECT REQUEST METRICS NONE. The COLLECT REQUEST METRICS
clause is only valid for a service superclass (SQLSTATE 50U44). Note: The effective request metrics collection setting is the combination of the attribute specified by the COLLECT REQUEST METRICS clause on the service superclass associated with the connection submitting the request, and the mon_req_metrics database configuration parameter. If either the service superclass attribute or the configuration parameter has a value other than NONE, metrics will be collected for the request.
- BASE
- Specifies that basic metrics will be collected for any request submitted by a connection associated with the service superclass.
- EXTENDED
- Specifies that basic metrics will be collected for any request submitted by a connection
associated with the service superclass. In addition, specifies that the values for the following
monitor elements should be determined with additional granularity:
- total_section_time
- total_section_proc_time
- total_routine_user_code_time
- total_routine_user_code_proc_time
- total_routine_time
- NONE
- Specifies that no metrics will be collected for any request submitted by a connection associated with the service superclass.
- ACTIVITY LIFETIME HISTOGRAM TEMPLATE
- Specifies the template that describes the histogram used to collect statistical data about the duration, in milliseconds, of database activities running in the service class during a specific interval. This time includes both time queued and time executing. This information is only collected when the COLLECT AGGREGATE ACTIVITY DATA clause is specified, with either the BASE or EXTENDED option.
- ACTIVITY QUEUETIME HISTOGRAM TEMPLATE
- Specifies the template that describes the histogram used to collect statistical data about the length of time, in milliseconds, that database activities running in the service class are queued during a specific interval. This information is only collected when the COLLECT AGGREGATE ACTIVITY DATA clause is specified, with either the BASE or EXTENDED option.
- ACTIVITY EXECUTETIME HISTOGRAM TEMPLATE
- Specifies the template that describes the histogram used to collect statistical data about the length of time, in milliseconds, that database activities running in the service class are executing during a specific interval. This time does not include the time spent queued. Activity execution time is collected in this histogram at the coordinator member only. The time does not include idle time. Idle time is the time between the execution of requests belonging to the same activity when no work is being done. An example of idle time is the time between the end of opening a cursor and the start of fetching from that cursor. This information is only collected when the COLLECT AGGREGATE ACTIVITY DATA clause is specified, with either the BASE or EXTENDED option.
- REQUEST EXECUTETIME HISTOGRAM TEMPLATE
- Specifies the template that describes the histogram used to collect statistical data about the length of time, in milliseconds, that database requests running in the service class are executing during a specific interval. This time does not include the time spent queued. Request execution time is collected in this histogram on each member where the request executes. This information is only collected when the COLLECT AGGREGATE REQUEST DATA clause is specified with the BASE option. This clause is only valid for a service subclass.
- ACTIVITY ESTIMATEDCOST HISTOGRAM TEMPLATE
- Specifies the template that describes the histogram used to collect statistical data about the estimated cost, in timerons, of DML activities running in the service class. This information is only collected when the COLLECT AGGREGATE ACTIVITY DATA clause is specified with the EXTENDED option.
- ACTIVITY INTERARRIVALTIME HISTOGRAM TEMPLATE
- Specifies the template that describes the histogram used to collect statistical data about the length of time, in milliseconds, between the arrival of one DML activity and the arrival of the next DML activity. This information is only collected when the COLLECT AGGREGATE ACTIVITY DATA clause is specified with the EXTENDED option.
- UOW LIFETIME HISTOGRAM TEMPLATE
- Specifies the template that describes the histogram used to collect statistical data about the duration, in milliseconds, of units of work running in the service class during a specific interval. The default is SYSDEFAULTHISTOGRAM. This information is collected only when the COLLECT AGGREGATE UNIT OF WORK DATA clause is specified with the BASE option.
- ENABLE or DISABLE
- Specifies whether or not connections and activities can be mapped to the service class.
- ENABLE
- Connections and activities can be mapped to the service class.
- DISABLE
- Connections and activities cannot be mapped to the service class. New connections or activities that are mapped to a disabled service class will be rejected (SQLSTATE 5U028). When a service superclass is disabled, its service subclasses are also disabled. When the service superclass is re-enabled, its service subclasses return to states that are defined in the system catalog. A default service class cannot be disabled (SQLSTATE 5U032).
Rules
- A workload management (WLM)-exclusive SQL statement must be followed by a COMMIT or a ROLLBACK
statement (SQLSTATE 5U021). WLM-exclusive SQL statements are:
- CREATE HISTOGRAM TEMPLATE, ALTER HISTOGRAM TEMPLATE, or DROP (histogram template)
- CREATE SERVICE CLASS, ALTER SERVICE CLASS, or DROP (service class)
- CREATE THRESHOLD, ALTER THRESHOLD, or DROP (threshold)
- CREATE WORK ACTION SET, ALTER WORK ACTION SET, or DROP (work action set)
- CREATE WORK CLASS SET, ALTER WORK CLASS SET, or DROP (work class set)
- CREATE WORKLOAD, ALTER WORKLOAD, or DROP (workload)
- GRANT (workload privileges) or REVOKE (workload privileges)
- A WLM-exclusive SQL statement cannot be issued within a global transaction (SQLSTATE 51041) such as, for example, an XA transaction.
Notes
- Only one uncommitted WLM-exclusive SQL statement at a time is allowed across all members. If an uncommitted WLM-exclusive SQL statement is executing, subsequent WLM-exclusive SQL statements will wait until the current WLM-exclusive SQL statement commits or rolls back.
- Changes are written to the system catalog, but do not take effect until after a COMMIT statement, even for the connection that issues the statement.
- After the ALTER SERVICE CLASS statement is committed, changes to PREFETCH PRIORITY, OUTBOUND CORRELATOR, and COLLECT take effect for the next new activity in the service class. Existing activities in the service class continue to complete their work using the old settings.
- Syntax alternatives: The following syntax alternatives are supported for
compatibility with previous versions of Db2® and with other
database products. These alternatives are non-standard and should not be used.
- o DATABASE PARTITION can be specified in place of MEMBER, except when the DB2_ENFORCE_MEMBER_SYNTAX registry variable is set to ON.
- o DATABASE PARTITIONS can be specified in place of MEMBERS, except when the DB2_ENFORCE_MEMBER_SYNTAX registry variable is set to ON.
Examples
- Example 1: Alter the amount of CPU that can be consumed by work
running in service superclass PETSALES to a maximum of 50%.
ALTER SERVICE CLASS PETSALES CPU LIMIT 50
- Example 2: Alter service superclass BARNSALES and add an outbound correlator
'osLowPriority'. Threads running in the service superclass and its service subclasses will have the
outbound correlator 'osLowPriority' associated with
them.
ALTER SERVICE CLASS BARNSALES OUTBOUND CORRELATOR 'osLowPriority'