Tuesday, March 17, 2015

Determing whether a reorg could benefit performance without using reorgchk




the scripts below can be used to determine whether over a certain interval ,
how much overflow accesses occur for  table in that interval.


I created this script after reading the blog article on reorg and reorgchk by Ember Crooks,
and the comment by Scott hayes on this article.
Ember's Article on Reorg
Scott hayes' company website where I learned the formula below


thanks to both people mentioned above, I was able to write this script that might help you.

Step1 create the baseline table
Step2 insert the baseline into the baseline table
Step3 wait the interval
Step 4 determine the delta values over the interval
Step5 evaluate the metrics
step6 reorg the table


#!/usr/bin/ksh
#
# Usage         :
#
# Description   :
#
# Pre-requisites:
#
# Author        : Albert Mukendi Raf Mathijs
#
# Version       : 1.1
#
# Date          : 2012-XX-XX
#
# Information   :
#
#
# Begin Funcions
#

function Usage
{
   echo "---------------------------------------------------------------------------------------------------------"
   echo "Usage : $(basename $0) DATABASE INTERVAL_in_seconds"
   echo
}

# Load common functions
. /db2scripts/common_script/ksh_functions

# Check unintialized variables
set -u

# Check input parameter
readonly NbInputParmReq=2
[[ $# != ${NbInputParmReq} ]] && Usage && FatalError "The script expects ${NbInputParmReq} input parameters and receives $#"

# Initialisation and declaration of variables
readonly BASEPATH=
readonly LOGFILE=$(basename $0)_${DB2INSTANCE}_$(hostname)_$(date +%Y-%m-%d-%H.%M.%S).log
integer RC_CMD=0
readonly DATABASE=$1
readonly INTERVAL=$2

# Action
{
MsgStart
db2 connect to ${DATABASE}
print "create baseline tables"
db2 -v "declare global temporary table session.mon_table_baseline as (select current timestamp as                                                                                                           /dev/null
print " delete data from baseline table ( just in case )"
db2 -x "delete from session.mon_table_baseline"  > /dev/null
print "insert baseline data into baseline table"
db2 -v "insert into session.mon_table_baseline select current timestamp as snapshot_timestamp, a.
print " wait the given interval ( ${INTERVAL} seconds )"
sleep ${INTERVAL}
print " done sleeping"
#print " collect the delta information and return the wanted information"
print " Overflow Related Metrics "
print " ------------------------ "
db2 -v " select timestampdiff(2,char(timestamp(current timestamp)-b.snapshot_timestamp)) as snaps                                                                                                            TABNAME,c.DATA_OBJECT_L_PAGES as Logical_pages_on_disk,c.OVERFLOW_ACCESSES-b.OVERFLOW_ACCESSES a                                                                                                            /( c.rows_read - b.rows_read) as PCT_OVERFLOW_ACCESSES_ROWS_READ from table(mon_get_table(NULL,N                                                                                                           R=b.MEMBER where c.rows_read-b.rows_read > 0  order by 5,6,7 desc fetch first 50 rows only"

MsgSuccess "End of the script - `date`"
#} > ${LOGFILE}
} | tee ${LOGFILE}
#}


# History:
# --------
# 1.1 2012-XX-XX Creation

# To do:
# ------

Monday, March 16, 2015

In memory metrics of db2, working with baseline tables

in my previous blog entry I rewrote some scripts that scott hayes published in a blog post on the IDUG website.

my version of those scripts would give you feedback on the metrics based on the data collected since the start of the instance.

in this entry I will put the same scripts but modified so they give you the metrics based on a baseline you setup in advance.

#!/usr/bin/ksh

function Usage
{
   echo "---------------------------------------------------------------------------------------------------------"
   echo "Usage : $(basename $0) DATABASE INTERVAL_in_seconds"
   echo
}

readonly LOGFILE=$(basename $0)_${DB2INSTANCE}_$(hostname)_$(date +%Y-%m-%d-%H.%M.%S).log
readonly DATABASE=$1
readonly INTERVAL=$2

{db2 -v " declare global temporary table session.mon_get_table_baseline as (select current timestamp as snapshot_timestamp, a.*  from table(mon_get_table(null,null,-2)) a ) with no data on commit preserve rows"

db2 -v "insert into session.mon_get_table_baseline select current timestamp as snapshot_timestamp, a.*  from table(mon_get_table(null,null,-2)) a"

WAIT THE TIMEFRAME YOU WANT TO ANALYZE
sleep $INTERVAL

db2 -v "with delta_values as (
select substr(a.tabschema,1,20) as TABSCHEMA,

substr(a.tabname,1,25) as TABNAME,
--a.member,
sum(a.rows_read) - sum(b.rows_read) as delta_rows_read,
((select sum(c.rows_read) from table(mon_get_table(null,null,-2)) c ) - (select sum(d.rows_read) from session.mon_get_table_baseline d)) as delta_total_rows_read
from table(mon_get_table(null,null,-2)) a join  session.mon_get_table_baseline b on a.tabschema=b.tabschema and a.tabname=b.tabname and a.member=b.member and a.DATA_PARTITION_ID=b.DATA_PARTITION_ID
group by a.tabschema,a.tabname)

select substr(e.tabschema,1,20) as TABSCHEMA, 

substr(e.tabname,1,25) as TABNAME,
--e.member,

e.delta_rows_read,
e.delta_total_rows_read,
decimal(e.delta_rows_read,31,4)/e.delta_total_rows_read * 100 as pct_of_rows_read
from delta_values e
order by 
--pct_of_rows_read,
e.delta_rows_read desc fetch first 20 rows only"
} | tee ${LOGFILE}

Thursday, March 12, 2015

DB2 Performance Queries: Stolen from Scott hayes and changed to use mon_get_functions

scott hayes DB2 performance article on IDUG 


first script to check which tables are read the most:

Figure 1 – Table Weights

select substr(a.tabschema,1,20) as TABSCHEMA,

substr(a.tabname,1,25) as TABNAME,

a.rows_read as RowsRead,

CAST((((A.ROWS_READ) * 100.0)

/ (Select (SUM(Z.ROWS_READ) + 1.0)

FROM table(mon_get_table(null,null,-2)) Z

WHERE A.MEMBER = Z.MEMBER

)) AS DECIMAL(5,2)) AS PCT_DB_TB_ROWSREAD

from table(mon_get_table(null,null,-2)) a

order by a.rows_read desc fetch first 20 rows only;

Figure 4 – SQL Heavy CPU Consumers

SELECT

CAST(

A.TOTAL_CPU_TIME


/ A.NUM_EXECUTIONS

AS DECIMAL (15,0)) AS AVG_CPU_TIME,

CAST (A.NUM_EXECUTIONS AS INTEGER) AS NUM_EXECS,

CAST(((

A.TOTAL_CPU_TIME
* 100.0)

/ Coalesce((Select SUM(TOTAL_CPU_TIME)

FROM table(mon_get_pkg_cache_stmt('D',null,null,-2)) B

WHERE A.MEMBER = B.MEMBER and Member=0

),1)) AS DECIMAL(5,2)) AS PCT_CPU_TIME,

SUBSTR(A.STMT_TEXT,1,110) AS CPU_SUCKING_SQL

FROM table(mon_get_pkg_cache_stmt('D',null,null,-2)) A

WHERE A.NUM_EXECUTIONS > 0

ORDER BY A.MEMBER ASC, 3 DESC, 1 DESC FETCH FIRST 25 ROWS ONLY

Figure 5 – SQL Heavy I/O Consumers

SELECT CAST (A.NUM_EXECUTIONS AS INTEGER) AS NUM_EXECS,

CAST( (A.ROWS_READ + 0.001) / (A.NUM_EXECUTIONS + 0.001)

AS DECIMAL (13,4)) AS AVG_ROWS_READ,

CAST((((A.ROWS_READ) * 100.0)

/ (Select (SUM(B.ROWS_READ) + 1.0)

FROM table(mon_get_pkg_cache_stmt('D',null,null,-2)) B

WHERE A.MEMBER = B.MEMBER

)) AS DECIMAL(5,2)) AS PCT_ROWS_READ,

SUBSTR(A.STMT_TEXT,1,110) AS HEAVY_READER_SQL

FROM table(mon_get_pkg_cache_stmt('D',null,null,-2)) A

WHERE A.ROWS_READ > 0 AND A.NUM_EXECUTIONS > 0

ORDER BY A.MEMBER ASC, 3 DESC, 2 DESC FETCH FIRST 25 ROWS ONLY;

I'll work on the other scripts too...