Wednesday, January 7, 2009

BIND PARAMETERS

Explanation for Bind parameters:


DSN SYSTEM (DSN)

BIND PLAN(CBI018P) -

MEMBER(CBI018P, CBISOFM) -

ACQUIRE(USE) - --> Acquires table space locks only when the application program bound to the plan first uses them.

RELEASE(COMMIT)- --> Releases the table locks once commit is issued.

OWNER(OWNER) -

QUALIFIER(NAME) --> Used to qualify Un-qualified objects(without any schema name) in the query.

ACTION(REPLACE)- --> It replaces existing PLAN with a new PLAN with same name. If you change the SQL statements or recompile a program, you should use BIND PLAN with the option ACTION(REPLACE).

RETAIN - --> Preserves EXECUTE privileges when you replace the plan using ACTION(REPLACE).

VALIDATE(BIND)- --> DB2 verifies the authorization on the objects involved at bind time

ISOLATION(CS) - --> DB2 uses Cursor Stability phenomenon for locking purposes.

DYNAMICRULES(BIND)- -->DB2 checks necessary authorization at bind time to execute dynamic SQL statements .

DBPROTOCOL(PRIVATE) -->DB2 to use DB2 private protocol access for accessing remote data that is specified with three-part names.

END

Sunday, January 4, 2009

DB2 Command - DISPLAY GROUP



The DISPLAY GROUP command can be used to check information about the DB2 subsystem. The above screenshot conveys the following information
DB2 subsystem name --> DSNS,
Version --> V8.1,
Subsystem is active or not,
System name is EGGQ,
and the mode in which it is .
MODE(C) --> compatibility mode,
MODE(E) --> Enable New function mode,
MODE(N) --> New function mode.

Friday, January 2, 2009

DB2 Command - DISPLAY BUFFERPOOL











The DISPLAY BUFFERPOOL command can be issued to display the current status and allocation information for each buffer pool.

The above screenshot conveys that the bufferpool BP0 has been assigned 16,000 pages, all of which have been allocated. No. of pages which are IN-USE/UPDATED(pages which are being updated or already updated which are not externalized ie. written into disk) is 537.Sequential access(consecutive data pages are fetched from the disk and stored in BP) is 80% and hence Random access(data pages are fetched randomly ) would be 20%.Information on write thresholds like Deferred write thresholds(DWTH) which is 50% and Vertical deferred write threshold(VDWTH) which is 10% can be checked.

For additional information-buffer-pool details, you can specify the DETAIL parameter. Using DETAIL(INTERVAL) produces buffer pool usage information since the last execution of DISPLAY BUFFERPOOL. To report on buffer pool usage since the pool was activated, specify DETAIL(*). In each case, DB2 will return detailed information on buffer-pool usage such as the number of GETPAGEs, prefetch usage, and synchronous reads. The detailed data returned after executing this command can be used for rudimentary buffer pool tuning. For example, you can monitor the read efficiency of each buffer pool using the following formula:

(Total GETPAGEs) / [ (SEQUENTIAL PREFETCH) +
(DYNAMIC PREFETCH) +

(SYNCHRONOUS READ)]

The higher the number, the better. Additionally, if buffer pool I/O is consistently high, you might consider adding pages to the buffer pool to handle more data.

Finally, you can gather even more information about your buffer pools using the LIST and LSTATS parameters. The LIST parameter lists the open tablespaces and indexes within the specified buffer pools; the LSTATS parameter lists statistics for the tablespaces and indexes reported by LIST. Statistical information is reset each time DISPLAY with LSTATS is issued, so the statistics are as of the last time LSTATS was issued.



Tuesday, December 30, 2008

DB2 Utilities- Unload Image Copy Dataset.

Sample Job:

//UTIL EXEC DSNUPROC,SYSTEM=DSNS,UID='TEMP',UTPROC=''


//**********************************************

//* UNLOADING IMAGE COPY DATASET

//**********************************************

//DSNUPROC.SYSREC DD DSN=USERID.SRI.SYSREC,

// DISP=(MOD,CATLG),

// SPACE=(16384,(20,20),,,ROUND),

// UNIT=SYSALLDA

//DSNUPROC.SYSPUNCH DD DSN=USERID.SRI.SYSPUNCH,

// DISP=(MOD,CATLG),

// SPACE=(16384,(20,20),,,ROUND),

// UNIT=SYSALLDA

//DSNUPROC.SYSIN DD *

UNLOAD TABLESPACE DBNAME.TSNAME FROMCOPY USERID.SRI.DATA;

If the table was dropped, its not possible to Unload data from the Image copies. You will receive the following error message.

DSNU000I DSNUGUTC - OUTPUT START FOR UTILITY, UTILID = TEMP

DSNU1044I DSNUGTIS - PROCESSING SYSIN AS EBCDIC

DSNU050I DSNUGUTC - UNLOAD TABLESPACE DBNAME.ZSRIDHAR

DSNU260I -DSNS DSNUULIA-TABLESPACE DBNAME.ZSRIDHAR IS EMPTY

DSNU010I DSNUGBAC - UTILITY EXECUTION COMPLETE, HIGHEST RETURN CODE=4

Recovering an accidentally dropped table

Tables in a partitioned table space cannot be dropped without dropping the table space.

To perform this procedure, you need a full image copy or a DSN1COPY file that contains the data from the dropped table.

For segmented or universal table spaces, the image copy or DSN1COPY file must contain the table when it was active (that is, created). Because of the way space is reused for segmented table spaces, this procedure cannot be used if the table was not active when the image copy or DSN1COPY was made. For nonsegmented table spaces, the image copy or DSN1COPY file can contain the table when it was active or not active.

To recover a dropped table:

  1. If you know the DBID, the PSID, the original OBID of the dropped table, and the OBIDs of all other tables in the table space, go to step 2.

If you do not know all of the preceding items, use the following steps to find them. For later use with DSN1COPY, record the DBID, the PSID, and the OBIDs of all the tables in the table space, not just the dropped table.

    1. For the data set that contains the dropped table, run DSN1PRNT with the FORMAT and NODATA options. Record the HPGOBID field in the header page and the PGSOBD field from the data records in the data pages.

For the auxiliary table of a LOB table space, record the HPGROID field in the header page instead of the PGSOBD field in the data pages.

      • Field HPGOBID is 4 bytes long and contains the DBID in the first 2 bytes and the PSID in the last 2 bytes.
      • Field HPGROID (for LOB table spaces) contains the OBID of the table. A LOB table space can contain only one table.
      • Field PGSOBD (for non-LOB table spaces) is 2 bytes long and contains the OBID of the table. If your table space contains more than one table, check for all OBIDs. By searching for all different PGSOBD fields. You need to specify all OBIDs from the data set as input for the DSN1COPY utility.
    1. Convert the hex values in the identifier fields to decimal so that they can be used as input for the DSN1COPY utility.
  1. Begin general-use programming information.Use the SQL CREATE statement to re-create the table and any indexes on the table.End general-use programming information.
  2. To allow DSN1COPY to access the DB2 data set, stop the table space using the following command:
-STOP DATABASE(database-name) SPACENAM(tablespace-name)

Stopping the table space is necessary to ensure that all changes are written out and that no data updates occur during this procedure.

  1. Begin program-specific programming information.Find the OBID for the table that you created in step 2 by querying the SYSIBM.SYSTABLES catalog table.

The following statement returns the object ID (OBID) for the table:

SELECT NAME, OBID FROM SYSIBM.SYSTABLES
  WHERE NAME='table_name'
    AND CREATOR='creator_name';

This value is returned in decimal format, which is the format that you need for DSN1COPY. End program-specific programming information.

  1. Run DSN1COPY with the OBIDXLAT and RESET options to perform the OBID translation and to copy data from the dropped table into the original data set. You must specify a previous full image copy data set, inline copy data set, or DSN1COPY file as the input data set SYSUT1 in the control statement. Specify each of the input records in the following order in the SYSXLAT file to perform OBID translations:
    1. The DBID that you recorded in step 1 as both the translation source and the translation target
    2. The PSID that you recorded in step 1 as both the translation source and the translation target
    3. The original OBID that you recorded in step 1 for the dropped table as the translation source and the OBID that you recorded in step 4 as the translation target
    4. OBIDs of all other tables in the table space that you recorded in step 2 as both the translation sources and translation targets

Be sure that you have named the VSAM data sets correctly by checking messages DSN1998I and DSN1997I after DSN1COPY completes.

  1. Use DSN1COPY with the OBIDXLAT and RESET options to apply any incremental image copies. You must apply these incremental copies in sequence, and specify the same SYSXLAT records that step 5 specifies.

Important: After you complete this step, you have essentially recovered the table space to the point in time of the last image copy. If you want to use log records to perform forward recovery on the table space, you must use the IBM® DB2 Log Analysis Tool for z/OS at this point in the recovery procedure.

  1. Start the table space for normal use by using the following command:
-START DATABASE(database-name) SPACENAM(tablespace-name)
  1. Rebuild all indexes on the table space.
  2. Execute SELECT statements on the previously dropped table to verify that you can access the table. Include all LOB columns in these queries.
  3. Make a full image copy of the table space.
  4. Re-create the objects that are dependent on the recovered table.

Start of changeWhen a table is dropped, objects that are dependent on that table (synonyms, views, indexes, referential constraints, and so on) are dropped. (Aliases are not dropped.) Privileges that are granted for that table are also dropped. Catalog reports or a copy of the catalog taken prior to the DROP TABLE can make this task easier. End of change



Sample JCL:

//H136830$ JOB MSGCLASS=X,MSGLEVEL=(1,1),CLASS=A,

// REGION=0M,NOTIFY=&SYSUID

//EXECUTE EXEC PGM=DSN1COPY,PARM='OBIDXLAT,RESET,INLCOPY'

//*EXECUTE EXEC PGM=DSN1COPY,PARM='OBIDXLAT,RESET'

//STEPLIB DD DSN=DSN810.SDSNLOAD,DISP=SHR

//SYSPRINT DD SYSOUT=A

//SYSUT1 DD DSN=full image copy dataset,DISP=SHR

//SYSUT2 DD DSN=tablespace VSAM file,DISP=SHR

//SYSXLAT DD *

273,273

42,42

43,43

44,44

60,61 (60-> OBID of source and 61-> OBID of target)

/*

//

End of change

Monday, December 29, 2008

Hinting Optimizer to choose the access path of your choice

Let us analyse the following SQL:

EXPLAIN ALL SET QUERYNO=999 FOR
SELECT TACCONT.AC_NA , TACCONT.AC_TYP_CD
FROM TACCONT
WHERE TACCONT.AC_NR = '123456' AND
TACCONT.CNY_CD = 'US' and
TACCONT.AC_TYP_CD = 'A';

Suppose that DB2 would pick up index IACCONT1, which is an
index based on AC_NR.
In the event of DB2 picking up the normal index, the PLAN_TABLE
entry for the above query would appear as follows:

Query # MTH TNAME TABNO ACCESS MATCH ACCESS INDEX
TYPE COLS NAME ONLY
999 Ø TACCONT 1 I Ø1 IACCONT1 Y

But, based on our knowledge of the data, we want DB2 to pick up
IACCONT2, a secondary index based on CNY_CD and AC_TYP_CD.
In earlier versions of DB2 we could not influence the access path, but
illustrated below is a feature provided by DB2 Version 6 by which we
can give hints to the DB2 optimizer to pick up IACCONT2.
Some new columns to the PLAN_TABLE have been added in DB2
Version 6 to facilitate this feature of DB2. They are OPTHINT and
HINT_USED.

Now, let’s update the OPTHINT field to name our new access path.
Let’s call that new plan for accessing the secondary index PICKSECX.
We need to update the PLAN_TABLE as follows:

UPDATE PLAN_TABLE
SET OPTHINT = 'PICKSECX'
WHERE OPTHINT = '' AND QUERYNO = 999;

Now let’s update the PLAN_TABLE to indicate the access path for
our new plan,PICKSECX. In this case, you will update the
ACCESSNAME column of PLAN_TABLE, with the following SQL
statement:

UPDATE PLAN_TABLE
SET ACCESSNAME = 'IACCONT2'
WHERE OPTHINT = 'PICKSECX' AND QUERYNO = 999;

When updating the PLAN_TABLE for the second time, do make sure
you are updating the right row, by predicating the OPTHINT column
by the plan – which picks the secondary index.
After updating the PLAN_TABLE, the row of interest to us would
look like:

Query # MTH TNAME TABNO ACCESS MATCH ACCESS INDEX OPT_HINT HINT_USED
TYPE COLS NAME ONLY
999 Ø TACCONT 1 I Ø1 IACCONT2 Y PICKSECX

Now after setting the hint to the optimizer in the PLAN_TABLE, we
should bind our static SQL accordingly.
For static SQL, let’s use the following parameter in our bind package
or bind plan cards:

OPTHINT('PICKSECX').

For dynamic SQL, issue a new special DB2 register statement as follows:
SET CURRENT QUERY OPTIMIZATION HINT = 'PICKSECX' WHERE QUERYNO=999;
And then execute the same SQL as in the first example above as
follows:

SELECT TACCONT.AC_NA , TACCONT.AC_TYP_CD
FROM TACCONT
WHERE TACCONT.AC_NR = '123456' AND
TACCONT.CNY_CD = 'US' and
TACCONT.AC_TYP_CD = 'A'
QUERYNO 999;

The difference between the two SQL examples is the presence of
QUERYNO in the second example.
After execution, the PLAN_TABLE row suggests the following:

Query # MTH TNAME TABNO ACCESS MATCH ACCESS INDEX OPT_HINT HINT_USED
TYPE COLS NAME ONLY
999 Ø TACCONT 1 I Ø2 IACCONT2 Y PICKSECX

After executing the second SQL with hints to the optimizer, if we then
run an EXPLAIN, PLAN_TABLE shows that plan PICKSECX has
moved from column OPT_HINT to HINT_USED. This confirms that
DB2 has indeed picked the secondary index for the second SQL
example. MATCHCOLS for the second SQL, on picking up the
secondary index, IACCONT2, has become 02.

The BIND statement for static SQL and the PREPARE statement for
dynamic SQL indicates a SQLCODE of +394, suggesting that the hint
was successfully picked up for execution.

If IACCONT2 is a non-existent secondary index, then the BIND
statement for static SQL and the PREPARE statement for dynamic
SQL indicates a SQLCODE of +395, suggesting that the hint was
found, but execution was found to be invalid.

Sunday, December 28, 2008

Important DB2 commands


-DISPLAY UTIL(*) --> Displays any object which is placed in utility mode due to abnormal completion of any utilitity job.

-TERM UTIL(*) --> Terminates the utility and resets the utility mode.

-STA DATABASE(DBNAME) SPACENAM(TSNAME) ACCESS(RW) - ->
Starts the TS in Read/Write mode.

-STO DATABASE(DBNAME) SPACENAM(*) --> Stops all the TS in the Database.

-DIS DB(DBNAME) SPACENAM(TSNAME) LOCKS/CLAIMERS LIMIT(*) -->
Displays list of TS which are held/locked by the users
and the corresponding USERID.

-DIS GROUP --> Displays information about the DB2 subsystem (which mode the
DB2 is in, name of the subsystem,Active/Inactive,current version of the DB2 )

-DIS DB(DBNAME) SPACENAM(TSNAME) RESTRICT --> Displays TS and IX which are in utility pending status (COPY,RECOVERY,REORG pending,..etc)

-DIS DB(DBNAME) SPACENAM(TSNAME) RESTRICT LIMIT(*) --> Displays all
information without any space restriction. LIMIT(100) displays 100 rows of information.
Default is 50.