SYSPACKAGE catalog table

The SYSPACKAGE table contains a row for every package. The schema is SYSIBM.

Column name Data type Description Use
LOCATION
VARCHAR(128)
NOT NULL
Always contains blanks S
COLLID
VARCHAR(128)
NOT NULL
Name of the package collection. For a trigger package, it is the schema name of the trigger. G
NAME
VARCHAR(128)
NOT NULL
Name of the package. G
CONTOKEN
CHAR(8)
NOT NULL
FOR BIT DATA
Consistency token for the package. For a package derived from a Db2 DBRM, it is one of the following values:
  • The level as specified by the LEVEL option when the package's program was precompiled
  • The timestamp indicating when the package's program was precompiled, in an internal format.
S
OWNER
VARCHAR(128)
NOT NULL
Authorization ID of the package owner. For a trigger package, the value is the authorization ID of the owner of the trigger, which is set to the current authorization ID (the plan or package owner for static CREATE TRIGGER statement; the CURRENT SQLID for a dynamic CREATE TRIGGER statement). G
CREATOR
VARCHAR(128)
NOT NULL
Start of changeAuthorization ID of the creator of the package. The creator is the authorization ID under which the package was bound or rebound.End of change For a trigger package, the value is determined differently. For dynamic SQL, it is the primary authorization ID of the user who issued the CREATE TRIGGER statement. For static SQL, it is the authorization ID of the plan or package owner. G
TIMESTAMP
TIMESTAMP
NOT NULL
Timestamp indicating when the package was created. G
BINDTIME
TIMESTAMP
NOT NULL
Timestamp indicating when the package was last bound. G
QUALIFIER
VARCHAR(128)
NOT NULL
Implicit qualifier for the unqualified table, view, index, and alias names in the static SQL statements of the package. G
PKSIZE
INTEGER
NOT NULL
Size of the base section1 of the package, in bytes. G
AVGSIZE
INTEGER
NOT NULL
Average size, in bytes, of those sections1 of the plan that contain SQL statements processed at bind time. G
SYSENTRIES
SMALLINT
NOT NULL
Number of enabled or disabled entries for this package in SYSIBM.SYSPKSYSTEM. A value of 0 if all types of connections are enabled. G
VALID
CHAR(1)
NOT NULL
Whether the package is valid:
A
An ALTER statement changed the description of the table or base table of a view referred to by the package. The changes do not invalidate the package. However, a rebind might be required for the package to pick up the changes from the ALTER statement.
H
An ALTER TABLE statement changed the description of the table or base table of a view referred to by the package. For releases of Db2 prior to Version 5, the change invalidates the package.
N
No
Y
Yes
G
OPERATIVE
CHAR(1)
NOT NULL
Whether the package can be allocated:
N
A package with package-level dependency cannot be allocated. An explicit BIND or REBIND is required before the package can be allocated.
Y
Yes
G
VALIDATE
CHAR(1)
NOT NULL
Whether validity checking can be deferred until run time:
B
All checking must be performed at bind time.
R
Validation is done at run time for tables, views, and privileges that do not exist at bind time.
G
ISOLATION
CHAR(1)
NOT NULL
Isolation level when the package was last bound or rebound
R
RR (repeatable read)
S
CS (cursor stability)
T
RS (read stability)
U
UR (uncommitted read)
blank
Not specified, and therefore at the level specified for the plan executing the package
G
RELEASE
CHAR(1)
NOT NULL
The value used for RELEASE when the package was last bound or rebound:
C
Value used was COMMIT.
D
Value used was DEALLOCATE.
I
The local package is inheriting the value from the plan
blank
Not specified, and therefore the value specified for the plan executing the package.
G
EXPLAIN
CHAR(1)
NOT NULL
EXPLAIN option specified for the package; that is, whether information on the package's statements was added to the owner of the PLAN_TABLE table:
N
No
Y
Yes
G
QUOTE
CHAR(1)
NOT NULL
SQL string delimiter for SQL statements in the package:
N
Apostrophe
Y
Quotation mark
G
COMMA
CHAR(1)
NOT NULL
Decimal point representation for SQL statements in package:
N
Period
Y
Comma
G
HOSTLANG
CHAR(1)
NOT NULL
Start of changeHost language, or a value set by the program preparation process:End of change
B
Assembler language
C
OS/VS COBOL
D
C
F
Fortran
J
Java™
P
PL/I
Start of changeREnd of change
Start of changeREST End of change
2
VS COBOL II or IBM® COBOL Release 1 (formerly called COBOL/370)
3
IBM COBOL (Release 2 or subsequent releases)
4
C++
blank
Start of changeFor remotely bound packages, trigger packages (TYPE='T' or '1'), SQL procedure packages (TYPE='N'), or non-inline SQL scalar function packages (TYPE='F').End of change
G
CHARSET
CHAR(1)
NOT NULL
Indicates whether the system CCSID for SBCS data was 290 (Katakana) when the program was precompiled:
K
Yes
A
No
G
MIXED
CHAR(1)
NOT NULL
Indicates if mixed data was in effect when the package's program was precompiled (for more on when mixed data is in effect, see Character strings):
N
No
Y
Yes
G
DEC31
CHAR(1)
NOT NULL
Indicates whether DEC31 was in effect when the package's program was precompiled (for more on when DEC31 is in effect, see Arithmetic with two decimal operands):
N
No
Y
Yes
G
DEFERPREP
CHAR(1)
NOT NULL
Indicates the CURRENTDATA option when the package was bound or rebound:
A
Data currency is required for all cursors. Inhibit blocking for all cursors.
B
Data currency is not required for ambiguous cursors.
C
Data currency is required for ambiguous cursors.
blank
The package was created before the CURRENTDATA option was available.
G
SQLERROR
CHAR(1)
NOT NULL
Indicates the SQLERROR option on the most recent subcommand that bound or rebound the package:
C
CONTINUE
N
NOPACKAGE
G
REMOTE
CHAR(1)
NOT NULL
Source of the package:
C
Package was created by BIND COPY.
D
Package was created by BIND COPY with the OPTIONS(COMMAND) option.
K
The package was copied from a package that was originally bound on behalf of a remote requester.
L
The package was copied with the OPTIONS(COMMAND) option from a package that was originally bound on behalf of a remote requester.
N
Package was locally bound from a DBRM.
Y
Package was bound on behalf of a remote requester.
G
PCTIMESTAMP
TIMESTAMP
NOT NULL
Date and time the application program was precompiled, or '0001-01-01-00.00.00.000000' if the LEVEL precompiler option was used, or if the package came from a non-Db2 location. G
IBMREQD
CHAR(1)
NOT NULL
A value of Y indicates that the row was provided with the Db2 product code. For all other values, see Release dependency indicators.

The value in this field is not a reliable indicator of release dependencies. RELBOUND should be used instead.

G
VERSION
VARCHAR(122)
NOT NULL
Version identifier for the package.
Start of change The value is an empty string for:
  • A package for a basic trigger (TYPE='T').
  • A package for an application that was precompiled without SQL processing option VERSION, or was precompiled with an empty string for the VERSION value. (TYPE=blank).
End of change
G
PDSNAME
VARCHAR(132)
NOT NULL
For a locally bound package, the name of the PDS (library) in which the package's DBRM is a member. For a locally copied package, the value in SYSPACKAGE.PDSNAME for the source package. Otherwise, the product signature of the bind requester followed by one of the following:
  • For Db2 for z/OS® remote requesters, the requester's location name, or IP address, or LU name enclosed in angle brackets (for example, <LUSQLDS>).
  • For non-Db2 for z/OS remote requesters, the requester's IP address or LU name enclosed in angle brackets.
G
DEGREE
CHAR(3)
NOT NULL WITH
DEFAULT
The DEGREE option used when the package was last bound:
ANY
DEGREE(ANY)
1 or blank
DEGREE(1). Blank if the package was migrated.
G
GROUP_MEMBER
VARCHAR(24)
NOT NULL WITH
DEFAULT
The Db2 data sharing member name of the Db2 subsystem that performed the most recent bind. This column is blank if the Db2 subsystem was not in a Db2 data sharing environment when the bind was performed. G
DYNAMICRULES
CHAR(1)
NOT NULL WITH
DEFAULT
The DYNAMICRULES option used when the package was last bound:
B
BIND. Dynamic SQL statements are executed with DYNAMICRULES bind behavior.
D
DEFINEBIND. When the package is run under an active stored procedure or user-defined function, dynamic SQL statements in the package are executed with DYNAMICRULES define behavior.

When the package is not run under an active stored procedure or user-defined function, dynamic SQL statements in the package are executed with DYNAMICRULES bind behavior.

E
DEFINERUN. When the package is run under an active stored procedure or user-defined function, dynamic SQL statements in the package are executed with DYNAMICRULES define behavior.

When the package is not run under an active stored procedure or user-defined function, dynamic SQL statements in the package are executed with DYNAMICRULES run behavior.

H
INVOKEBIND. When the package is run under an active stored procedure or user-defined function, dynamic SQL statements in the package are executed with DYNAMICRULES invoke behavior.

When the package is not run under an active stored procedure or user-defined function, dynamic SQL statements in the package are executed with DYNAMICRULES bind behavior.

G
DYNAMICRULES (continued)  
I
INVOKERUN. When the package is run under an active stored procedure or user-defined function, dynamic SQL statements in the package are executed with DYNAMICRULES invoke behavior.

When the package is not run under an active stored procedure or user-defined function, dynamic SQL statements in the package are executed with DYNAMICRULES run behavior.

R
RUN. Dynamic SQL statements are executed with DYNAMICRULES run behavior.
blank
DYNAMICRULES is not specified for the package. The package uses the DYNAMICRULES value of the plan to which the package is appended at execution time.
For a description of the DYNAMICRULES behaviors, see Authorization IDs and dynamic SQL.
 
REOPTVAR
CHAR(1)
NOT NULL WITH
DEFAULT 'N'
Whether the access path is determined again at execution time using input variable values:
A
Bind option REOPT(AUTO) indicates that the access path is determined multiple times at execution time depending on the parameter value.
N
Bind option REOPT(NONE) indicates that the access path is determined at bind time.
Y
Bind option REOPT(ALWAYS) indicates that the access path is determined at execution time for SQL statements with variable values.
1
Bind option REOPT(ONCE) indicates that the access path is determined only once at execution time, using the first set of input variable values, regardless of how many times the same statement is executed.
G
DEFERPREPARE
CHAR(1)
NOT NULL WITH
DEFAULT
Whether PREPARE processing is deferred until OPEN is executed:
N
Bind option NODEFER(PREPARE) indicates that PREPARE processing is not deferred until OPEN is executed.
Y
Bind option DEFER(PREPARE) indicates that PREPARE processing is deferred until OPEN is executed.
I
The local package is inheriting the value from the plan
blank
Start of changeBlank for a trigger package. Otherwise, the bind option was not specified for the package and is inherited from the plan.End of change
G
KEEPDYNAMIC
CHAR(1)
NOT NULL WITH
DEFAULT 'N'
Whether prepared dynamic statements are to be purged at each commit point:
N
The bind option is KEEPDYNAMIC(NO). Start of changePrepared dynamic SQL statements are destroyed at each commit point or rollback operation.End of change
Y
The bind option is KEEPDYNAMIC(YES). Start of changePrepared dynamic SQL statements are kept past each commit point or rollback operation.End of change
G
PATHSCHEMAS
VARCHAR(2048)
NOT NULL WITH
DEFAULT
SQL path specified on the BIND or REBIND command that bound the package. The path is used to resolve unqualified data type, function, and stored procedure names used in certain contexts. If the PATH bind option was not specified, the value in the column is a zero length string; however, Db2 uses the default SQL path. G
TYPE
CHAR(1)
NOT NULL WITH
DEFAULT
Type of package. Identifies how the package is created:
F
A CREATE FUNCTION or ALTER FUNCTION statement, or a BIND PACKAGE DEPLOY command created the package, and this package is a compiled SQL scalar function package.
N
A CREATE PROCEDURE or ALTER PROCEDURE statement, or BIND PACKAGE DEPLOY command created the package, and this package is a native SQL routine package.
Start of changeTEnd of change
Start of changeA CREATE TRIGGER or ALTER TRIGGER statement for a basic trigger created the package.End of change
blank
BIND PACKAGE command created the package.
Start of change1End of change
Start of changeA CREATE TRIGGER or ALTER TRIGGER statement for an advanced trigger created the package.End of change
G
DBPROTOCOL
CHAR(1)
NOT NULL WITH
DEFAULT 'D'
Whether remote access for SQL is implemented with DRDA access or DRDA access with the capability for package-based continuous block fetch:
D
DRDA
C
DRDA access with package-based continuous block fetch enabled.
G
FUNCTIONTS
TIMESTAMP
NOT NULL WITH
DEFAULT
Timestamp when the function was resolved. This value is set by the BIND and REBIND commands, but not by automatic rebinds (autobind). G
OPTHINT
VARCHAR(128)
NOT NULL WITH
DEFAULT
Value of the OPTHINT bind option. Identifies rows in owner.PLAN_TABLE that are to be used as input to Db2. Refer to the ACCESSPATH column in the SYSPACKSTMT catalog table for information about which statements are using the specified hints. G
ENCODING_CCSID
INTEGER
NOT NULL WITH
DEFAULT
The CCSID corresponding to the encoding scheme or CCSID as specified for the bind option ENCODING. The Encoding Scheme specified on the bind command:
ccsid
The specified or derived CCSID.
0
The default CCSID as specified on panel DSNTIPF at installation time. Used when the package was bound prior to Version 7.
G
IMMEDWRITE
CHAR(1)
NOT NULL WITH
DEFAULT
Indicates when writes of updated group buffer pool dependent pages are to be done. This option is only applicable for data sharing environments.
I
The local package is inheriting the value from the plan
N
Bind option IMMEDWRITE(NO) indicates normal write activity is done.
Y
Bind option IMMEDWRITE(YES) indicates that immediate writes are done for updated group buffer pool dependent pages.
1
Bind option IMMEDWRITE(PH1) indicates that updated group buffer pool dependent pages are written at or before phase 1 commit.
blank
A migrated package.
G
RELBOUND
CHAR(1)
NOT NULL WITH
DEFAULT
The release when the package was bound or rebound.
blank
Bound prior to Version 7
For all other values, see Release dependency indicators
G
CATENCODE
CHAR(1)
Not used. N
REMARKS
VARCHAR(550)
NOT NULL WITH
DEFAULT
A character string provided by the user with the COMMENT statement. G
OWNERTYPE
CHAR(1)
NOT NULL WITH
DEFAULT
Indicates the type of owner
blank
Authorization ID
L
Role
G
ROUNDING
CHAR(1)
NOT NULL WITH
DEFAULT
The ROUNDING option used when the package was last bound:
C
ROUND_CEILING
D
ROUND_DOWN
F
ROUND_FLOOR
G
ROUND_HALF_DOWN
E
ROUND_HALF_EVEN
H
ROUND_HALF_UP
U
ROUND_UP
blank
The package created in a Db2 release prior to Version 9.
G
DISTRIBUTE
CHAR(1)
NOT NULL WITH
DEFAULT 'N'
Determines if Db2 should gather location names from SQL statements, and create remote packages for the user (This only has effect during local bind):
A
Db2 will collect remote location names from SQL statements during local bind, and automatically create remote packages at those sites. The site names are gathered from object names in static SQL statements and literals on CONNECT statements. The sites at which the package is remotely bound can be determined by the location (BTYPE='X') records in SYSIBM.SYSPACKDEP for this package.
L
Db2 will automatically create remote packages at the sites specified in the list of location-names. The sites at which the package is remotely bound can be determined by the location (BTYPE='X') records in SYSIBM.SYSPACKDEP for this package.
G
LASTUSED
DATE
NOT NULL
WITH DEFAULT
The last date that the package was used. The LASTUSED value is set to '0001-01-01' when the package is created, and the value is updated whenever the package is used.2 The following commands preserve the existing value:
  • BIND REPLACE of the same package version
  • REBIND
G
CONCUR_ACC_RES
CHAR(1)
NOT NULL
Indicates the CONCURRENTACCESSRESOLUTION option when the package was bound or rebound:
blank
Not specified
U
USECURRENTLYCOMMITTED
W
WAITFOROUTCOME
G
EXTENDEDINDICATOR
CHAR(1)
NOT NULL
WITH DEFAULT
The value of the EXTENDEDINDICATOR bind option:
blank
Not specified
N
EXTENDEDINDICATOR NO
Y
EXTENDEDINDICATOR YES
G
COPYID
INTEGER
NOT NULL
Start of changeThe current copy of the package.End of change Start of changeGEnd of change
PLANMGMT
CHAR(1)
NOT NULL
WITH DEFAULT
The value of the PLANMGMT bind option:
E
PLANMGMT EXTENDED
B
PLANMGMT BASIC
blank
PLANMGMT OFF
G
PLANMGMTSCOPE
CHAR(1)
NOT NULL
WITH DEFAULT
The value of the PLANMGMTSCOPE bind option:
S
PLANMGMTSCOPE STATIC
G
APREUSE
CHAR(1)
NOT NULL
WITH DEFAULT
The value of the APREUSE bind option at the conclusion of a successful bind operation.
N
NO or NONE: Access paths were not reused.
W
WARN: Db2 attempted to reuse access paths. If an access path could not be reused, Db2 generated a new access path.
E
ERROR: Access paths were successfully reused. No error condition prevented Db2 from reusing access paths.
G
APRETAINDUP
CHAR(1)
NOT NULL
WITH DEFAULT
The value of the APRETAINDUP bind option:
Y
APRETAINDUP YES specified. All copies were retained.
0
APRETAINDUP NO specified; however, the previous or original package copy is still retained due to access path differences.
1
APRETAINDUP NO specified, and the previous package copy is not retained as the access paths are identical to the current copy.
2
APRETAINDUP NO specified, and the previous and original package copies are not retained as the access paths are identical to the current copy.
G
SYSTIMESENSITIVE
CHAR(1)
NOT NULL
WITH DEFAULT 'N'
The value of the SYSTIMESENSITIVE bind option:
Y
References to system-period temporal tables are affected by the value of the CURRENT TEMPORAL SYSTEM_TIME special register.
N
References to system-period temporal tables are not affected by the value of the CURRENT TEMPORAL SYSTEM_TIME special register.
G
RECORDTEMPORALHIST
CHAR(1)
NOT NULL
WITH DEFAULT 'Y'
Not used. N
BUSTIMESENSITIVE
CHAR(1)
NOT NULL
WITH DEFAULT  'N'
The value of the BUSTIMESENSITIVE bind option:
Y
References to application-period temporal tables are affected by the value of the CURRENT TEMPORAL BUSINESS_TIME special register.
N
References to application-period temporal tables are not affected by the value of the CURRENT TEMPORAL BUSINESS_TIME special register.
G
APPLCOMPAT
VARCHAR(10)
NOT NULL
WITH DEFAULT
The application compatibility level of the package, or blank if the package was bound before Db2 11, or not determined.
Start of changeVvvRrMmmmEnd of change
Start of change

Compatibility with the behavior of the identified Db2 function level. For example, V12R1M510 specifies compatibility with the highest available Db2 12 function level. The equivalent function level or higher must be activated.

Start of changeFor the new capabilities that become available in each application compatibility level, see: End of change

Tip: Start of changeExtra program preparation steps might be required to increase the application compatibility level for applications that use data server clients or drivers to access Db2 for z/OS. For more information, see Setting application compatibility levels for data server clients and drivers.End of change
End of change
Start of changeV12R1End of change
Start of changeCompatibility with the behavior of Db2 12 function level 500. This value has the same result as specifying V12R1M500.End of change
V11R1
Compatibility with the behavior of Db2 11 new-function mode. After migration to Db2 12, this value has the same result as specifying V12R1M100. For more information, see V11R1 application compatibility level
V10R1
Compatibility with the behavior of DB2® 10 new-function mode. For more information, see V10R1 application compatibility level.
G
ARCHIVESENSITIVE
CHAR(1)
NOT NULL
WITH DEFAULT 'N'
The value of the ARCHIVESENSITIVE bind option.
Y
References to archive-enabled tables are affected by the value of the SYSIBMADM.GET_ARCHIVE built-in global variable. Y is the default value.
N
References to archive-enabled tables are not affected by the value of the SYSIBMADM.GET_ARCHIVE built-in global variable.
G
EXTSEQNO
INTEGER
NOT NULL
WITH DEFAULT 0
Internal use only. I
DESCSTAT
CHAR(1)
NOT NULL
WITH DEFAULT
The value of the DESCSTAT bind option.
Y
The Db2 database manager generates a DESCRIBE SQLDA at bind time so that DESCRIBE requests for static SQL can be satisfied during execution.
N
The Db2 database manager does not generate a DESCRIBE SQLDA at bind time for static SQL statements.
blank
The package was bound before Db2 11, or not determined.
G
ORIGIN CHAR(1) NOT NULL WITH DEFAULT The origin of the EXPLAIN records:
A
Automatic bind
B
BIND command
G
Start of changeImplicit automatic regeneration of the SQL routine or trigger for changed options, or an explicit ALTER REGENERATE of the SQL routine or trigger for the packageEnd of change
I
Start of changeImplicit automatic regeneration of the SQL routine or trigger for the package because of fallback, coexistence, or deployment to a different release where the routines or triggers are incompatible. End of change
R
REBIND command
blank
The row existed before Db2 12. This is the default value.
G
Start of changeAPREUSE_NO_FLEnd of change Start of changeVARCHAR(10) NOT NULL WITH DEFAULTEnd of change Start of changeThe function level when the package was bound with APREUSE(NO), or blank if the package was bound before Db2 12, or not determined. This is the default value.End of change Start of changeGEnd of change
Start of changeAPREUSE_NO_TSEnd of change Start of changeTIMESTAMP NOT NULL WITH DEFAULTEnd of change Start of changeThe bind time when the package was bound with APREUSE(NO):
0001-01-01-00.00.00.000000
The package was bound before Db2 12. This is the default value.
End of change
Start of changeGEnd of change
Start of changeCONC_STMTEnd of change Start of changeCHAR(1) NOT NULL WITH DEFAULT 'N'End of change Start of changeWhether statement concentration is enabled:
N
No. This is the default value.
Y
Yes
End of change
Start of changeGEnd of change
Start of changeFUNCTION_LVLEnd of change Start of changeStart of changeVARCHAR(10) NOT NULL WITH DEFAULTEnd of changeEnd of change Start of changeThe function level of the package, or blank if the package was bound before Db2 12, or not determined.End of change Start of changeGEnd of change
1 Packages are divided into sections. The base section of the package must be in the EDM pool during the entire time the package is executing. Other sections of the package, corresponding roughly to sets of related SQL statements, are brought into the pool as needed.
2 Start of changeThe value is not updated instantly. There might be a delay of several days before the value is updated.End of change