 |
|
Extending STATSPACK for OPS
Information
Oracle Tips by Burleson Consulting
|
Once the IDLM is running, you can run the
lkdump command to determine the values of IDLM resources and
locks, as well as overall IDLM processes. Checking these values is a
very critical activity because these values cannot exceed the values
defined in your IDLM configuration file. If any one of these values
exceeds the value in the configuration file, the IDLM will hang,
causing your entire OPS system to lock up.
It is very important to keep track of the
high-water mark for these IDLM values. The following script will get
the existing initial values for locks, resources, and programs from
your conf file and compare these values to the maximum values
from your Oracle IDLM statistics table. It is a good idea to run this
script at least once per day to ensure that the Oracle database does
not hang.
Here is the code to create a STATSPACK
extension table to hold the IDLM information.
create_idlm_table.sql
L 13-9
connect perfstat/perfstat;
drop table perfstat.stats$idlm_stats;
create table perfstat.stats$idlm_stats
(
snap_time date,
pro number,
res number,
loc number
)
tablespace perfstat
storage (initial 1m next 1m maxextents unlimited)
;
It is always a good idea to keep a running list of these
critical IDLM values, and the script here will capture these values
and place them into STATSPACK extension tables for later analysis.
get_idlm.ksh
L 13-10
# Capture IDLM statistics – 1998 by Donald
Keith Burleson
DAY_OF_WEEK=`date +"%A"`
MACHINE_NAME=`hostname`
REPORT_FILE=/oracle/HOME/Remote DBA/dlm_monitor.${MACHINE_NAME}.${DAY_OF_WEEK}.log
#
# Set up the file to log the lock to:
#
TIMESTAMP=`date +"%C%y.%m.%d-%H:%M:%S"`
DLM_RESOURCES=`/oracle/HOME/bin/lkdump -a res | head -2 | awk 'getline'`
DLM_LOCKS=`/oracle/HOME/bin/lkdump -a lock | head -2 | awk 'getline'
`
DLM_PROCESS=`/oracle/HOME/bin/lkdump -a proc | head -2 | awk 'getline'`
printf "$TIMESTAMP $DLM_RESOURCES $DLM_LOCKS $DLM_PROCESS \n" >>
REPORT_FILE
RES=`echo $DLM_RESOURCES|cut -f2 -d '='`
LOC=`echo $DLM_LOCKS|cut -f2 -d '='`
PRO=`echo $DLM_PROCESS|cut -f2 -d '='`
ORACLE_SID=HOME; export ORACLE_SID;
PATH=$PATH:/oracle/HOME/bin; export PATH;
ORACLE_HOME=/oracle/HOME; export ORACLE_HOME;
/oracle/HOME/bin/sqlplus <<! >> /dev/null
connect perfstat/perfstat;
insert into perfstat.stats$idlm_stats
values (
SYSDATE,
$PRO,
$RES,
$LOC );
exit;
!
This get_idlm.ksh script is normally scheduled to
run every five minutes to gather a snapshot of the important IDLM
behaviors. Most Remote DBAs place the execution for the script in their UNIX
crontab file.
Now that we have defined a table for the IDLM
information, we are ready to look at a report from our
stats$idlm_stats table. The next script is run against our STATSPACK
extension table to report on exceptional conditions within the IDLM.
rpt_idlm_hwm.ksh
L 13-11
#! /bin/ksh
# Display high-water mark of IDLM
# Donald K. Burleson
# get the max values . . . .
#grep ^lkmgr_args /oracle/HOME/ops/HOME.conf
MAX_LOC=`grep ^lkmgr_args /oracle/HOME/ops/HOME.conf|cut -f6 -d ' '`
MAX_RES=`grep ^lkmgr_args /oracle/HOME/ops/HOME.conf|cut -f8 -d ' '`
MAX_PRO=`grep ^lkmgr_args /oracle/HOME/ops/HOME.conf|cut -f10 -d '
'|sed -e 's/"//
'`
ORACLE_SID=HOME; export ORACLE_SID;
PATH=$PATH:/oracle/HOME/bin; export PATH;
ORACLE_HOME=/oracle/HOME; export ORACLE_HOME;
unalias rm
rm -f *.tmp
/oracle/HOME/bin/sqlplus <<! > /dev/null
connect perfstat/perfstat;
set newpage 0;
set space 0
set pages 0
set termout off
set feedback off
set echo off
set heading off
spool pro
select max(processes) from perfstat.stats$dlm_stats;
spool res
select max(resources) from perfstat.stats$dlm_stats;
spool loc
select max(locks) from perfstat.stats$dlm_stats;
spool off
exit
!
PRO=`grep '^ ' pro.lst|awk '{print $1}'`
RES=`grep '^ ' res.lst|awk '{print $1}'`
LOC=`grep '^ ' loc.lst|awk '{print $1}'`
# Now the fun part . . . .
PCT_PRO=`expr $PRO \* 100 \/ $MAX_PRO`
echo "IDLM Process high-water mark is $PRO, or $PCT_PRO percent of
max val of
MAX_PRO"
PCT_RES=`expr $RES \* 100 \/ $MAX_RES`
echo "IDLM Resource high-water mark is $RES, or $PCT_RES percent of
max val of
MAX_RES"
PCT_LOC=`expr $LOC \* 100 \/ $MAX_LOC`
echo "IDLM Locks high-water mark is $LOC, or $PCT_LOC percent of max
val of $MAX_LOC"
Again, most Remote DBAs schedule this report to run hourly so
they can track changes in the high-water mark for the IDLM. Next,
let's look at the v$ views that can help us track down OPS locking
issues with the IDLM.
Querying the v$ Views for
Oracle Parallel Server
Oracle has several v$ views that were created
especially for OPS. These views can be used to tell the Remote DBA the
cumulative rate of OPS activity since the instance was started. Here
are the most interesting v$ views for OPS:
-
The v$lock_activity view This view is a
very good way to determine if you have reached the maximum lock
convert rate for your IDLM. If the maximum lock convert rate has
been reached, you will need to repartition the application to
balance alike transactions into common instances.
-
The v$ping view This view tracks the
number of IDLM pings that relate to this database instance.
The v$ping view is especially useful for showing lock
conversions in OPS. Oracle Parallel Server provides a view called
v$ping to show lock conversions. We start by querying the v$ping view
to see if there are any data files experiencing a high degree on lock
conversions, as follows.
ping.sql
L 13-12
SELECT
substr(name,1,10),
file#,
class#,
max(xnc)
FROM
v$ping
GROUP BY 1, 2, 3
ORDER BY 1, 2, 3;
Here is the output from this script. The XNC column is
the one that directly relates to lock conversions.
L 13-13
Name File # Class # Max (XNC)
------ ------ ------- --------
Customer 13 1 556
Customer 13 4 32
Item 6 1 1
Item 3 4 32
Order 16 1 33456
Here, we see that the order table (File 16) may have a
problem with excessive lock conversions because of the high value for
Max XNC. To further investigate, return to v$ping, and get the sums
for File 16, as follows:
L 13-14
SELECT
*
FROM
v$ping
WHERE
file#=16
ORDER BY
block#;
Now, we can see additional detail about the contents of
File 16, as shown here:
L 13-15
File # Block # Stat XNC
Class # Name Kind
------ ------- ---- ----- ------- ---- -----
16 11 XCUR 5 1 ORDER Table
16 12 XCUR 33456 1 ORDER Table
16 13 XCUR 12 1 ORDER Table
From this output, we can see that block 12 inside File
16 is the source of our contention. The following query against the
order table will reveal the contents of the rows in the data block.
Remember, data blocks are numbered in hex, so we convert the decimal
number 12 to a hexadecimal “C”.
L 13-16
SELECT
rowid,
order_number,
customer_number
FROM
ORDER
WHERE
chattorowid(rowid) LIKE '0000000C%;
Here we see the results from this query, showing the
details for all data rows on this block:
L 13-17
ROWID ORDER_NUMBER
CUSTOMER_NUMBER
------------------ ----------- ---------------
0000000C.0000.0008 1212 73
0000000C.0000.0008 1213 73
0000000C.0000.0008 1214 73
These results indicate that lock conversion relates to
orders placed by customer number 73. Other than a random coincidence,
we can assume that there may be freelist contention in the order table
as new orders are added to the database. Adding additional freelists
will allow more concurrency during SQL insert operations, and
the value for freelists should be reset to the maximum number of end
users who are expected to be inserting an order row at any given time.
In Oracle8i, you can issue the following command:
L 13-18
alter table
order
storage
( freelists 7 )
;
Before Oracle8i, Oracle does not allow the dynamic
modification of freelists, because they were physically stored in each
data block. So, the only alternative is to drop and re-create the
table with more freelists in each block header. Following is the SQL
used to drop and recreate the order table:
L 13-19
CREATE TABLE
ORDER_DUMMY
STORAGE (freelists 10)
AS
SELECT * FROM ORDER;
DROP TABLE ORDER;
RENAME ORDER_DUMMY TO ORDER;
Next, let’s compare OPS with RAC and understand
how RAC is used for continuous availability. One of the most exciting
new features of Oracle9i is their new and improved clustering product,
Real Application Clusters. This next section explores techniques to
achieve success with RAC and see alternative mechanisms for automated
failover and continuous availability.
This is an excerpt from "Oracle9i
High Performance tuning with STATSPACK" by Oracle Press.
 |
If you like Oracle tuning, you may enjoy the new book "Oracle
Tuning: The Definitive Reference", over 900 pages
of BC's favorite tuning tips & scripts.
You can buy it direct from the publisher for 30%-off and get
instant access to the code depot of Oracle tuning scripts. |
 |
Expert Remote DBA
BC is America's oldest and largest Remote DBA Oracle support
provider. Get real Remote DBA experts, call
BC Remote DBA today. |
 |
|