Tridex September 2016

SEGUS & SOFTWARE ENGINEERING präsentieren

TRIDEX – am Dienstag den 27. September 2016

Compliance with compliments! Viable DB2 z/OS workload tracking.

Audit and Compliance is a need that many companies want and have to fulfill.

There’s different ways and tools that promise to be able to do it, but what can they really do and what are the associated costs? This presentation introduces DB2 10/11 technology exploitation that delivers any DML, DDL, DCL being executed in a DB2 environment along with identification details. Learn how you can run Audit analytics against a long‐term repository, pinpointing who executed a query, when and from where. Analyze your entire workload to understand access patterns and abnormalities.

1-Audit needs and musts
Take a journey to GLB HIPAA PCI‐DSS Basel III Sarbanes‐Oxley CA SB1386 Federal Information Security Management Act “ed Flag”Rules (FRCA)5.
2-Solution overview and their Pros/Cons
Get an overview about the existing solutions and understand how they work.
3-The viable way – let DB2 do the magic!
Learn about DB2 enhancements in DB2 10/11 that deliver the DB2 workload being processed and understand why it’s so efficient.
4-Customer results from the banking industry
Receive some experience from a large banking company and how they successfully replaced their DB2 Audit feature based reporting by a modern SQL tracking and analytics process.

 

The Delaware Valley DB2 Users Group

SEGUS & SOFTWARE ENGINEERING präsentieren

DVDUG – am Mittwoch den 28. September 2016

Compliance with compliments! Viable DB2 z/OS workload tracking.

Audit and Compliance is a need that many companies want and have to fulfill.

There’s different ways and tools that promise to be able to do it, but what can they really do and what are the associated costs? This presentation introduces DB2 10/11 technology exploitation that delivers any DML, DDL, DCL being executed in a DB2 environment along with identification details. Learn how you can run Audit analytics against a long‐term repository, pinpointing who executed a query, when and from where. Analyze your entire workload to understand access patterns and abnormalities.

1-Audit needs and musts
Take a journey to GLB HIPAA PCI‐DSS Basel III Sarbanes‐Oxley CA SB1386 Federal Information Security Management Act “ed Flag”Rules (FRCA)5.
2-Solution overview and their Pros/Cons
Get an overview about the existing solutions and understand how they work.
3-The viable way – let DB2 do the magic!
Learn about DB2 enhancements in DB2 10/11 that deliver the DB2 workload being processed and understand why it’s so efficient.
4-Customer results from the banking industry
Receive some experience from a large banking company and how they successfully replaced their DB2 Audit feature based reporting by a modern SQL tracking and analytics process.

 

Can you guess how interesting the DSN_PREDICAT_TABLE really is?

DB2 z/OS literal replacement:

Do you know the queries to list the Dynamic SQL which have literals or Parameter markers?

Here is a very handy method to (fairly) quickly see if you have a literal problem that is killing the DSC or causing access path problems.

 

I was asked by a customer the other week, to help them out with a classic DB2 SQL Performance problem involving dynamic SQL. Should Literals or Parameter markers be used in dynamic SQL? Now, of course, the classic answer is: “It depends.” But this customer wanted to go a stage further and get a list of all the dynamic SQL which had literals in the text.

 

EXPLAIN to the rescue!

Naturally an EXPLAIN must be the starting point, because manually parsing the SQL text is incredibly difficult. If you have paid for the DB2 Optimizer—and the ability of EXPLAIN to output to seventeen tables—why not use it and see what you get?

Manual time

After trolling through various manuals, it quickly becomes apparent that the table of choice is the DSN_PREDICAT_TABLE, as it contains at least one row for each predicate and, after all, it is predicates that are truly interesting for the optimizer. (Naturally DSC usage also hangs on the use, or not, of literals also in the SELECT—but that is another story!)

What is in the table?

The contents are quite simple really:

SELECT  A.QUERYNO                 Identification

      , A.QBLOCKNO                Identification

      , A.APPLNAME                Identification

      , A.PROGNAME                Identification

      , A.PREDNO                  Identification

      , A.TYPE                    Type of op AND, OR, EQUAL etc

      , A.LEFT_HAND_SIDE          Column/Value/colexp etc

      , A.LEFT_HAND_PNO           Child predicate number

      , A.LHS_TABNO               Table no.

      , A.LHS_QBNO                Query Block no.

      , A.RIGHT_HAND_SIDE         As left hand

      , A.RIGHT_HAND_PNO          As left hand

      , A.RHS_TABNO               As left hand

      , A.RHS_QBNO                As left hand

      , A.FILTER_FACTOR           Estimated FF

      , A.BOOLEAN_TERM            Whole WHERE is Boolean?

      , A.SEARCHARG               DM or RDS?

      , A.JOIN                    Simple join or not?

      , A.AFTER_JOIN              Predicate after/during join?

      , A.ADDED_PRED              T Transitive clos., B Bubble,
                                  C correlation,

                                  J Join, K like, L local, P push down,

                                  R page range, S simplification

      , A.REDUNDANT_PRED          Is the predicate redundant?

      , A.DIRECT_ACCESS           ROWID Possible?

      , A.KEYFIELD                Is the predicate in indexes?

      , A.EXPLAIN_TIME            Identification

      , A.CATEGORY                IBM Internal use

      , A.CATEGORY_B              IBM Internal use

      , A.TEXT                    First 2000 bytes of text

      , A.PRED_ENCODE             IBM Internal use

      , A.PRED_CCSID              IBM Internal use

      , A.PRED_MCCSID             IBM Internal use

      , A.MARKER                  Host vars, parameter markers,
                                  special regs

      , A.PARENT_PNO              If a root predicate then zero

      , A.NEGATION                Is NOT used?

      , A.LITERALS                Literals separated by colons

      , A.CLAUSE                  HAVING, ON, WHERE or SELECT

      , A.GROUP_MEMBER            Identification

      , A.ORIGIN                  Origin of predicate. Blank, C, R or U

      , A.UNCERTAINTY             Level of uncertainty

      , A.SECTNOI                 Identification

      , A.COLLID                  Identification

      , A.VERSION                 Identification

--V11 , A.EXPANSION_REASON        Archive or Temporal table indicator

FROM BOXWELL.DSN_PREDICAT_TABLE A

 

The first four columns are used for joining to your existing EXPLAIN tables (PLAN_TABLE etc.)

Columns of interest

Now what interested me straightaway, were the columns MARKER and LITERALS. Looking in the Managing Performance documentation you see that these columns:

MARKER CHAR(1) NOT NULL WITH DEFAULT

Whether this predicate includes host variables, parameter markers, or special Registers.

LITERALS VARCHAR(128) NOT NULL

This column indicates the literal value or literal values separated by colon symbols.

 

So now it looks quite easy just do a select where LITERALS is non blank. Of course that fails miserably…

First attempt

Here’s an SQL that shows what comes out:

DSN; predicat table, query1-DB2-z-OS-literal-replacement

DSN; predicat table, query1-DB2-z-OS-literal-replacement

This looks like lots of literals, but is actually just one WHERE predicate and one ON being broken down. So I thought “Aha! The PARENT_PNO must be the problem.” Sure enough, when you add AND PARENT_PNO = 0 to the SQL it now Returns:

DSN; predicat table, query1-DB2-z-OS-literal-replacement

Now all of the ON data has vanished, so you must add an OR into the query:

Second attempt

Giving us now this Output:

DSN; predicat table, query1-DB2-z-OS-literal-replacement

The COLEXP row SQL text looks like:

SUBSTR(DIGITS("A"."CORR_TYPE"),1,10)

So we can also exclude these rows from the select.

DSN; predicat table, query1-DB2-z-OS-literal-replacement

Still duplicates?

This*still* looks like duplicates, but now pushed down to the ON clause in this context. Final fix is to make sure that the LHS_TABNO and RHS_TABNO are both equal to zero. Now we have the “literal finder” SQL:

DSN; predicat table, query1-DB2-z-OS-literal-replacement

Host with no colon?

Which gives (excluding the first columns for clarity!):

DSN; predicat table, query1-DB2-z-OS-literal-replacement

See the HV2 and then the list of HVs? Now this is not documented at all! A comma separated list of host variables… super…

All we can now do, at least in standard SQL, is split the output into two distinct blocks, one where MARKER is ‘N’ so no host variables or special registers are involved, and one where they are! It should be easy to remove the HVs and then see if the LITERALS column is empty—or not—but that is a bit more than a simple newsletter can possibly do!

And Finally

So now the final two queries:

SELECT QUERYNO , QBLOCKNO , PREDNO                 
      ,LITERALS
      ,TEXT                                        
FROM BOXWELL.DSN_PREDICAT_TABLE                    
WHERE NOT LITERALS = ''                            
  AND ((CLAUSE = 'WHERE'                           
    AND PARENT_PNO = 0)                            
    OR CLAUSE = 'ON')                              
  AND NOT RIGHT_HAND_SIDE = 'COLEXP'               
  AND LHS_TABNO = 0                                
  AND RHS_TABNO = 0                                
  AND MARKER    = 'N'                              
ORDER BY QUERYNO , QBLOCKNO , PREDNO               
;                                                  
SELECT QUERYNO , QBLOCKNO , PREDNO                 
      ,LITERALS
      ,TEXT                                        
FROM BOXWELL.DSN_PREDICAT_TABLE                    
WHERE NOT LITERALS = ''                            
  AND ((CLAUSE = 'WHERE'                           
    AND PARENT_PNO = 0)                            
    OR CLAUSE = 'ON')                              
  AND NOT RIGHT_HAND_SIDE = 'COLEXP'               
  AND LHS_TABNO = 0                                
  AND RHS_TABNO = 0                                
  AND MARKER    = 'Y'                              
ORDER BY QUERYNO , QBLOCKNO , PREDNO               
;

This gives you a very handy method to (fairly) quickly see if you have a literal problem that is killing the DSC or causing access path problems at your shop.

I hope you liked this month’s topic.

As always, any questions or comments would be most welcome!

TTFN,

Roy Boxwell

 

Once again for your cut and paste (the queries presented first of all as a screenshot):

Query 1

SELECT CLAUSE, PARENT_PNO, SUBSTR(RIGHT_HAND_SIDE , 1 , 8)
      ,LHS_TABNO, RHS_TABNO                               
      ,MARKER, LITERALS                             
FROM BOXWELL.DSN_PREDICAT_TABLE                           
WHERE NOT LITERALS = ''                  
Output1                 
-----+-------+---------+---------+---------+---------+---------+
CLAUSE PARENT_PNO        LHS_TABNO  RHS_TABNO  MARKER  LITERALS
-----+-----+---------+---------+---------+---------+-----------+
WHERE      0                    0           0  N       0,1,'W' 
WHERE      1  VALUE             2           0  N       0,1     
WHERE      1  VALUE             3           0  N       'W'     
ON         1  COLEXP            2           0  N       1,10    
ON         1  VALUE             2           0  N       'F'     
ON         1  VALUE             2           0  N       'en_US'


Output2
-----+---------+---------+---------+---------+---------+---------+------
CLAUSE     PARENT_PNO            LHS_TABNO  RHS_TABNO  MARKER  LITERALS
-----+---------+---------+---------+---------+---------+---------+------
WHERE               0                    0          0  N       0,1,'W'

Output3
-----+--------+--------+---------+---------+-----------------
CLAUSE PARENT_PNO     LHS_TABNO RHS_TABNO MARKER LITERALS
-----+-------+--------+---------+----------------------------
WHERE    0                 0            0  N     'X',' ',
                                                  220,219,1,10,'F’
ON       1  COLEXP         2            0  N      1,10
ON       1  VALUE          2            0  N     'F' 
ON       1  VALUE          2            0  N     'en_US'
WHERE    0  VALUE          3            0  N     'X'

Output4
-----+---------+---------+---------+---------+----------+----
 CLAUSE PARENT_PNO    LHS_TABNO  RHS_TABNO  MARKER LITERALS
 -----+---------+---------+---------+---------+---------+----
 WHERE   0                0              0  N      'X','
                                                   ',220,219,1,10,'F’
 ON      1  VALUE         2              0  N      'F'
 ON      1  VALUE         2              0  N      'en_US'
 WHERE   0  VALUE         3              0  N      'X'

Query 2

SELECT QUERYNO , QBLOCKNO , PREDNO                 
      ,MARKER, SUBSTR(LITERALS, 1 , 32) AS LITERALS
      ,TEXT                                        
FROM BOXWELL.DSN_PREDICAT_TABLE                    
WHERE NOT LITERALS = ''                            
  AND ((CLAUSE = 'WHERE'                           
    AND PARENT_PNO = 0)                            
    OR CLAUSE = 'ON')                              
  AND NOT RIGHT_HAND_SIDE = 'COLEXP'               
  AND LHS_TABNO = 0                                
  AND RHS_TABNO = 0                                
ORDER BY QUERYNO , QBLOCKNO , PREDNO               
;

Output5
MARKER  LITERALS                          TEXT                                    
---+---------+---------+---------+---------+---------+---------+--------
N 'X','X','T'                  (((((((((((("B"."WLX_TIMESTAMP"=(SELECT 
N 'X','X','T'                  (((((((((((("B"."WLX_TIMESTAMP"=(SELECT 
Y  HV2,'S'                     ("IQA0610"."IQATW001"."WLX_TIMESTAMP"=(E
N 'X'                          ("Z"."WLX_TIMESTAMP"="A"."WLX_TIMESTAMP"
N 'X'                          ("Z"."WLX_TIMESTAMP"="A"."WLX_TIMESTAMP"
N 'X','X','I','  '             ((((((((((("B"."WLX_TIMESTAMP"=(SELECT M
N 'X','X','I','  '             ((((((((((("B"."WLX_TIMESTAMP"=(SELECT M
N 'X'                          ("Z"."WLX_TIMESTAMP"="A"."WLX_TIMESTAMP"
N  X'                          ("Z"."WLX_TIMESTAMP"="A"."WLX_TIMESTAMP"
Y  HV1,HV2,HV3,HV4,HV5,'F',HV6 ((((("SYSIBM"."SYSCOPY"."DBNAME"=(EXPR)

2016-04 DB2 SYSCOPY – Do you know what is in it? Redux

DB2 10, DB2 11 Migration & DB2 Database maintenance

A special query to check and clear out the DB2 Catalog

 

This is a redux of my original Newsletter from February 2013 with additional data at the very end – The reason for this relaunch? Simple – I have had numerous emails about this topic, especially with regard to migrating from DB2 10 to DB2 11, and it is obviously still very important to check and to clear out *before* you start your DB2 migration. So now enjoy the redux version…

 

DB2 Database Maintenance and the DB2 Catalog

If you have written your own DB2 database maintenance programs then you almost certainly run SQL queries against the DB2 Catalog. If you are also checking for Incremental Image Copies (IIC) or Full Image Copies (FIC) then you will probably be using a mix of Real-Time Statistics tables (RTS) and the SYSIBM.SYSCOPY to figure out which type of utility to generate. Further if you are in DB2 10 (any mode! CM8, CM9, or NF) then this newsletter is for you!

 

I had a problem in one of our test centers with a cursor that I noticed was taking a long time to finish and so I went into our Analyze+ tool and extracted the EDM Pool data (this is the new data in DB2 10 NF that is synonymous with the Dynamic Statement Cache counters and statistics) and sorted by Total Elapsed Time descending to get this:

 

Analyze+ for DB2 z/OS ----- EDM Pool (6/12) -------- Stmt 1 from 316 
Command ===>                                         Scroll ===> CSR  
                                                           DB2: QA1B 
Primary cmd: END, SE(tup), Z(oom), L(ocate) 
             total elapse time                 
Line    cmd: Z(oom), A(nalyze), D(ynamic Analyze), E(dit Statement), 
             P(ackage), S(tatement Text)
                                                               
                     Total       Average         Total       Average
     StmtID   Elapsed Time  Elapsed Time      CPU Time      CPU Time
----------- HHHH:MM:SS.ttt HHH:MM:SS.ttt HHH:MM:SS.ttt HHH:MM:SS.ttt
     115967    1:28.107705     29.369235   1:12.151391     24.050464
     114910       8.367834      0.000331      6.779229      0.000268
      79642       7.998559      0.054412      6.346829      0.043176
     114907       5.760045      0.000238      4.378691      0.000181
     115974       5.031890      2.515945      2.937258      1.468629
       5439       4.037261      0.000739      2.685938      0.000492

 

Over one hour total and over 29 minutes average for our small amount of test data set alarm bells ringing – so I drilled down to the SQL:

 

Analyze+ for DB2 z/OS -- View EDM-Pool Statement LINE 00000001 COL 001 080
Command ===>                                             Scroll ===> CSR
                                                         DB2: QA1B
Primary cmd: END
Collection:RTDX0510_PTFTOOL
Package   :M2DBSC09 
Contoken  :194C89620AE53D88  PrecompileTS: 2012-10-29-15.34.40.938230
StmtID    :          115967  StmtNo      :      1223  SectNo:       2
---------------------------------------------------------------------
DECLARE
  SYSCOPY-IC-MODI-9N
CURSOR WITH HOLD FOR 
SELECT                                                                       
  T1.N1 , T1.N2 , T1.N3 , T1.N4 , T1.N5 , T1.N6 , T1.N7 , T1.N8 , T1.N9 
  , T1.N10 , T1.N11 , T1.N12 
FROM (
  SELECT       
    ICTS.DBNAME AS N1
  , ICTS.TSNAME AS N2
  , ICTS.TIMESTAMP AS N3
  , ' ' AS N4
  , ICTS.DSNUM AS N5
 , ICTS.ICTYPE AS N6
 , DAYS ( :WORK-CURRENT-DATE ) - DAYS ( ICTS.TIMESTAMP ) AS N7
 , ICTS.OTYPE AS N8
 , ICTS.DSNAME AS N9
 , ICTS.ICUNIT AS N10
 , ICTS.INSTANCE AS N11
 , ICTS.STYPE AS N12                                                                    
  FROM SYSIBM.SYSCOPY ICTS                                                     
  WHERE ICTS.ICBACKUP IN ( '  ' , 'LB' , 'FC' )                            
  AND  ICTS.OTYPE = 'T' 
  UNION                    
   SELECT                           
    ICIX.DBNAME AS N1
  , CAST ( TABLES.TSNAME AS CHAR ( 8 ) CCSID EBCDIC ) AS N2
  , ICIX.TIMESTAMP AS N3
  , ICIX.TSNAME AS N4
  , ICIX.DSNUM AS N5
  , ICIX.ICTYPE AS N6
  , DAYS ( :WORK-CURRENT-DATE ) - DAYS ( ICIX.TIMESTAMP ) AS N7
  , ICIX.OTYPE AS N8
  , ICIX.DSNAME AS N9
  , ICIXS.ICUNIT AS N10
  , ICIX.INSTANCE AS N11
  , ICIX.STYPE AS N12
   FROM SYSIBM.SYSCOPY ICIX
      , SYSIBM.SYSINDEXES INDEXES
      , SYSIBM.SYSTABLES TABLES           
   WHERE ICIX.ICBACKUP IN ( '  ' , 'LB' , 'FC' )                          
   AND  ICIX.OTYPE = 'I' 
   AND VARCHAR ( ICIX.DBNAME , 24 ) = INDEXES.DBNAME       
   AND VARCHAR ( ICIX.TSNAME , 24 ) = INDEXES.INDEXSPACE 
   AND INDEXES.TBNAME = TABLES.NAME
   AND INDEXES.TBCREATOR = TABLES.CREATOR           
   AND  TABLES.TYPE IN ( 'H' , 'M' , 'P' , 'T' , 'X' ) )    
 AS T1                                                   
 ORDER BY CAST (T1.N1 AS CHAR ( 8 ) CCSID EBCDIC )
        , CAST (T1.N2 AS CHAR ( 8 ) CCSID EBCDIC )
        , N3 DESC 
 FOR FETCH ONLY       
 WITH UR                                                             



 HOSTVARIABLE NAME             NULLABLE  TYPE           LENGTH  SCALE
 ---------------------------  --------  --------------  -----  -----
 WORK-CURRENT-DATE             NO        CHAR              26       
 WORK-CURRENT-DATE             NO        CHAR              26       
******************************** Bottom of Data **********************

 

Ok, ok this SQL is not going to win a beauty contest any day soon but it used to run just fine…so now I explained it:

Analyze+ for DB2 z/OS -- Explain Data (1/6) --------- Entry 1 from 7  
Command ===>                                         Scroll ===> CSR   
EXPLAIN: DYNAMIC     MODE: CATALOG                         DB2: QA1B  
Primary cmd: END, T(Explain Text), V(iolations), R(unstats), 
             P(redicates), S(tatement Text), C(atalog Data),
             M(ode Catalog/History),Z(oom), PR(int Reports), 
             SAVExxx, SHOWxxx
             
Line    cmd: Z(oom), C(osts), I(ndexes of table), S(hort catalog),
             T(able), V(irtual indexes of table), 
             X(IndeX)                               
Collection : RTDX0510_PTFTOOL   Package : M2DBSC09   Stmt :     1223
Version    : - NONE -         
Milliseconds:  77519  Service Units: 220222  Cost Category: B
                                                                                
  QBNO QBTYPE CREATOR  TABLE NAME       MTCH IX METH PRNT TABL PRE  MXO 
  PLNO TABNO  XCREATOR INDEX NAME ACTYP COLS ON OD   QBLK TYPE FTCH PSQ 
  ---- ------ -------- ---------- ----- ---- -- ---- ---- ---- ---- --- 
     1 SELECT R510PTFT T1         R        0 N     0    0 W    S      0 
     1 5 
     1 SELECT                              0 N     3    0 -           0 
     2 0  
     2 UNION                               0       3    1 -           0 
     1 0 
     3 NCOSUB SYSIBM   SYSCOPY    R        0 N     0    2 T    S      0 
     1 1         
     4 NCOSUB SYSIBM   SYSCOPY    R        0 N     0    2 T    S      0 
     1 2        
     4 NCOSUB SYSIBM   SYSINDEXES I        2 N     1    2 T           0 
     2 3      SYSIBM   DSNDXX02       
     4 NCOSUB SYSIBM   SYSTABLES  I        2 N     1    2 T           0 
     3 4      SYSIBM   DSNDTX01      
  ---- ------ -------- ---------- ----- ---- -- ---- ---- ---- ---- ---

 

This is *after* I had REORGed the SYSCOPY, SYSTSIXS and SYSTSTAB and then run the RUNSTATS on the SYSTSIXS and SYSTSTAB as you cannot do inline RUNSTATS on those two of course!

 

Two tablespace scans against the SYSCOPY is not brilliant of course but in this system we only have 4,000 table spaces and 2,500 indexes… so then I used the Catalog primary command to have another look at the catalog data:

TS   : DSNDB06 .SYSCOPY 
Stats: 2013-02-04-10.49.32.600316 
  Partitions:  0 , Tables: 1 , NACTIVEF: 18.272 pages 
  Type      :  Neither a LOB nor a MEMBER CLUSTER.
  RTS data TOTALROWS : 347.087 , Pages: 18.268
              
Table: SYSIBM.SYSCOPY 
Stats: 2013-02-04-10.49.32.600316
  No. of rows (CARDF): 347.082 , Pages: 18.268 
  Index: SYSIBM.DSNUCH01 
  Stats: 2013-02-04-10.49.32.600316     Type: Type-2 index
    Levels: 3 , Leaf pages: 3.945 
    FIRSTKEYCARDF: 101 , FULLKEYCARDF: 347.082 
    RTS data Levels: 3 , Leaf pages: 3.945 , TOTALENTRIES: 347.087 
    CLUSTERING: Y , CLUSTERED: Y , CLUSTERRATIO = 100,00% 
    DATAREPEATFACTORF: 18.268 
    Indexcolumn  ! Format        ! Dist. Values ! A/D ! NL ! Stats  
    -------------+---------------+--------------+-----+----+-------
    DBNAME       ! CHAR(8)       !          101 ! ASC ! N  ! OK  
    TSNAME       ! CHAR(8)       !          712 ! ASC ! N  ! OK  
    START_RBA    ! CHAR(6)       !       72.398 ! DSC ! N  ! OK  
    TIMESTAMP    ! TIMESTAMP(6)  !      347.082 ! DSC ! N  ! OK  
                                                                               
  Index: SYSIBM.DSNUCX01                                                 
  Stats: 2013-02-04-10.49.32.600316   Type: Type-2 index 
    Levels: 3 , Leaf pages: 509
    FIRSTKEYCARDF: 1.820 , FULLKEYCARDF: 1.820
    RTS data Levels: 3 , Leaf pages: 509 , TOTALENTRIES: 347.087 
    CLUSTERING: N , CLUSTERED: Y , CLUSTERRATIO = 100,00%
    DATAREPEATFACTORF: 18.275 
    Indexcolumn  ! Format        ! Dist. Values ! A/D ! NL ! Stats 
    -------------+---------- ----+--------------+-----+----+-------
    DSNAME       ! CHAR(44)      !        1.820 ! ASC ! N  ! OK    
                                                

Here I had a heart attack! 347,087 rows?!?!?!?!?!? How in the wide wide world of sports did that happen? Time to drill down into the contents of SYSCOPY with this little query:

SELECT ICTYPE , STYPE,  COUNT(*) 
FROM SYSIBM.SYSCOPY  
GROUP BY ICTYPE , STYPE            
;

Which returned these rather surprising results:

---------+---------+---------+
ICTYPE  STYPE                          
---------+---------+---------+
A       A                4             
B                       46             
C       L             1669             
C       O                4             
F                      100             
F       W               16             
I                        4             
L       M           344723             
M       R               18             
R                      151             
S                       62             
W                       18             
W       S                1             
Y                        2             
Z                      269             
DSNE610I NUMBER OF ROWS DISPLAYED IS 15

The L and M combination appears 344,723 times!!!

Grab your handy DB2 10 SQL reference and page on down to DB2 Catalog tables, SYSIBM.SYSCOPY and you will see:

ICTYPE CHAR(1) NOT NULL

Type of Operation:

A ALTER
B REBUILD INDEX
C CREATE
D CHECK DATA LOG(NO) (no log records for the range are available for RECOVER utility)
E RECOVER (to current point)
F COPY FULL YES
I COPY FULL NO
L SQL (type of operation)
M MODIFY RECOVERY utility
P RECOVER TOCOPY or RECOVER TORBA (partial recovery point)
Q QUIESCE
R LOAD REPLACE LOG(YES)
S LOAD REPLACE LOG(NO)
T TERM UTILITY command
V REPAIR VERSIONS utility
W REORG LOG(NO)
X REORG LOG(YES)
Y LOAD LOG(NO)
Z LOAD LOG(YES)

Now in my version the L entry has a ‘|’ by it to signify it is new. Scroll on down further to STYPE to read

STYPE CHAR(1) NOT NULL

Sub-type of operation:

When ICTYPE=L, the value is:

M Mass DELETE, TRUNCATE TABLE, DROP TABLE, or ALTER TABLE ROTATE PARTITION.
The LOWDSNUM column contains the table OBID of the affected table.

So, in other words, every time a program does a MASS DELETE it inserts a row into SYSCOPY. So then I ran another query to see when this all began and, hopefully, ended:

SELECT MAX(ICDATE), MIN(ICDATE) 
FROM SYSIBM.SYSCOPY                   
WHERE ICTYPE = 'L'                    
;                                     
---------+---------+---------+--------
                                      
---------+---------+---------+--------
121107  120828                        
DSNE610I NUMBER OF ROWS DISPLAYED IS 1

 

So we started getting records on the 28th August 2012 and the last one was the 7th November 2012 so in just about ten weeks even we managed 344,723 Mass Deletes!

So now, with my Sherlock Holmes deer stalker hat on, the question was “Why did it stop in November?” Happily we have a history here of APARs and that’s when this PMR bubbled to the Surface:

PM52724: MASS DELETES ENDS UP WITH LOCK ESCALATION ON SYSCOPY IN V10. BECAUSE PM30991 INTALLED CODE INSERTING L 12/01/04 PTF PECHANGE

 

I will let you go and read the text but suffice it to say IBM realized what a disaster this “logging” of Mass Deletes was and HIPERed a quick fix to stop it! Plus you can see the APAR that “brought in the dead mouse” PM30991.

PM30991 UK66327 Closed 2011-03-30

PM52724 UK80113 Closed 2012-07-03

So if you installed the PM30991 and not the PM52724 you probably have some cleaning up to do…

By the way I also rewrote the Ugly Duckling SQL:

  SELECT  T1.N1      
         ,T1.N2         
         ,T1.N3              
         ,T1.N4         
         ,T1.N5        
         ,T1.N6       
         ,T1.N7 
         ,T1.N8      
         ,T1.N9     
         ,T1.N10         
         ,T1.N11        
         ,T1.N12       
    FROM (                                   
   SELECT ICTS.DBNAME    AS N1   
         ,ICTS.TSNAME    AS N2      
         ,ICTS.TIMESTAMP AS N3      
         ,' '            AS N4     
         ,ICTS.DSNUM     AS N5     
         ,ICTS.ICTYPE    AS N6     
         ,DAYS ( :WORK-CURRENT-DATE ) - DAYS ( ICTS.TIMESTAMP ) AS N7
         ,ICTS.OTYPE     AS N8             
         ,ICTS.DSNAME    AS N9               
         ,ICTS.ICUNIT    AS N10              
         ,ICTS.INSTANCE  AS N11              
         ,ICTS.STYPE     AS N12              
     FROM SYSIBM.SYSCOPY ICTS                
    WHERE ICTS.ICBACKUP IN ('  ','LB','FC')  
      AND ICTS.OTYPE    = 'T'
UNION ALL    
   SELECT ICIX.DBNAME     AS N1    
         ,CAST(TABLES.TSNAME                 
          AS CHAR(8) CCSID EBCDIC) AS N2  
         ,ICIX.TIMESTAMP  AS N3      
         ,ICIX.TSNAME     AS N4
         ,ICIX.DSNUM      AS N5              
         ,ICIX.ICTYPE     AS N6              
         ,DAYS ( :WORK-CURRENT-DATE ) - DAYS ( ICIX.TIMESTAMP ) AS N7
         ,ICIX.OTYPE      AS N8              
         ,ICIX.DSNAME    AS N9               
         ,ICIX.ICUNIT    AS N10              
         ,ICIX.INSTANCE  AS N11              
        ,ICIX.STYPE     AS N12                
    FROM SYSIBM.SYSCOPY ICIX                  
        ,SYSIBM.SYSINDEXES INDEXES            
        ,SYSIBM.SYSTABLES TABLES              
   WHERE ICIX.ICBACKUP IN ('  ','LB','FC')    
     AND ICIX.OTYPE        = 'I'              
     AND ICIX.DBNAME      = INDEXES.DBNAME    
     AND ICIX.TSNAME      = INDEXES.INDEXSPACE
     AND INDEXES.TBNAME    = TABLES.NAME      
     AND INDEXES.TBCREATOR = TABLES.CREATOR   
 ) AS T1                                      
ORDER BY CAST(T1.N1 AS CHAR(8) CCSID EBCDIC)  
        ,CAST(T1.N2 AS CHAR(8) CCSID EBCDIC)  
        ,        N3 DESC                      
  FOR FETCH ONLY                              
  WITH UR                                     
  ;

 

To now perform like this:

Milliseconds:  55911  Service Units:   158836  Cost Category: A 
                                                                                 
QBNO QBTYPE CREATOR  TABLE NAME       MTCH IX METH PRNT TABL PRE  MXO 
PLNO TABNO  XCREATOR INDEX NAME ACTYP COLS ON OD   QBLK TYPE FTCH PSQ 
---- ------ -------- ---------- ----- ---- -- ---- ---- ---- ---- ---
   1 NCOSUB SYSIBM   SYSINDEXES I        0 N    0     2 T    S      0 
   1 3      SYSIBM   DSNDXX07   
   1 NCOSUB SYSIBM   SYSTABLES  I        2 N    1     2 T           0 
   2 4      SYSIBM   DSNDTX01
   1 NCOSUB SYSIBM   SYSCOPY    I        2 N    1     2 T    S      0 
   3 2      SYSIBM   DSNUCH01    
   2 UNIONA                              0 N    3     0 -           0 
   1 0   
   5 NCOSUB SYSIBM   SYSCOPY    R        0 N    0     2 T    S      0 
   1 1         
   ------ -------- ----------  ------ ---- -- ---- ---- ---- ----- ---

 

I am sure once I have deleted all the SYSCOPY rows (Note that we do not need to RECOVER on our test machine so I have the luxury of being able to delete the data – You, of course, cannot!) that it will return to being a nice little SQL!

 

After a large DELETE run which left only 2,365 rows followed by a REORG with inline RUNSTATS the original SQL now looks like:

 

Milliseconds:       672  Service Units:       1909  Cost Category: B  
                                                                               
QBNO QBTYPE CREATOR  TABLE NAME       MTCH IX METH PRNT TABL PRE  MXO
PLNO TABNO  XCREATOR INDEX NAME ACTYP COLS ON OD   QBLK TYPE FTCH PSQ
---- ------ -------- ---------- ----- ----- ---- -- ---- ---- ---- --
   1 SELECT R510PTFT T1         R        0 N     0    0 W    S      0
   1 5   
   1 SELECT                              0 N     3    0 -           0
   2 0   
   2 UNION                               0       3    1 -           0
   1 0 
   3 NCOSUB SYSIBM   SYSCOPY    R        0 N     0    2 T    S      0
   1 1  
   4 NCOSUB SYSIBM   SYSCOPY    R        0 N     0    2 T    S      0
   1 2  
   4 NCOSUB SYSIBM   SYSINDEXES I        2 N     1    2 T           0
   2 3      SYSIBM   DSNDXX02                 
   4 NCOSUB SYSIBM   SYSTABLES  I        2 N     1    2 T           0
   3 4      SYSIBM   DSNDTX01      
  ---- ------ -------- ------------------ ----- ---- -- ---- ---- ----

And my version:

Milliseconds:      631  Service Units:     1792  Cost Category: A          
                                                                                
QBNO QBTYPE CREATOR  TABLE NAME       MTCH IX METH PRNT TABL PRE  MXO
PLNO TABNO  XCREATOR INDEX NAME ACTYP COLS ON OD   QBLK TYPE FTCH PSQ
---- ------ -------- ---------- ----- ---- ---- -- ---- ---- ---- ---- 
   1 NCOSUB SYSIBM   SYSCOPY    R        0 N     0    2 T    S      0
   1 2       
   1 NCOSUB SYSIBM   SYSINDEXES I        2 N     1    2 T           0
   2 3      SYSIBM   DSNDXX02  
   1 NCOSUB SYSIBM   SYSTABLES  I        2 N     1    2 T           0
   3 4      SYSIBM   DSNDTX01 
   2 UNIONA                              0 N     3    0 -           0
   1 0             
   5 NCOSUB SYSIBM   SYSCOPY    R        0 N     0    2 T    S      0
   1 1   
   ---- ------ -------- ------------------ ----- ---- -- ---- ---- ----

Doesn’t look quite so impressive now…sniff…sniff

 

Here’s my SYSCOPY query for all cases:

SELECT ICTYPE, STYPE, MIN(ICDATE) AS OLDEST, MAX(ICDATE) AS NEWEST
     , COUNT(*) AS COUNT                                          
FROM SYSIBM.SYSCOPY                                               
GROUP BY ICTYPE , STYPE                                           
;                                                                 
---------+---------+---------+---------+---------+
ICTYPE  STYPE  OLDEST  NEWEST        COUNT           
---------+---------+---------+---------+---------+
A       A      121228  121228            4        
B              121228  130128           46       
C       L      100809  130204         1669    
C       O      120827  120827            4    
F              100809  130204          100     
F       W      100809  130204           16   
I              130131  130204            4
M       R      130102  130131           18         
R              120829  130130          151        
S              120829  130131           62      
W              100809  130204           18       
W       S      100809  100809            1     
Y              120828  120828            2    
Z              120828  130201          269    
DSNE610I NUMBER OF ROWS DISPLAYED IS 14

 

Clean Up

OK, so what can you do if you have 1000’s of these records? Well I would start with MODIFY RECOVER utilities to delete the bad guys. Your “normal” DB2 Database Maintenance jobs should take care of this for you but if you do not run these on a regular basis then start with this query:

SELECT A.DBNAME, A.TSNAME, A.DSNUM                              
      , MAX(DATE(A.TIMESTAMP)), MIN(DATE(A.TIMESTAMP)), COUNT(*)
FROM SYSIBM.SYSCOPY A                                           
WHERE A.ICTYPE = 'L'                                            
  AND A.STYPE  = 'M'                                            
  AND EXISTS (SELECT 1                                          
              FROM SYSIBM.SYSCOPY B                             
              WHERE A.DBNAME = B.DBNAME                         
                AND A.TSNAME = B.TSNAME                         
                AND (A.DSNUM  = B.DSNUM                         
                 OR (A.DSNUM > 0                                
                 AND B.DSNUM = 0 ))                             
                AND A.START_RBA < B.START_RBA                   
                AND B.ICTYPE = 'F')                             
GROUP BY A.DBNAME, A.TSNAME, A.DSNUM                            
FOR FETCH ONLY                                                  
WITH UR                                                         
;

The output shows you the DBNAME, TSNAME, DSNUM and counts for all of the “bad guys” that have at least one Full Image Copy *after* the bad guy was inserted:

---------+---------+---------+---------+---------+---------+---------+
DBNAME    TSNAME          DSNUM                                       
---------+---------+---------+---------+---------+---------+---------+
R510D0PT  R510S04             0  2016-01-26  2015-11-11           75  
R510D0PT  R510S10             0  2016-01-26  2015-11-11           75  
R510D0PT  R510S12             0  2016-01-26  2015-11-11           75  
R510D0PT  R510S14             0  2016-01-26  2015-11-11           75

 

This gives you the needed input to write a simple MODIFY RECOVER utility input like this:

 

MODIFY RECOVERY TABLESPACE R510D0PT.R510S04 DELETE DATE 20151203

Why did I use 2015-12-03 when in the query output I have 2015-11-11? That’s because I do not want to delete *all* of the Image Copy data in SYSCOPY – just the data from 2015-11-11 to 2015-12-02 (remember that MODIFY works up to the date *before* you enter). The output from the MODIFY looked like this:

 

DSNU000I    028 09:10:43.97 DSNUGUTC - OUTPUT START FOR UTILITY, 
            UTILID = PTFMO000MOU001
DSNU1044I   028 09:10:44.16 DSNUGTIS - PROCESSING SYSIN AS EBCDIC
DSNU050I    028 09:10:44.17 DSNUGUTC -  MODIFY RECOVERY TABLESPACE
            R510D0PT.R510S04 DELETE DATE 20151203
DSNU517I    -QA1B 028 09:10:44.28 DSNUMDEL 
            - SYSCOPY RECORD DELETED BY MODIFY UTILITY.
DSN=SETEST.R510D0PT.R510S04.D15142.T0635, VOL=SER=(CATLG), FILESEQNO=0
DSNU575I   -QA1B 028 09:10:44.49 DSNUMODA - MODIFY COMPLETED SUCCESSFULLY
DSNU010I    028 09:10:44.52 DSNUGBAC - UTILITY EXECUTION COMPLETE, 
            HIGHEST RETURN CODE=0

 

Now you must also IDCAMS Delete any, and all, of the dataset names output here.

Now re-running the original query gives:

---------+---------+---------+---------+---------+---------+---------
DBNAME    TSNAME          DSNUM                                      
---------+---------+---------+---------+---------+---------+---------
R510D0PT  R510S04             0  2016-01-26  2015-12-03           53 
R510D0PT  R510S10             0  2016-01-26  2015-11-11           75 
R510D0PT  R510S12             0  2016-01-26  2015-11-11           75 
R510D0PT  R510S14             0  2016-01-26  2015-11-11           75

 

24 type L & M records gone from between 2015-11-11 and 2015-12-02 and of course the object is not in COPY Pending status!

However, there are cases where you cannot do this straightaway (Perhaps never been image copied?). In these cases, the simplest method is to do an Image copy and then a Modify, but if the object is to big then you must make the DB2 Catalog updateable (ask your friendly Sysprog about this,) and simply use an SQL DELETE to remove all of the entries for an object *before* the last Full Image Copy.

Once you have removed all the fluff, remember to REORG SYSCOPY and RUNSTAT the indexes. Then it should be a *lot* thinner and make migrating a tad easier!

 

As always if you have any comments or questions please email me!

TTFN

Roy Boxwell

 

IDUG 2016 DB2 European Tech Conference

SEGUS & SOFTWARE ENGINEERING präsentieren


„Access Path Recovery for DB2 11 & 12 using RUNSTATS Rescue“

15. November 2016

What is the number one reason for bad access paths? Bad statistics!

Why do you have bad statistics? Bad timing is the number one reason, followed by manually updated stats and then forgotten about.

RUNSTATS Rescue for DB2 z/OS saves you when these events happen. The basis is a complete copy of all productive required statistical data in the DB2 catalog. This should be regularly executed and the data saved away. The best way to do this is to use a Generation Gengroup which automatically stores “copies” of the data. RUNSTATS Rescue then provides a front end where you can use a variety of inputs to get back you good access paths.

  • Dynamic SQL, Static SQL completely covered
  • Why PLAN Stability doesn’t save you when you need it
  • What’s new in DB2 12 for Dynamic SQL that still will not save you

Audience experience Level

Beginner, Intermediate, Advanced

Speaker Biography

Roy Boxwell has more than 30 years of experience in MVS, OS/390, and z/OS environments – 26 of those in DB2. He specializes in installation, migration, and performance monitoring and tuning. Roy leads the SEG development team responsible for the real time database maintenance solutions. He is also an active participant, speaker and contributor on the IDUG DB2 Listserv and sends out a monthly DB2 z/OS Newsletter.


„Compliance with compliments! Viable DB2 z/OS workload tracking“.

16. November, 2016

Audit and Compliance is a need that many companies want and have to fulfill.

There’s different ways and tools that promise to be able to do it, but what can they really do and what are the associated costs? This presentation introduces DB2 10/11 technology exploitation that delivers any DML, DDL, DCL being executed in a DB2 environment along with identification details. Learn how you can run Audit analytics against a long‐term repository, pinpointing who executed a query, when and from where. Analyze your entire workload to understand access patterns and abnormalities.

Audience experience Level

Beginner, Intermediate, Advanced

Objectives

 Objective 1Audit needs and musts Take a journey to GLB HIPAA PCI‐DSS Basel III Sarbanes‐Oxley CA SB1386 Federal Information Security Management Act “ed Flag”Rules (FRCA)5.
 Objective 2Solution overview and their Pros/Cons Get an overview about the existing solutions and understand how they work.
 Objective 3 The viable way – let DB2 do the magic! Learn about DB2 enhancements in DB2 10/11 that deliver the DB2 workload being processed and understand why it’s so efficient.
 Objective 4 Customer results from the banking industry Receive some experience from a large banking company and how they successfully replaced their DB2 Audit feature based reporting by a modern SQL tracking and analytics process.


Speaker biography

Ulf Heinrich is the Director of Solutions Delivery at SOFTWARE ENGINEERING GmbH. He specializes in DB2 recovery issues and database maintenance, focusing on the growing requirement for cost reduction and 24×7 operations. As a consultant at large customer sites, he has implemented database maintenance procedures and recovery strategies, and also experienced the pitfalls of recovery scenarios under real‐world recovery pressure. His activities cover EMEA, as well as North America through SE’ U.S. subsidiary, SEGUS Inc. He’ involved in the development of SE’ maintenance andrecovery Solutions.