DB2 Version 9.7 for Linux, UNIX, and Windows

CREATE THRESHOLD statement

The CREATE THRESHOLD statement defines a threshold.

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

The privileges held by the authorization ID of the statement must include WLMADM or DBADM authority.

Syntax

Read syntax diagramSkip visual syntax diagram
>>-CREATE THRESHOLD--threshold-name----------------------------->

>--FOR--| threshold-domain |--ACTIVITIES------------------------>

                                       .-ENABLE--.   
>--ENFORCEMENT--| enforcement-scope |--+---------+-------------->
                                       '-DISABLE-'   

>--WHEN--| threshold-predicate |-------------------------------->

>--| threshold-exceeded-actions |------------------------------><

threshold-domain

|--+-DATABASE---------------------------------------------------------+--|
   +-SERVICE CLASS--service-class-name--+---------------------------+-+   
   |                                    '-UNDER--service-class-name-' |   
   '-WORKLOAD--workload-name------------------------------------------'   

enforcement-scope

|--+-DATABASE------------+--------------------------------------|
   +-DATABASE PARTITION--+   
   '-WORKLOAD OCCURRENCE-'   

threshold-predicate

|--+-TOTALDBPARTITIONCONNECTIONS-->--integer-value----------------------------------------------+--|
   |                                                .-AND QUEUEDCONNECTIONS > 0---------------. |   
   +-TOTALSCPARTITIONCONNECTIONS-->--integer-value--+-----------------------------------------+-+   
   |                                                +-AND QUEUEDCONNECTIONS-->--integer-value-+ |   
   |                                                '-AND QUEUEDCONNECTIONS UNBOUNDED---------' |   
   +-CONNECTIONIDLETIME-->--integer-value--+-DAY-----+------------------------------------------+   
   |                                       +-DAYS----+                                          |   
   |                                       +-HOUR----+                                          |   
   |                                       +-HOURS---+                                          |   
   |                                       +-MINUTE--+                                          |   
   |                                       '-MINUTES-'                                          |   
   +-CONCURRENTWORKLOADOCCURRENCES-->--integer-value--------------------------------------------+   
   +-CONCURRENTWORKLOADACTIVITIES-->--integer-value---------------------------------------------+   
   |                                                .-AND QUEUEDACTIVITIES > 0---------------.  |   
   +-CONCURRENTDBCOORDACTIVITIES-->--integer-value--+----------------------------------------+--+   
   |                                                +-AND QUEUEDACTIVITIES-->--integer-value-+  |   
   |                                                '-AND QUEUEDACTIVITIES UNBOUNDED---------'  |   
   +-ESTIMATEDSQLCOST-->--bigint-value----------------------------------------------------------+   
   +-SQLROWSRETURNED-->--integer-value----------------------------------------------------------+   
   +-ACTIVITYTOTALTIME-->--integer-value--+-DAY-----+-------------------------------------------+   
   |                                      +-DAYS----+                                           |   
   |                                      +-HOUR----+                                           |   
   |                                      +-HOURS---+                                           |   
   |                                      +-MINUTE--+                                           |   
   |                                      +-MINUTES-+                                           |   
   |                                      '-SECONDS-'                                           |   
   +-UOWTOTALTIME-->--integer-value--+-DAY-----+------------------------------------------------+   
   |                                 +-DAYS----+                                                |   
   |                                 +-HOUR----+                                                |   
   |                                 +-HOURS---+                                                |   
   |                                 +-MINUTE--+                                                |   
   |                                 +-MINUTES-+                                                |   
   |                                 '-SECONDS-'                                                |   
   +-SQLTEMPSPACE-->--integer-value--+-K-+------------------------------------------------------+   
   |                                 +-M-+                                                      |   
   |                                 '-G-'                                                      |   
   +-AGGSQLTEMPSPACE-->--integer-value--+-K-+---------------------------------------------------+   
   |                                    +-M-+                                                   |   
   |                                    '-G-'                                                   |   
   |                               .-CHECKING EVERY 60 SECONDS------------------.               |   
   +-SQLROWSREAD-->--bigint-value--+--------------------------------------------+---------------+   
   |                               '-CHECKING EVERY--integer-value--+-SECOND--+-'               |   
   |                                                                '-SECONDS-'                 |   
   |                                   .-CHECKING EVERY 60 SECONDS------------------.           |   
   +-SQLROWSREADINSC-->--bigint-value--+--------------------------------------------+-----------+   
   |                                   '-CHECKING EVERY--integer-value--+-SECOND--+-'           |   
   |                                                                    '-SECONDS-'             |   
   |                                         .-CHECKING EVERY 60 SECONDS------------------.     |   
   +-CPUTIME-->--integer-value--+-HOUR----+--+--------------------------------------------+-----+   
   |                            +-HOURS---+  '-CHECKING EVERY--integer-value--+-SECOND--+-'     |   
   |                            +-MINUTE--+                                   '-SECONDS-'       |   
   |                            +-MINUTES-+                                                     |   
   |                            +-SECOND--+                                                     |   
   |                            '-SECONDS-'                                                     |   
   |                                             .-CHECKING EVERY 60 SECONDS------------------. |   
   '-CPUTIMEINSC-->--integer-value--+-HOUR----+--+--------------------------------------------+-'   
                                    +-HOURS---+  '-CHECKING EVERY--integer-value--+-SECOND--+-'     
                                    +-MINUTE--+                                   '-SECONDS-'       
                                    +-MINUTES-+                                                     
                                    +-SECOND--+                                                     
                                    '-SECONDS-'                                                     

threshold-exceeded-actions

   .-COLLECT ACTIVITY DATA--NONE---------------------------------------.   
|--+-------------------------------------------------------------------+-->
   |                                          .-DATABASE PARTITION-.   |   
   |                        .-ON COORDINATOR--+--------------------+-. |   
   '-COLLECT ACTIVITY DATA--+----------------------------------------+-'   
                            |         .-DATABASE PARTITIONS-.        |     
                            '-ON ALL--+---------------------+--------'     

   .-WITHOUT DETAILS---------------------------.                                  
>--+-------------------------------------------+--+-STOP EXECUTION------------+--|
   |       .-,---------------.                 |  +-CONTINUE------------------+   
   |       V           (1)   |                 |  +-FORCE APPLICATION---------+   
   '-WITH----+-DETAILS-----+-+--+------------+-'  '-| remap-activity-action |-'   
             '-SECTION-----'    '-AND VALUES-'                                    

remap-activity-action

|--REMAP ACTIVITY TO--service-subclass-name--------------------->

   .-NO EVENT MONITOR RECORD--.   
>--+--------------------------+---------------------------------|
   '-LOG EVENT MONITOR RECORD-'   

Notes:
  1. The DETAILS keyword is the minimum to be specified, followed by the option separated by a comma.

Description

threshold-name
Names the threshold. This is a one-part name. It is an SQL identifier (either ordinary or delimited). The threshold-name must not identify a threshold that already exists at the current server (SQLSTATE 42710). The name must not begin with the characters 'SYS' (SQLSTATE 42939).
FOR threshold-domain ACTIVITIES
Specifies the definition domain of the threshold.
DATABASE
This threshold applies to any activity in the database.
SERVICE CLASS service-class-name
This threshold applies to activities executing in service class service-class-name. If UNDER is not specified, service-class-name must identify an existing service superclass (SQLSTATE 42704). If UNDER is specified, service-class-name must identify an existing service subclass of the service superclass specified after the UNDER keyword (SQLSTATE 42704). The service-class-name cannot be the SYSDEFAULTSYSTEMCLASS service class or the SYSDEFAULTMAINTENANCECLASS service class (SQLSTATE 5U032).
UNDER service-class-name
Specifies a service superclass. The service-class-name must identify an existing service superclass (SQLSTATE 42704).
WORKLOAD workload-name
This threshold applies to the specified workload. The workload-name must identify an existing workload (SQLSTATE 42704).
ENFORCEMENT enforcement-scope
The enforcement scope of the threshold.
DATABASE
The threshold is enforced across all database partitions within the definition domain; that is, all database partitions of the database, and all database partitions of the service class.
DATABASE PARTITION
The threshold is enforced on a per database partition basis. There is no coordination across all database partitions to enforce the threshold.
WORKLOAD OCCURRENCE
The threshold is enforced only within a workload occurrence. Two workload occurrences running concurrently on the same database partition will each have their own running count for this threshold.
ENABLE or DISABLE
Specifies whether or not the threshold is enabled for use by the database manager.
ENABLE
The threshold is used by the database manager to restrict the execution of database activities.
DISABLE
The threshold is not used by the database manager to restrict the execution of database activities.
WHEN threshold-predicate
Specifies the condition of the threshold.
TOTALDBPARTITIONCONNECTIONS > integer-value
This condition defines an upper bound on the number of coordinator connections that can run concurrently on a database partition. This value can be zero or any positive integer (SQLSTATE 42820). A value of zero means that any new coordinator connection will be prevented from connecting. All currently running or queued connections will continue. The definition domain for this condition must be DATABASE, and the enforcement scope must be DATABASE PARTITION (SQLSTATE 5U037). This threshold is not enforced for users with DBADM or WLMADM authority.
TOTALSCPARTITIONCONNECTIONS > integer-value
This condition defines an upper bound on the number of coordinator connections that can run concurrently on a database partition in a specific service superclass. This value can be zero or any positive integer (SQLSTATE 42820). A value of zero means that any new connection will be prevented from joining the service class. All currently running or queued connections will continue. The definition domain for this condition must be SERVICE SUPERCLASS, and the enforcement scope must be DATABASE PARTITION (SQLSTATE 5U037).
AND QUEUEDCONNECTIONS > integer-value or AND QUEUEDCONNECTIONS UNBOUNDED
Specifies a queue size for when the maximum number of coordinator connections is exceeded. This value can be zero or any positive integer (SQLSTATE 42820). A value of zero means that no coordinator connections are queued. Specifying UNBOUNDED will queue every connection that exceeds the specified maximum number of coordinator connections, and the threshold-exceeded-actions will never be executed. The default is zero.
CONNECTIONIDLETIME > integer-value DAY | DAYS | HOUR | HOURS | MINUTE | MINUTES
This condition defines an upper bound for the amount of time the database manager will allow a connection to remain idle. This value can be any positive integer (not zero) (SQLSTATE 42820).Use a valid duration keyword to specify an appropriate unit of time for integer-value. The definition domain for this condition must be DATABASE or SERVICE SUPERCLASS, and the enforcement scope must be DATABASE (SQLSTATE 5U037). This condition is logically enforced at the coordinator database partition.

If you specify the STOP EXECUTION action with CONNECTIONIDLETIME thresholds, the connection for the application is dropped when the threshold is exceeded. Any subsequent attempt by the application to access the data server will receive SQLSTATE 5U026.

The maximum value for this threshold is 2 147 483 640 seconds. Any value specified that has a seconds equivalent larger than 2 147 483 640 seconds will be set to this number of seconds.

CONCURRENTWORKLOADOCCURRENCES > integer-value
This condition defines an upper bound on the number of concurrent occurrences for the workload on each database partition. This value can be any non-zero positive integer (SQLSTATE 42820). The definition domain for this condition must be WORKLOAD and the enforcement scope must be DATABASE PARTITION (SQLSTATE 5U037).
CONCURRENTWORKLOADACTIVITIES > integer-value
This condition defines an upper bound on the number of concurrent coordinator activities and nested activities for the workload on each database partition. This value can be any positive integer (not zero) (SQLSTATE 42820). The definition domain for this condition must be WORKLOAD and the enforcement scope for this condition must be WORKLOAD OCCURRENCE (SQLSTATE 5U037).
Each nested activity must satisfy the following conditions:
  • It must be a recognized coordinator activity. Any nested coordinator activity that does not fall within the recognized types of activities will not be counted. Similarly, nested subagent activities, such as remote node requests, are not counted.
  • It must be directly invoked from user logic, such as a user-written procedure issuing SQL statements.

Consequently, nested coordinator activities that were automatically started under the invocation of a DB2® utility or routines in the SYSIBM, SYSFUN, or SYSPROC schemas are not counted towards the upper bound specified by this threshold.

Internal SQL activities, such as those initiated by the setting of a constraint or the refreshing of a materialized query table, are also not counted by this threshold, because they are initiated by the database manager and not directly invoked by user logic.

CONCURRENTDBCOORDACTIVITIES > integer-value
This condition defines an upper bound on the number of recognized database coordinator activities that can run concurrently on all database partitions in the specified domain. This value can be zero or any positive integer (SQLSTATE 42820). A value of zero means that any new database coordinator activities will be prevented from executing. All currently running or queued database coordinator activities will continue. The definition domain for this condition must be DATABASE, work action (a threshold for a work action definition domain is created using a CREATE WORK ACTION SET or ALTER WORK ACTION SET statement, and the work action set must be applied to a workload or a database), SERVICE SUPERCLASS, or SERVICE SUBCLASS, and the enforcement scope must be DATABASE (SQLSTATE 5U037). All activities are tracked by this condition, except for the following items:
  • CALL statements are not controlled by this threshold, but all nested child activities started within the called routine are under this threshold's control. Anonymous blocks and autonomous routines are classified as CALL statements.
  • User-defined functions are controlled by this threshold, but child activities nested in a user-defined function are not controlled. If an autonomous routine is called from within a user defined function, neither the autonomous routine nor any child activities of the autonomous routine are under threshold control.
  • Trigger actions that invoke CALL statements and the child activities of these CALL statements are not controlled by this threshold. INSERT, UPDATE, or DELETE statements that can cause a trigger to activate continue to be under threshold control.
  • To manage concurrency with a CALL statement, you may be able to use the TOTALSCPARTITIONCONNECTIONS threshold. The TOTALSCPARTITIONCONNECTIONS threshold is effective for controlling concurrency of CALL statements when your workload consists of transient connections. Transient connections are connections that are established only during the procedure invocation. The TOTALSCPARTITIONCONNECTIONS threshold is not appropriate if your workload consists of long-lived connections.
Important: Before using CONCURRENTDBCOORDACTIVITIES thresholds, be sure to become familiar with the effects that they can have on the database system. For more information, see the "CONCURRENTDBCOORDACTIVITIES threshold" topic.
AND QUEUEDACTIVITIES > integer-value or AND QUEUEDACTIVITIES UNBOUNDED
Specifies a queue size for when the maximum number of database coordinator activities is exceeded. This value can be zero or any positive integer (SQLSTATE 42820). A value of zero means that no database coordinator activities are queued. Specifying UNBOUNDED will queue every database coordinator activity that exceeds the specified maximum number of database coordinator activities, and the threshold-exceeded-actions will never be executed. The default is zero.
ESTIMATEDSQLCOST > bigint-value
This condition defines an upper bound for the optimizer-assigned cost (in timerons) of an activity. This value can be any positive big integer (not zero) (SQLSTATE 42820). The definition domain for this condition must be DATABASE, work action (a threshold for a work action definition domain is created using a CREATE WORK ACTION SET or ALTER WORK ACTION SET statement, and the work action set must be applied to a workload or a database), SERVICE SUPERCLASS, SERVICE SUBCLASS, or WORKLOAD, and the enforcement scope must be DATABASE (SQLSTATE 5U037). This condition is enforced at the coordinator database partition. Activities tracked by this condition are:
  • Coordinator activities of type data manipulation language (DML).
  • Nested DML activities that are invoked from user logic. Consequently, DML activities that can be initiated by the database manager (such as utilities, procedures, or internal SQL) are not tracked by this condition (unless their cost is included in the parent's estimate, in which case they are indirectly tracked).
SQLROWSRETURNED > integer-value
This condition defines an upper bound for the number of rows returned to a client application from the application server. This value can be any positive integer (not zero) (SQLSTATE 42820). The definition domain for this condition must be DATABASE, work action (a threshold for a work action definition domain is created using a CREATE WORK ACTION SET or ALTER WORK ACTION SET statement, and the work action set must be applied to a workload or a database), SERVICE SUPERCLASS, SERVICE SUBCLASS, or WORKLOAD, and the enforcement scope must be DATABASE (SQLSTATE 5U037). This condition is enforced at the coordinator database partition. Activities tracked by this condition are:
  • Coordinator activities of type DML.
  • Nested DML activities that are derived from user logic. Activities that are initiated by the database manager through a utility, procedure, or internal SQL are not affected by this condition.
Result sets returned from within a procedure are treated separately as individual activities. There is no aggregation of the rows that are returned by the procedure itself.
ACTIVITYTOTALTIME > integer-value DAY | DAYS | HOUR | HOURS | MINUTE | MINUTES | SECONDS
This condition defines an upper bound for the amount of time the database manager will allow an activity to execute, including the time the activity was queued. The definition domain for this condition must be DATABASE, work action (a threshold for a work action definition domain is created using a CREATE WORK ACTION SET or ALTER WORK ACTION SET statement, and the work action set must be applied to a workload or a database), SERVICE SUPERCLASS, SERVICE SUBCLASS, or WORKLOAD, and the enforcement scope must be DATABASE (SQLSTATE 5U037). This condition is logically enforced at the coordinator database partition.

The specified integer-value must be an integer that is greater than zero (SQLSTATE 42820). Use a valid duration keyword to specify an appropriate unit of time for integer-value. If the specified time unit is SECONDS, the value must be a multiple of 10 (SQLSTATE 42615). The maximum value that can be specified for this threshold is 2 147 483 640 seconds. If any value (using the DAY, HOUR, MINUTE, or SECONDS time unit) has a seconds equivalent larger than the maximum value, an error is returned (SQLSTATE 42615).

UOWTOTALTIME > integer-value DAY | DAYS | HOUR | HOURS | MINUTE | MINUTES | SECONDS
This condition defines an upper bound for the amount of time the database manager will allow a unit of work to execute. This value can be any positive integer (not zero) (SQLSTATE 42820). Use a valid duration keyword to specify an appropriate unit of time for integer-value. If the specified time unit is SECONDS, the value must be a multiple of 10 (SQLSTATE 42615). The definition domain for this condition must be DATABASE, SERVICE SUPERCLASS, or WORKLOAD, and the enforcement scope must be DATABASE (SQLSTATE 5U037). This condition is logically enforced at the coordinator database partition.

The maximum value that can be specified for this threshold is 2 147 483 640 seconds. If any value (using the DAY, HOUR, MINUTE, or SECONDS time unit) has a seconds equivalent larger than the maximum value, an error is returned (SQLSTATE 42615).

SQLTEMPSPACE > integer-value K | M | G
This condition defines an upper bound for the size of a system temporary table space on any database partition. This value can be any positive integer (not zero) (SQLSTATE 42820).

If integer-value K (in either upper- or lowercase) is specified, the maximum size is 1024 times integer-value. If integer-value M is specified, the maximum size is 1 048 576 times integer-value. If integer-value G is specified, the maximum size is 1 073 741 824 times integer-value.

The definition domain for this condition must be DATABASE, work action (a threshold for a work action definition domain is created using a CREATE WORK ACTION SET or ALTER WORK ACTION SET statement, and the work action set must be applied to a workload or a database), SERVICE SUPERCLASS, SERVICE SUBCLASS, or WORKLOAD, and the enforcement scope must be DATABASE PARTITION (SQLSTATE 5U037). Activities tracked by this condition are:
  • Coordinator activities of type DML and corresponding subagent work (subsection execution).
  • Nested DML activities that are derived from user logic and their corresponding subagent work (subsection execution). Activities that are initiated by the database manager through a utility, procedure, or internal SQL are not affected by this condition.
AGGSQLTEMPSPACE > integer-value K | M | G

This condition defines the maximum amount of system temporary space that can be consumed in total across all activities in the definition domain on a database partition. This value can be any positive integer (not zero) (SQLSTATE 42820).

If integer-value K (in either upper- or lowercase) is specified, the maximum size is 1024 times integer-value. If integer-value M is specified, the maximum size is 1 048 576 times integer-value. If integer-value G is specified, the maximum size is 1 073 741 824 times integer-value.

The definition domain for this condition must be SERVICE SUBCLASS and the enforcement scope must be DATABASE PARTITION (SQLSTATE 5U037).

Activities contributing to the aggregate that is tracked by this condition are:

  • Coordinator activities of type DML and corresponding subagent work like subsection execution.
  • Nested DML activities that are derived from user logic and their corresponding subagent work like subsection execution. Activities initiated by the database manager through a utility, procedure, or internal SQL statement are not affected by this condition.
SQLROWSREAD > bigint-value
This condition defines an upper bound on the number of rows that may be read by an activity during its lifetime on a particular database partition. This value can be any positive big integer (not zero) (SQLSTATE 42820). Note that the number of rows read is different from the number of rows returned, which is controlled by the SQLROWSRETURNED condition.

The definition domain for this condition must be DATABASE, SERVICE CLASS, a service subclass (SERVICE CLASS specifying the UNDER clause), WORKLOAD or a work action (a threshold for a work action definition domain is created using a CREATE WORK ACTION SET or ALTER WORK ACTION SET statement, and the work action set must be applied to a workload or a database), and the enforcement scope must be DATABASE PARTITION (SQLSTATE 5U037). This condition is enforced independently at each database partition.

Activities tracked by this condition are:

  • Coordinator activities of type DML and corresponding subagent work (like subsection execution).
  • Nested DML activities that are derived from user logic and their corresponding subagent work (like subsection execution). Activities that are initiated by the database manager through a utility or procedure (with the exception of the ADMIN_CMD procedure) are not counted for this condition.
  • Internal SQL activities like those initiated by the setting of a constraint, or the refreshing of a materialized query table, are also not tracked by this threshold, because they are initiated by the database manager and not directly invoked by user logic.
CHECKING EVERY integer-value SECOND | SECONDS
Specifies how frequently the threshold condition is checked for an activity. The threshold is checked at the end of each request (like a fetch operation, for example) and on the interval defined by the CHECKING clause. The CHECKING clause defines an upper bound on how long a threshold violation may go undetected. The default is 60 seconds. The value can be any positive integer (not zero) with a maximum value of 86400 seconds (SQLSTATE 42820). Setting a low value may impact system performance negatively.
SQLROWSREADINSC > bigint-value
This condition defines an upper bound on the number of rows that may be read by an activity on a particular database partition while it is executing in a service subclass. Rows read before executing in the service subclass specified are not counted. This value can be any positive big integer (not zero) (SQLSTATE 42820). Note that the number of rows read is different from the number of rows returned, which is controlled by the SQLROWSRETURNED condition.

The definition domain for this condition must be a service subclass (SERVICE CLASS specifying the UNDER clause) and the enforcement scope must be DATABASE PARTITION (SQLSTATE 5U037). This condition is enforced independently at each database partition.

Activities tracked by this condition are:

  • Coordinator activities of type DML and corresponding subagent work (like subsection execution).
  • Nested DML activities that are derived from user logic and their corresponding subagent work (like subsection execution). Activities that are initiated by the database manager through a utility or procedure (with the exception of the ADMIN_CMD procedure) are not counted for this condition.
  • Internal SQL activities like those initiated by the setting of a constraint, or the refreshing of a materialized query table, are also not tracked by this threshold, because they are initiated by the database manager and not directly invoked by user logic.
CHECKING EVERY integer-value SECOND | SECONDS
Specifies how frequently the threshold condition is checked for an activity. The threshold is checked at the end of each request (like a fetch operation, for example) and on the interval defined by the CHECKING clause. The CHECKING clause defines an upper bound on how long a threshold violation may go undetected. The default is 60 seconds. The value can be any positive integer (not zero) with a maximum value of 86400 seconds (SQLSTATE 42820). Setting a low value may impact system performance negatively.
CPUTIME > integer-value HOUR | HOURS | MINUTE | MINUTES | SECOND | SECONDS
This condition defines an upper bound for the amount of processor time that an activity may consume during its lifetime on a particular database partition. The processor time tracked by this threshold is measured from the time that the activity starts executing. This value can be any positive integer (not zero) (SQLSTATE 42820).

The definition domain for this condition must be DATABASE, a service superclass (SERVICE CLASS), a service subclass (SERVICE CLASS specifying the UNDER clause), WORKLOAD or work action (a threshold for a work action definition domain is created using a CREATE WORK ACTION SET or ALTER WORK ACTION SET statement, and the work action set must be applied to a workload or a database), and the enforcement scope must be DATABASE PARTITION (SQLSTATE 5U037). This condition is enforced independently at each database partition.

Activities tracked by this condition are:

  • Coordinator activities of type DML and corresponding subagent work (like subsection execution).
  • Nested DML activities that are derived from user logic and their corresponding subagent work (like subsection execution). Activities that are initiated by the database manager through a utility or procedure (with the exception of the ADMIN_CMD procedure) are not counted for this condition.
  • Internal SQL activities, like those initiated by the setting of a constraint or the refreshing of a materialized query table, are also not tracked by this threshold, because they are initiated by the database manager and not directly invoked by user logic.
  • Activities of type CALL. For CALL activities, the processor time tracked for the procedure does not include the processor time used by any child activities or by any fenced mode processes. The threshold condition will be checked only upon return from user logic to the database engine. For example: During the execution of a trusted routine, the threshold condition will be checked only when the routine issues a request to the database engine).
CHECKING EVERY integer-value SECOND | SECONDS
Specifies how frequently the threshold condition is checked for an activity. The granularity of the CPUTIME threshold is approximately this number multiplied by the degree of parallelism for the activity. For example: If the threshold is checked every 60 seconds and the degree of parallelism is 2, the activity might use an extra 2 minutes of processor time instead of 1 minute before the threshold violation is detected. The default is 60 seconds. The value can be any positive integer (not zero) with a maximum value of 86400 seconds (SQLSTATE 42820). Setting a low value may impact system performance negatively.
CPUTIMEINSC > integer-value HOUR | HOURS | MINUTE | MINUTES | SECOND | SECONDS
This condition defines an upper bound for the amount of processor time that an activity may consume on a particular database partition while it is executing in a particular service subclass. The processor time tracked by this threshold is measured from the time that the activity starts executing in the service subclass identified in the threshold domain. Any processor time used before that point is not counted towards the limit imposed by this threshold. This value can be any positive integer (not zero) (SQLSTATE 42820).

The definition domain for this condition must be a service subclass (SERVICE CLASS specifying the UNDER clause), and the enforcement scope must be DATABASE PARTITION (SQLSTATE 5U037). This condition is enforced independently at each database partition.

Activities tracked by this condition are:

  • Coordinator activities of type DML and corresponding subagent work (like subsection execution).
  • Nested DML activities that are derived from user logic and their corresponding subagent work (like subsection execution). Activities that are initiated by the database manager through a utility or procedure (with the exception of the ADMIN_CMD procedure) are not counted for this condition.
  • Internal SQL activities, like those initiated by the setting of a constraint or the refreshing of a materialized query table, are also not tracked by this threshold, because they are initiated by the database manager and not directly invoked by user logic.
  • Activities of type CALL. For CALL activities, the processor time tracked for the procedure does not include the processor time used by any child activities or by any fenced mode processes. The threshold condition will be checked only upon return from user logic to the database engine. For example: During the execution of a trusted routine, the threshold condition will be checked only when the routine issues a request to the database engine).
CHECKING EVERY integer-value SECOND | SECONDS
Specifies how frequently the threshold condition is checked for an activity. The granularity of the CPUTIMEINSC threshold is approximately this number multiplied by the degree of parallelism for the activity. For example: If the threshold is checked every 60 seconds and the degree of parallelism is 2, the activity might use an extra 2 minutes of processor time instead of 1 minute before the threshold violation is detected. The default is 60 seconds. The value can be any positive integer (not zero) with a maximum value of 86400 seconds (SQLSTATE 42820). Setting a low value may impact system performance negatively.
threshold-exceeded-actions
Specifies what action is to be taken when a condition is exceeded. Each time that a condition is exceeded, an event is recorded in the threshold violations event monitor, if one is active.
COLLECT ACTIVITY DATA
Specifies that data about each activity that exceeded the threshold is to be sent to any active activities event monitor, when the activity completes. The default is COLLECT ACTIVITY DATA NONE. If COLLECT ACTIVITY DATA is specified, the default is WITHOUT DETAILS. The COLLECT ACTIVITY DATA setting does not apply to non-activity thresholds, such as the following: CONNECTIONIDLETIME, TOTALDBPARTITIONCONNECTIONS, TOTALSCPARTITIONCONNECTIONS, CONCURRENTWORKLOADOCCURRENCES, UOWTOTALTIME.
NONE
Specifies that activity data should not be collected for each activity that exceeds the threshold.
ON COORDINATOR DATABASE PARTITION
Specifies that the activity data is to be collected only at the database partition of the coordinator of the activity.
ON ALL DATABASE PARTITIONS
Specifies that the activity data is to be collected at all database partitions on which the activity is processed. On remote database partitions, a record for the activity may be captured multiple times as the activity comes and goes on those partitions. For predictive thresholds, activity information is collected at all partitions only if you also specify the CONTINUE action for exceeded thresholds. For reactive thresholds, the ON ALL DATABASE PARTITIONS clause has no effect and activity information is always collected only at the coordinator partition. For both predictive and reactive thresholds, any activity details, section information, or values will be collected only at the coordinator partition.
WITHOUT DETAILS
Specifies that data about each activity associated with the work class for which this work action is defined 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. For predictive thresholds, if section actuals are enabled, they will be collected on any partition where the activity data is collected. For reactive thresholds, if section actuals are enabled, they will be collected only on the coordinator partition.
AND VALUES
Specifies that input data values are to be sent to any active activities event monitor, for those activities that have them.
STOP EXECUTION
The execution of the activity is stopped and an error is returned (SQLSTATE 5U026). In the case of the UOWTOTALTIME threshold, the unit of work is rolled back.
CONTINUE
The execution of the activity is not stopped.
FORCE APPLICATION
The application is forced off the system (SQLSTATE 55032). This action can only be specified for the UOWTOTALTIME threshold.
remap-activity-action
REMAP ACTIVITY TO service-subclass-name
The activity is mapped to service-subclass-name.The execution of the activity is not stopped. This action is valid only for in-service-class thresholds like CPUTIMEINSC and SQLROWSREADINSC thresholds (SQLSTATE 5U037). The service-subclass-name must identify an existing service subclass under the same superclass associated with the threshold (SQLSTATE 5U037). The service-subclass-name cannot be the same as the associated service subclass of the threshold (SQLSTATE 5U037).
NO EVENT MONITOR RECORD
Specifies that no threshold violation record will be written.
LOG EVENT MONITOR RECORD
Specifies that if a THRESHOLD VIOLATIONS event monitor exists and is active, a threshold violation record is written to it.

Notes

Examples

Example 1: Create a threshold that enforces a maximum temporary table space usage of 50M (per database partition) to any activity in the database. Any activity that violates this threshold is to be stopped.
   CREATE THRESHOLD DBMAX50MEGTEMPSPACE
     FOR DATABASE ACTIVITIES
     ENFORCEMENT DATABASE PARTITION
     WHEN SQLTEMPSPACE > 50 M
     STOP EXECUTION
Example 2: Create a second threshold to limit the default runtime of any activity in the database to a maximum of 1 hour. Any activity that violates this threshold is to be stopped.
   CREATE THRESHOLD DBMAX1HOURRUNTIME
     FOR DATABASE ACTIVITIES
     ENFORCEMENT DATABASE
     WHEN ACTIVITYTOTALTIME > 1 HOUR
     STOP EXECUTION
Example 3: Assume that a service superclass named BIGQUERIES was created to host queries using more temporary space than average and running longer than 1 hour. The thresholds defined inside this service class will override the values that were set above at the database level. Note how activities violating the thresholds inside this superclass are allowed to continue executing, but detailed information is collected for further analysis.
   CREATE THRESHOLD BIGQUERIESMAX500MEGTEMPSPACE
     FOR SERVICE CLASS BIGQUERIES ACTIVITIES
     ENFORCEMENT DATABASE PARTITION
     WHEN SQLTEMPSPACE  > 500 M
     COLLECT ACTIVITY DATA WITH DETAILS AND VALUES
     CONTINUE

   CREATE THRESHOLD BIGQUERIESLONGRUNNINGTIME
     FOR SERVICE CLASS BIGQUERIES ACTIVITIES
     ENFORCEMENT DATABASE
     WHEN ACTIVITYTOTALTIME   > 10 HOURS
     COLLECT ACTIVITY DATA WITH DETAILS AND VALUES
     CONTINUE
Example 4: Assuming the existence of a workload named PAYROLL, create a threshold that enforces the maximum number of activities within the workload to be less than or equal to 10.
   CREATE THRESHOLD MAXACTIVITIESINPAYROLL
     FOR WORKLOAD PAYROLL ACTIVITIES
     ENFORCEMENT WORKLOAD OCCURRENCE
     WHEN CONCURRENTWORKLOADACTIVITIES > 10
     STOP EXECUTION
Example 5: Create a threshold that enforces a maximum concurrency of 2 activities in the service class BIGQUERIES.
   CREATE THRESHOLD MAXBIGQUERIESCONCURRENCY
     FOR SERVICE CLASS BIGQUERIES  ACTIVITIES
     ENFORCEMENT DATABASE
     WHEN  > 2
     STOP EXECUTION