Setting built-in global variables by using profile tables

You can create profiles to specify that Db2 sets global variable values for applications that meet the criteria that are defined in the profile, especially for remote applications that use TCP/IP connectivity to access Db2 for z/OS®. Start of changeFL 501 Profiles can also specify DEADLOCK_RESOLUTION_PRIORITY global variable values for local applications.End of change

Before you begin

If the Db2 profile tables and related objects does not exist on the Db2 subsystem, you must create them. For a list of the objects and how to create them, see Profile tables.

The distributed data facility (DDF) must be loaded, with the DDF subsystem parameter set to AUTO or COMMAND. See DDF STARTUP OPTION field (DDF subsystem parameter).

If you plan to use TCP/IP domain names for profile filtering, you must enable the database services address space (ssnmDBM1) to access TCP/IP services. See Enabling Db2 to access TCP/IP services in z/OS UNIX System Services.

This task describes one of several uses for profile tables. For an overview of how to use profile tables and a summary of the different uses, see Monitoring and controlling Db2 by using profile tables.

About this task

Setting global variables in profile tables allows you to override default built-in global variable values without changing application code. When a profile filter matches a connection attribute, Db2 automatically applies the global variable value to the Db2 process when the connection is initially established and whenever a connection is reused.

FL 501 Profiles that assign values to the DEADLOCK_RESOLUTION_PRIORITY built-in global variable can apply to remote TCP/IP applications only, local applications only, or both. Profiles for other built-in global variables apply only to remote TCP/IP applications. For more information, see the ATTRIBUTE2 column description.

For remote applications, the built-in global variable values persist for the lifetime of the connection unless the application explicitly sets the global variable. Built-in global variable values that are set explicitly by the application take precedence over values that are set in the profile tables. System directed connections, such as three-part name references, use the values of the global variables of the requesting Db2 site. For example, if a Java™ application establishes a connection to Db2 site 1, the global variable values are established with the profile tables from site 1. Later, if the application runs an SQL statement with an implicit three-part name connection to Db2 site 2, then the global variable values that are established on site 1 are referenced when the SQL statement runs on site 2.

Commit and rollback operations have no effect on the values of global variables, regardless of how they were established.

Procedure

To set global variables for specific remote applications, complete the following steps:

  1. In the SYSIBM.DSN_PROFILE_TABLE table, insert a row to create the profile and specify its filtering criteria:
    1. In the PROFILEID column, specify a unique value or accept the generated default value. This value identifies the profile and the relationship between DSN_PROFILE_TABLE and DSN_PROFILE_ATTRIBUTES rows.
    2. Specify the filtering criteria of the profile.
      You can specify values in the columns from one of the following filtering categories:
      Application type Filtering category
      Remote applications:
      • LOCATION only
      • PRDID only
      • AUTHID, ROLE, or both
      • COLLID, PKGNAME, or both
      • One of CLIENT_APPLNAME, CLIENT_USERID, or CLIENT_WRKSTNNAME
      The filtering values are not case-sensitive, and profiles can match regardless of the case of the input values.
      Start of changeFL 500 Local applications:End of change Start of change
      • AUTHID, ROLE, or both
      • COLLID, PKGNAME, or both
      • One of CLIENT_APPLNAME, CLIENT_USERID, or CLIENT_WRKSTNNAME
      The filtering values are not case-sensitive, and profiles can match regardless of the case of the input values.
      End of change

      Other filtering columns must contain the null value.

      Tip: If you create multiple profiles with overlapping filtering criteria, Db2 applies only one profile from each filtering category, based on a specific order of precedence. Start of changeIf multiple DSN_PROFILE_TABLE rows specify the same filtering criteria, only the newest is row is accepted when you start the profiles, and the other duplicates are rejected.End of change Also, exact values take precedence over values that use an asterisk (*) wildcard. However, profiles from different filtering categories can all apply. For more information about these rules, see How Db2 applies multiple matching profiles for threads and connections.
    3. In the PROFILE_ENABLED column, specify 'Y' so that the profile is enabled when profiles are started.
      If the PROFILE_AUTOSTART subsystem parameter setting is YES, the profile starts when you issue a START PROFILE command or when Db2 starts.
  2. Specify the global variables that you want to set by inserting SYSIBM.DSN_PROFILE_ATTRIBUTES rows:
    1. Specify the PROFILEID value from the DSN_PROFILE_TABLE row that specifies the filtering criteria for this profile.
      Tip: Start of changeUse the same PROFILEID value for any DSN_PROFILE_ATTRIBUTES rows that require the same filtering criteria. If multiple DSN_PROFILE_TABLE rows contain exactly matching filtering criteria, only the newest duplicate row is accepted when you start the profiles, and the others are rejected and disabled.End of change
    2. In the KEYWORDS column, specify 'GLOBAL_VARIABLE'.
    3. In the ATTRIBUTEn columns, specify the attributes of the profile:
    ATTRIBUTE1

    For GLOBAL_VARIABLE, specifies a SET statement to provide a value for a built-in global variable.

    The SET statement must adhere to the rules described in SET assignment-statement statement. Also, the following rules apply to the ATTRIBUTE1 value for SET statements for all supported built-in global variables:

    • The schema qualifier of the variable must be specified.
    • The SET statement must have an equal sign (=) between the global variable name and the value that is assigned.
    • Variable names can be specified in mixed case. Extraneous blanks between keywords are removed.
    • The value that is specified for assignment must be valid for the variable and must not be an expression, or reference other special registers or variables.
    • The value that is specified for assignment is passed through this interface as a string constant. For example, if a value to be assigned is the same as the name of a special register, Db2 stores the special register name, and not the special register value.
    • The maximum length of the SET statement is 1024 bytes.
    • The statement must be a Unicode string and encoded with the appropriate CCSID for the application.
    • The variable is assigned the value and it is stored as specified.

    You can set the following global variable values by using profile tables:

    Global variable Examples
    GET_ARCHIVE
    SET SYSIBMADM.GET_ARCHIVE = 'Y'
    FL 501 DEADLOCK_RESOLUTION_PRIORITY
    SET SYSIBMADM.DEADLOCK_RESOLUTION_PRIORITY = NULL 
    MAX_LOCKS_PER_TABLESPACE
    SET SYSIBMADM.MAX_LOCKS_PER_TABLESPACE = NULL 
    MAX_LOCKS_PER_USER
    SET SYSIBMADM.MAX_LOCKS_PER_USER = DEFAULT
    MOVE_TO_ARCHIVE
    SET SYSIBMADM.MOVE_TO_ARCHIVE = 'N'
    TEMPORAL_LOGICAL_TRANSACTION_TIME
    SET SYSIBM.TEMPORAL_LOGICAL_TRANSACTION_TIME = '2014-11-14-08.05.01.123456789'
    TEMPORAL_LOGICAL_TRANSACTIONS
    SET SYSIBM.TEMPORAL_LOGICAL_TRANSACTIONS = 0
    ATTRIBUTE2
    For GLOBAL_VARIABLE, species whether the profile applies to threads for remote applications, local applications, or both.

    FL 501 The value must be NULL unless the ATTRIBUTE1 value is DEADLOCK_RESOLUTION_PRIORITY.

    NULL
    The profile applies to remote threads only. The profile is evaluated and SET statements are processed only when the first package is loaded, and when the first SQL statement (other than a SET statement) in the package executes.
    1
    The profile applies to local threads only. The profile is evaluated and SET statements are processed when each package is loaded.
    2
    The profile applies to both local and remote threads. For remote threads, the behavior is the same as if the value is NULL. For local threads, the behavior is the same as if the value is 1.
    ATTRIBUTE3
    NULL
  3. Load or reload the profile tables into memory by issuing a START PROFILE command. (For best results, do not issue a STOP PROFILE command when you add or modify existing profiles. Use the STOP PROFILE command only if you intend to disable all existing profiles.) For more information, see Starting and stopping profiles.
  4. Check the status of all newly added profiles in the STATUS columns of the DSN_PROFILE_HISTORY and DSN_PROFILE ATTRIBUTES_HISTORY tables.
    Successful completion of the START PROFILE command does not imply that all profiles started successfully. If the STATUS column of either history table contains a value that does not start with 'ACCEPTED', further action is required to enable the profile or the keyword action.

Example

Suppose that you insert the following row into SYSIBM.DSN_PROFILE_ATTRIBUTES:
PROFILEID KEYWORDS ATTRIBUTE1 ATTRIBUTE TIMESTAMP
17 GLOBAL_VARIABLE SET SYSIBMADM.MOVE_TO_ARCHIVE = 'Y' 2016-10-21...
This row specifies that for all statements that match the filtering criteria in the DSN_PROFILE_TABLE row for PROFILEID='17', when a row is deleted from an archive-enabled table, Db2 stores a copy of the deleted row in the associated archive table. Additionally, an insert or update operation that specifies the archive-enabled table as the target of the statement returns an error.