New enhancements from IBM minimize disk activity and disk storage requirements.
As documented in a previous TechTip, the Database Monitor is a great tool for collecting SQL performance data. However, you must apply great care when using this tool because it can cause significant disk activity on your system and quickly consume disk space. Recently, IBM introduced enhancements to minimize the disk activity and disk storage requirements associated with database monitor collections.
When a DB2 for i Database Monitor is active, the collected performance data is written to a normal DB2 table (i.e., physical file) known as the monitor output table. By default, the output table used by the monitor has no storage allocated. As a result, some of the database monitor overhead is caused by the system having to allocate disk storage for the monitor output table at the same time that DB2 for i is writing monitor records to the same output table. This overhead can be significant when a monitor collection is active on a workload that is executing a large number of SQL statements. To minimize the storage allocation overhead, an INITIAL_RECORDS attribute can now be specified on the Start Database Monitor (STRDBMON) CL command to pre-allocate storage for the specified output table before any database monitor data is collected. Here's an example of how to specify the pre-allocation on the STRDBMON command:
STRDBMON OUTFILE(MYLIB/OUTPUT1) JOB(QZDASOINIT)
COMMENT('INITIAL_RECORDS(100000)')
Like the monitor filters discussed in my previous tip, the INITIAL_RECORDS attribute must be specified on the COMMENT parameter. A new command parameter was not possible because IBM is delivering this enhancement via a PTF instead of a new version of the IBM i operating system. PTFs are available for both V5R4 (SI34914, SI34889) and V6R1 (SI34915, SI34887).
In this example, storage for 100,000 monitor records will be initially allocated for the specified output table (MYLIB/OUTPUT1). If more than 100,000 rows of monitor data are generated, DB2 will extend the size of the output table by allocating space for 32,767 more rows. DB2 will allow the table size to be extended 32,767 times. This means that the output table in this example can contain over 1 billion rows. Collecting that much Database Monitor data is not recommended, but at least you know that specifying the INITIAL_RECORDS filter will not severely limit the maximum size of a monitor output table.
In addition to the large number of rows that can be written to a database monitor output table, the hundreds of columns contained in a monitor table also quickly eat up disk space. To be exact, the database monitor output table is made up of 276 columns, with several of those columns having column lengths longer than 1,000 bytes. Most people who analyze Database Monitor data for performance issues or execution history do not require use of all 276 columns. The vast majority of the monitor table disk space is allocated to columns that will never be touched.
As a result, IBM has delivered a set of 6.1 PTFs (SI34889, SI35060, SI35061, SI35063, SI35064, SI35066, SI35217) to enable the use of views. The SQL view and underlying table definition are used to identify the subset of columns that the user plans to reference and use during analysis.
The SQL view approach requires multiple steps. The first step is to create a table that contains the desired columns from the monitor output table. This is accomplished by using the CREATE TABLE AS SELECT syntax, with the SELECT statement referencing the master monitor output table, QAQQDBMN, provided in QSYS:
CREATE TABLE mylib/sub_dbmon AS (SELECT
QQSTIM, /* Start timestamp */
QQETIM, /* End timestamp */
QQ1000L, /* SQL statement text */
QQJOB , /* Job name */
QQUSER , /* Job user */
QQJNUM , /* Job number */
QVC102 , /* Current user */
QQC104 , /* Program/package library */
QQC103 , /* Program/package name */
QQC183, /* IP Address */
QQRID, /* DBMon row type */
QQI5, /* Iteration of QQUCNT */
QQUCNT, /* Unique query counter */
QQJFLD /* Unique identifier
across jobs */
FROM QSYS/QAQQDBMN) WITH NO DATA;
In this example, only 14 of the 276 columns from the output monitor have been chosen. However, you can see from the comments describing the subsetted columns that the monitor still contains enough data to describe where the SQL statement came from, who ran the statement, and what the text of the SQL statement is.
The next step is to create an SQL view over the subsetted monitor table (mylib/sub_dbmon). In contrast to the underlying subsetted monitor table, the SQL view does need to contain a reference to all 276 of the columns that exist in the master monitor table definition. In the sample view below, notice that the unwanted columns are converted to a null value. For instance, the QQTIME column is not referenced in the sub_dbmon table definition and is cast as a null value in the view definition. This is the real trick in having only a subset of the database monitor columns copied to the underlying monitor output table. The cast derivation makes the associated column an input-only field in logical file terminology. Input-only means that values can only be read from the column of the SQL view; any new values supplied to an input-only column via insert or update operations are ignored. This input-only behavior also occurs during updates and inserts made to the view by the DB2 for i database monitor.
CREATE VIEW mylib.mon_view AS SELECT
QQRID AS "Row Type",
CAST(NULL AS TIMESTAMP) AS QQTIME,
QQJFLD AS "Unique Identifier-Across Jobs",
CAST(NULL AS CHAR(18)) AS QQRDBN,
CAST(NULL AS CHAR(8)) AS QQSYS,
QQJOB AS "Job Name",
QQUSER AS "Job User",
QQJNUM AS "Job Number",
QQUCNT AS "Query Identifier",
CAST(NULL AS VARCHAR(100)) AS QQUDEF,
CAST(NULL AS DECIMAL(15,0)) AS QQSTN,
CAST(NULL AS DECIMAL(15,0)) AS QQQDTN,
CAST(NULL AS DECIMAL(15,0)) AS QQQDTL,
CAST(NULL AS DECIMAL(15,0)) AS QQMATN,
CAST(NULL AS DECIMAL(15,0)) AS QQMATL,
CAST(NULL AS CHAR(10)) AS QQTLN,
CAST(NULL AS CHAR(10)) AS QQTFN,
CAST(NULL AS CHAR(10)) AS QQTMN,
CAST(NULL AS CHAR(10)) AS QQPTLN,
CAST(NULL AS CHAR(10)) AS QQPTFN,
CAST(NULL AS CHAR(10)) AS QQPTMN,
CAST(NULL AS CHAR(10)) AS QQILNM,
CAST(NULL AS CHAR(10)) AS QQIFNM,
CAST(NULL AS CHAR(10)) AS QQIMNM,
CAST(NULL AS CHAR(10)) AS QQNTNM,
CAST(NULL AS CHAR(10)) AS QQNLNM,
QQSTIM AS "Start Time",
QQETIM AS "End Time",
CAST(NULL AS CHAR(1)) AS QQKP ,
CAST(NULL AS CHAR(1)) AS QQKS ,
CAST(NULL AS DECIMAL(15,0)) AS QQTOTR ,
CAST(NULL AS DECIMAL(15,0)) AS QQTMPR ,
CAST(NULL AS DECIMAL(15,0)) AS QQJNP ,
CAST(NULL AS DECIMAL(15,0)) AS QQEPT ,
CAST(NULL AS CHAR(1)) AS QQDSS ,
CAST(NULL AS CHAR(1)) AS QQIDXA ,
CAST(NULL AS CHAR(1)) AS QQORDG ,
CAST(NULL AS CHAR(1)) AS QQGRPG ,
CAST(NULL AS CHAR(1)) AS QQJNG ,
CAST(NULL AS CHAR(1)) AS QQUNIN ,
CAST(NULL AS CHAR(1)) AS QQSUBQ ,
CAST(NULL AS CHAR(1)) AS QQHSTV ,
CAST(NULL AS CHAR(1)) AS QQRCDS ,
CAST(NULL AS CHAR(2)) AS QQRCOD ,
CAST(NULL AS DECIMAL(15,0)) AS QQRSS ,
CAST(NULL AS DECIMAL(15,0)) AS QQREST ,
CAST(NULL AS DECIMAL(15,0)) AS QQRIDX ,
CAST(NULL AS DECIMAL(15,0)) AS QQFKEY ,
CAST(NULL AS DECIMAL(15,0)) AS QQKSEL ,
CAST(NULL AS DECIMAL(15,0)) AS QQAJN ,
CAST(NULL AS VARCHAR(1000)) AS QQIDXD ,
CAST(NULL AS CHAR(1)) AS QQC11 ,
CAST(NULL AS CHAR(1)) AS QQC12 ,
CAST(NULL AS CHAR(1)) AS QQC13 ,
CAST(NULL AS CHAR(1)) AS QQC14 ,
CAST(NULL AS CHAR(1)) AS QQC15 ,
CAST(NULL AS CHAR(1)) AS QQC16 ,
CAST(NULL AS CHAR(1)) AS QQC18 ,
CAST(NULL AS CHAR(2)) AS QQC21 ,
CAST(NULL AS CHAR(2)) AS QQC22 ,
CAST(NULL AS CHAR(2)) AS QQC23 ,
CAST(NULL AS DECIMAL(15,0)) AS QQI1 ,
CAST(NULL AS DECIMAL(15,0)) AS QQI2 ,
CAST(NULL AS DECIMAL(15,0)) AS QQI3 ,
CAST(NULL AS DECIMAL(15,0)) AS QQI4 ,
QQI5 AS "QQUCNT Iteration Counter",
CAST(NULL AS DECIMAL(15,0)) AS QQI6 ,
CAST(NULL AS DECIMAL(15,0)) AS QQI7 ,
CAST(NULL AS DECIMAL(15,0)) AS QQI8 ,
CAST(NULL AS DECIMAL(15,0)) AS QQI9 ,
CAST(NULL AS DECIMAL(15,0)) AS QQIA ,
CAST(NULL AS DECIMAL(15,0)) AS QQF1 ,
CAST(NULL AS DECIMAL(15,0)) AS QQF2 ,
CAST(NULL AS DECIMAL(15,0)) AS QQF3 ,
CAST(NULL AS CHAR(6)) AS QQC61 ,
CAST(NULL AS CHAR(8)) AS QQC81 ,
CAST(NULL AS CHAR(8)) AS QQC82 ,
CAST(NULL AS CHAR(8)) AS QQC83 ,
CAST(NULL AS CHAR(8)) AS QQC84 ,
CAST(NULL AS CHAR(10)) AS QQC101 ,
CAST(NULL AS CHAR(10)) AS QQC102 ,
QQC103 AS "Program Name",
QQC104 AS "Program Library",
CAST(NULL AS CHAR(10)) AS QQC105 ,
CAST(NULL AS CHAR(10)) AS QQC106 ,
CAST(NULL AS VARCHAR(128)) AS QQC181 ,
CAST(NULL AS VARCHAR(128)) AS QQC182 ,
QQC183 AS "IP Address",
CAST(NULL AS VARCHAR(30)) AS QQC301 ,
CAST(NULL AS VARCHAR(30)) AS QQC302 ,
CAST(NULL AS VARCHAR(30)) AS QQC303 ,
CAST(NULL AS VARCHAR(1000)) AS QQ1000 ,
CAST(NULL AS TIMESTAMP) AS QQTIM1 ,
CAST(NULL AS TIMESTAMP) AS QQTIM2 ,
CAST(NULL AS VARCHAR(128)) AS QVQTBL ,
CAST(NULL AS VARCHAR(128)) AS QVQLIB ,
CAST(NULL AS VARCHAR(128)) AS QVPTBL ,
CAST(NULL AS VARCHAR(128)) AS QVPLIB ,
CAST(NULL AS VARCHAR(128)) AS QVINAM ,
CAST(NULL AS VARCHAR(128)) AS QVILIB ,
CAST(NULL AS CHAR(1)) AS QVQTBLI ,
CAST(NULL AS CHAR(1)) AS QVPTBLI ,
CAST(NULL AS CHAR(1)) AS QVINAMI ,
CAST(NULL AS CHAR(1)) AS QVBNDY ,
CAST(NULL AS CHAR(1)) AS QVJFANO ,
CAST(NULL AS CHAR(1)) AS QVPARPF ,
CAST(NULL AS CHAR(1)) AS QVPARPL ,
CAST(NULL AS CHAR(1)) AS QVC11 ,
CAST(NULL AS CHAR(1)) AS QVC12 ,
CAST(NULL AS CHAR(1)) AS QVC13 ,
CAST(NULL AS CHAR(1)) AS QVC14 ,
CAST(NULL AS CHAR(1)) AS QVC15 ,
CAST(NULL AS CHAR(1)) AS QVC16 ,
CAST(NULL AS CHAR(1)) AS QVC17 ,
CAST(NULL AS CHAR(1)) AS QVC18 ,
CAST(NULL AS CHAR(1)) AS QVC19 ,
CAST(NULL AS CHAR(1)) AS QVC1A ,
CAST(NULL AS CHAR(1)) AS QVC1B ,
CAST(NULL AS CHAR(1)) AS QVC1C ,
CAST(NULL AS CHAR(1)) AS QVC1D ,
CAST(NULL AS CHAR(1)) AS QVC1E ,
CAST(NULL AS CHAR(1)) AS QVC1F ,
CAST(NULL AS CHAR(1)) AS QWC11 ,
CAST(NULL AS CHAR(1)) AS QWC12 ,
CAST(NULL AS CHAR(1)) AS QWC13 ,
CAST(NULL AS CHAR(1)) AS QWC14 ,
CAST(NULL AS CHAR(1)) AS QWC15 ,
CAST(NULL AS CHAR(1)) AS QWC16 ,
CAST(NULL AS CHAR(1)) AS QWC17 ,
CAST(NULL AS CHAR(1)) AS QWC18 ,
CAST(NULL AS CHAR(1)) AS QWC19 ,
CAST(NULL AS CHAR(1)) AS QWC1A ,
CAST(NULL AS CHAR(1)) AS QWC1B ,
CAST(NULL AS CHAR(1)) AS QWC1C ,
CAST(NULL AS CHAR(1)) AS QWC1D ,
CAST(NULL AS CHAR(1)) AS QWC1E ,
CAST(NULL AS CHAR(1)) AS QWC1F ,
CAST(NULL AS CHAR(2)) AS QVC21 ,
CAST(NULL AS CHAR(2)) AS QVC22 ,
CAST(NULL AS CHAR(2)) AS QVC23 ,
CAST(NULL AS CHAR(2)) AS QVC24 ,
CAST(NULL AS DECIMAL(15,0)) AS QVCTIM ,
CAST(NULL AS DECIMAL(15,0)) AS QVPARD ,
CAST(NULL AS DECIMAL(15,0)) AS QVPARU ,
CAST(NULL AS DECIMAL(15,0)) AS QVPARRC ,
CAST(NULL AS DECIMAL(15,0)) AS QVRCNT ,
CAST(NULL AS DECIMAL(15,0)) AS QVFILES ,
CAST(NULL AS DECIMAL(15,0)) AS QVP151 ,
CAST(NULL AS DECIMAL(15,0)) AS QVP152 ,
CAST(NULL AS DECIMAL(15,0)) AS QVP153 ,
CAST(NULL AS DECIMAL(15,0)) AS QVP154 ,
CAST(NULL AS DECIMAL(15,0)) AS QVP155 ,
CAST(NULL AS DECIMAL(15,0)) AS QVP156 ,
CAST(NULL AS DECIMAL(15,0)) AS QVP157 ,
CAST(NULL AS DECIMAL(15,0)) AS QVP158 ,
CAST(NULL AS DECIMAL(15,0)) AS QVP159 ,
CAST(NULL AS DECIMAL(15,0)) AS QVP15A ,
CAST(NULL AS DECIMAL(15,0)) AS QVP15B ,
CAST(NULL AS DECIMAL(15,0)) AS QVP15C ,
CAST(NULL AS DECIMAL(15,0)) AS QVP15D ,
CAST(NULL AS DECIMAL(15,0)) AS QVP15E ,
CAST(NULL AS DECIMAL(15,0)) AS QVP15F ,
CAST(NULL AS CHAR(4)) AS QVC41 ,
CAST(NULL AS CHAR(4)) AS QVC42 ,
CAST(NULL AS CHAR(4)) AS QVC43 ,
CAST(NULL AS CHAR(4)) AS QVC44 ,
CAST(NULL AS CHAR(8)) AS QVC81 ,
CAST(NULL AS CHAR(8)) AS QVC82 ,
CAST(NULL AS CHAR(8)) AS QVC83 ,
CAST(NULL AS CHAR(8)) AS QVC84 ,
CAST(NULL AS CHAR(8)) AS QVC85 ,
CAST(NULL AS CHAR(8)) AS QVC86 ,
CAST(NULL AS CHAR(8)) AS QVC87 ,
CAST(NULL AS CHAR(8)) AS QVC88 ,
CAST(NULL AS CHAR(10)) AS QVC101 ,
QVC102 AS "User Name",
CAST(NULL AS CHAR(10)) AS QVC103 ,
CAST(NULL AS CHAR(10)) AS QVC104 ,
CAST(NULL AS CHAR(10)) AS QVC105 ,
CAST(NULL AS CHAR(10)) AS QVC106 ,
CAST(NULL AS CHAR(10)) AS QVC107 ,
CAST(NULL AS CHAR(10)) AS QVC108 ,
CAST(NULL AS VARCHAR(128)) AS QVC1281 ,
CAST(NULL AS VARCHAR(128)) AS QVC1282 ,
CAST(NULL AS VARCHAR(128)) AS QVC1283 ,
CAST(NULL AS VARCHAR(128)) AS QVC1284 ,
CAST(NULL AS VARCHAR(300)) AS QVC3001 ,
CAST(NULL AS VARCHAR(300)) AS QVC3002 ,
CAST(NULL AS VARCHAR(300)) AS QVC3003 ,
CAST(NULL AS VARCHAR(300)) AS QVC3004 ,
CAST(NULL AS VARCHAR(300)) AS QVC3005 ,
CAST(NULL AS VARCHAR(300)) AS QVC3006 ,
CAST(NULL AS VARCHAR(300)) AS QVC3007 ,
CAST(NULL AS VARCHAR(300)) AS QVC3008 ,
CAST(NULL AS VARCHAR(500)) AS QVC5001 ,
CAST(NULL AS VARCHAR(500)) AS QVC5002 ,
CAST(NULL AS VARCHAR(1000)) AS QVC1000 ,
CAST(NULL AS VARCHAR(1000)) AS QWC1000 ,
CAST(NULL AS INTEGER) AS QQINT01 ,
CAST(NULL AS INTEGER) AS QQINT02 ,
CAST(NULL AS INTEGER) AS QQINT03 ,
CAST(NULL AS INTEGER) AS QQINT04 ,
CAST(NULL AS SMALLINT) AS QQSMINT1 ,
CAST(NULL AS SMALLINT) AS QQSMINT2 ,
CAST(NULL AS SMALLINT) AS QQSMINT3 ,
CAST(NULL AS SMALLINT) AS QQSMINT4 ,
CAST(NULL AS SMALLINT) AS QQSMINT5 ,
CAST(NULL AS SMALLINT) AS QQSMINT6 ,
QQ1000L AS "Statement Text",
CAST(NULL AS CHAR(1)) AS QFC11 ,
CAST(NULL AS CHAR(1)) AS QFC12 ,
CAST(NULL AS CHAR(1)) AS QFC13 ,
CAST(NULL AS CLOB(2147483647)) AS QQCLOB2 ,
CAST(NULL AS CHAR(1)) AS QFC14 ,
CAST(NULL AS CHAR(1)) AS QFC15 ,
CAST(NULL AS CHAR(1)) AS QFC16 ,
CAST(NULL AS CLOB(2147483647)) AS QQCLOB3 ,
CAST(NULL AS CHAR(1)) AS QFC17 ,
CAST(NULL AS CHAR(1)) AS QFC18 ,
CAST(NULL AS CHAR(1)) AS QFC19 ,
CAST(NULL AS DBCLOB(1073741823)) AS QQDBCLOB1 ,
CAST(NULL AS CHAR(1)) AS QFC1A ,
CAST(NULL AS CHAR(1)) AS QFC1B ,
CAST(NULL AS CHAR(1)) AS QFC1C ,
CAST(NULL AS NCLOB(1073741823)) AS QQDBCLOB2 ,
CAST(NULL AS CHAR(1)) AS QFC1D ,
CAST(NULL AS CHAR(1)) AS QFC1E ,
CAST(NULL AS CHAR(1)) AS QFC1F ,
CAST(NULL AS BLOB(2147483647)) AS QQBLOB1 ,
CAST(NULL AS CHAR(1)) AS QXC11 ,
CAST(NULL AS CHAR(1)) AS QXC12 ,
CAST(NULL AS CHAR(1)) AS QXC13 ,
CAST(NULL AS CHAR(1)) AS QXC14 ,
CAST(NULL AS CHAR(1)) AS QXC15 ,
CAST(NULL AS CHAR(1)) AS QXC16 ,
CAST(NULL AS CHAR(1)) AS QXC17 ,
CAST(NULL AS CHAR(1)) AS QXC18 ,
CAST(NULL AS CHAR(1)) AS QXC19 ,
CAST(NULL AS CHAR(1)) AS QXC1A ,
CAST(NULL AS CHAR(1)) AS QXC1B ,
CAST(NULL AS CHAR(1)) AS QXC1C ,
CAST(NULL AS CHAR(1)) AS QXC1D ,
CAST(NULL AS CHAR(1)) AS QXC1E ,
CAST(NULL AS CHAR(2)) AS QXC21 ,
CAST(NULL AS CHAR(2)) AS QXC22 ,
CAST(NULL AS CHAR(2)) AS QXC23 ,
CAST(NULL AS CHAR(2)) AS QXC24 ,
CAST(NULL AS CHAR(2)) AS QXC25 ,
CAST(NULL AS CHAR(2)) AS QXC26 ,
CAST(NULL AS CHAR(2)) AS QXC27 ,
CAST(NULL AS CHAR(2)) AS QXC28 ,
CAST(NULL AS CHAR(2)) AS QXC29 ,
CAST(NULL AS CHAR(4)) AS QXC41 ,
CAST(NULL AS CHAR(4)) AS QXC42 ,
CAST(NULL AS CHAR (4) FOR BIT DATA) AS QXC43 ,
CAST(NULL AS CHAR(4)) AS QXC44 ,
CAST(NULL AS INTEGER) AS QQINT05 ,
CAST(NULL AS INTEGER) AS QQINT06 ,
CAST(NULL AS INTEGER) AS QQINT07 ,
CAST(NULL AS INTEGER) AS QQINT08 ,
CAST(NULL AS INTEGER) AS QQINT09 ,
CAST(NULL AS INTEGER) AS QQINT0A ,
CAST(NULL AS INTEGER) AS QQINT0B ,
CAST(NULL AS INTEGER) AS QQINT0C ,
CAST(NULL AS INTEGER) AS QQINT0D ,
CAST(NULL AS INTEGER) AS QQINT0E ,
CAST(NULL AS INTEGER) AS QQINT0F ,
CAST(NULL AS SMALLINT) AS QQSMINT7 ,
CAST(NULL AS SMALLINT) AS QQSMINT8 ,
CAST(NULL AS SMALLINT) AS QQSMINT9 ,
CAST(NULL AS SMALLINT) AS QQSMINTA ,
CAST(NULL AS SMALLINT) AS QQSMINTB ,
CAST(NULL AS SMALLINT) AS QQSMINTC ,
CAST(NULL AS SMALLINT) AS QQSMINTD ,
CAST(NULL AS SMALLINT) AS QQSMINTE ,
CAST(NULL AS SMALLINT) AS QQSMINTF
FROM mylib/sub_dbmon
RCDFMT QQQDBMN
The final step of this solution involves directing the DB2 database monitor to write the monitor data to the SQL view defined on the previous step. Normally, the STRDBMON command is passed the name of a table on the OUTFILE parameter to use as the monitor output table. By specifying the SQL view name (mylib/mon_view) on the OUTFILE parameter, the data associated with the input-only columns is ignored and not copied to the view's underlying table (i.e., mylib/sub_dbmon) each time that the DB2 database writes a new row of data. Here's the STRDBMON command needed to complete the steps of our example:
STRDBMON OUTFILE(mylib/mon_view)
With all the steps now completed, the database monitor collections using this view will have a drastically smaller disk footprint (writing and storing only 14 of the possible 276 columns). This multi-step process is summarized visually in Figure 1.
Figure 1: Follow these steps to achieve a smaller disk footprint.
Hopefully, you now understand how to use both of these options to reduce the disk-related overhead that can be caused by the DB2 database monitor. For more information on the Database Monitor tool and analysis, please reference the IBM Redbook OnDemand SQL Performance Analysis Simplified on DB2 for i5/OS in V5R4.
LATEST COMMENTS
MC Press Online