在平时的工作中,需要管理的数据库还是很多的,因为远程和权限的关系,访问不了一些图形工具,
有时候做检查的时候感觉都是一个串行的过程,这样检查针对性就不够强了,比如我们不知道在检查的这个时间范围内,数据库的负载是在什么范围内,如果有些库的负载极高,就需要格外注意,进行更有针对性的分析和检查,要不假设有20个库需要同时管理,没有重点,眉毛胡子一把抓还是很头疼的。查看数据库的负载还是一个不错的指标,我们可以根据这个基准来同时监控多个数据库,基本能够在一个大屏幕内显示就可以了。
自己专门写了脚本,发现效果还是不错的。这样数据库的负载就很清晰了,哪些库在忙需要重点关注,哪些库还基本处于休眠状态,可以不用太关注。
实现的脚本如下:
#getload.sh
function showsnap
{
sqlplus -s $1 break on db_name
set pages 50
set linesize 65
prompt
prompt Current Instance
prompt ~~~~~~~~~~~~~~~~
select d.dbid dbid
, d.name db_name
, i.instance_number inst_num
, i.instance_name inst_name
from v\$database d,
v\$instance i;
select
begin_snap
,end_snap
,snapdate
,round(((END_INTERVAL_TIME+0)-(BEGIN_INTERVAL_TIME+0 ))*24*60) dur_mins
,round((select round((sum(e.value) -
sum(b.value)) / 1000000 /60,2) dbtime
FROM DBA_HIST_SYS_TIME_MODEL e, DBA_HIST_SYS_TIME_MODEL b
WHERE
e.STAT_NAME = 'DB time'
and b.snap_id=begin_snap
and e.snap_id =end_snap
AND b.STAT_NAME = 'DB time'
group by e.snap_id,b.snap_id)) dbtime
from
(
select
s.snap_id begin_snap
,lead(s.snap_id ,1,s.snap_id ) over(order by s.end_interval_time ) end_snap
, to_char(s.end_interval_time,'dd Mon YYYY HH24:mi') snapdate
,s.end_interval_time
,s.begin_interval_time
from dba_hist_snapshot s
, dba_hist_database_instance di
where
( di.dbid,di.instance_number) in
(select d.dbid dbid
, i.instance_number inst_num
from v\$database d,
v\$instance i)
and di.dbid = s.dbid
and di.instance_number = s.instance_number
and di.startup_time = s.startup_time
and to_char(END_INTERVAL_TIME,'yyyymmdd')='$2'
and EXTRACT(HOUR FROM END_INTERVAL_TIME) between $3-1 and $4+1
order by db_name, instance_name, snap_id
);
EOF
}
curr_hr=`date '+%H'`
pre_hr=`expr $curr_hr - 3`
DATE=`date '+%Y%m%d'`
#echo $curr_hr $pre_hr
SH_DB_SID=`echo "$1"|awk -F@ '{print $2}'|tr '[a-z]' '[A-Z]'`
showsnap $1 $DATE $pre_hr $curr_hr > tmp_${SH_DB_SID}_${DATE}_load
function format_rpt
{
awk '
BEGIN{
print "#################################################################"
printf "%-65s\n","DB workload "
print "#################################################################"
}
{
printf "%-65s\n",$0
}' $1 > $2
}
format_rpt tmp_${SH_DB_SID}_${DATE}_load ${SH_DB_SID}_${DATE}_load
rm tmp_${SH_DB_SID}_${DATE}_load
cat ${SH_DB_SID}_${DATE}_load
第二个脚本是集成这些输出结果的,使用动态地方式灵活指定监控的指标,
#showall.sh
#get db load input getload
#get db tsps input showtsps
act_type=$1
ksh ${act_type}.sh xxx/xxx@xxxx > tmp_b4 cat b7
比如我们有一个脚本getload.sh是专门监控数据库负载的,就可以运行脚本 showall.sh getload即可。如果要查看表空间使用情况,我们有脚本showtsps.sh,就运行脚本showall.sh showtsps即可。DB_CONN_STR=XXX/XXX
#get db load input getload
#get db tsps input showtsps
act_type=$1
#### DB01
SH_DB_SID=XXX
ksh ${act_type}.sh $DB_CONN_STR@$SH_DB_SID > a1
#### DB02
SH_DB_SID=XXX
ksh ${act_type}.sh $DB_CONN_STR@$SH_DB_SID > a2
#### DB03
SH_DB_SID=XXX
ksh ${act_type}.sh $DB_CONN_STR@$SH_DB_SID > a3
cat a1
paste a2 a3
paste a4 a5
paste a6 a7
cat a8
自己专门写了脚本,发现效果还是不错的。这样数据库的负载就很清晰了,哪些库在忙需要重点关注,哪些库还基本处于休眠状态,可以不用太关注。
实现的脚本如下:
#getload.sh
function showsnap
{
sqlplus -s $1 break on db_name
set pages 50
set linesize 65
prompt
prompt Current Instance
prompt ~~~~~~~~~~~~~~~~
select d.dbid dbid
, d.name db_name
, i.instance_number inst_num
, i.instance_name inst_name
from v\$database d,
v\$instance i;
select
begin_snap
,end_snap
,snapdate
,round(((END_INTERVAL_TIME+0)-(BEGIN_INTERVAL_TIME+0 ))*24*60) dur_mins
,round((select round((sum(e.value) -
sum(b.value)) / 1000000 /60,2) dbtime
FROM DBA_HIST_SYS_TIME_MODEL e, DBA_HIST_SYS_TIME_MODEL b
WHERE
e.STAT_NAME = 'DB time'
and b.snap_id=begin_snap
and e.snap_id =end_snap
AND b.STAT_NAME = 'DB time'
group by e.snap_id,b.snap_id)) dbtime
from
(
select
s.snap_id begin_snap
,lead(s.snap_id ,1,s.snap_id ) over(order by s.end_interval_time ) end_snap
, to_char(s.end_interval_time,'dd Mon YYYY HH24:mi') snapdate
,s.end_interval_time
,s.begin_interval_time
from dba_hist_snapshot s
, dba_hist_database_instance di
where
( di.dbid,di.instance_number) in
(select d.dbid dbid
, i.instance_number inst_num
from v\$database d,
v\$instance i)
and di.dbid = s.dbid
and di.instance_number = s.instance_number
and di.startup_time = s.startup_time
and to_char(END_INTERVAL_TIME,'yyyymmdd')='$2'
and EXTRACT(HOUR FROM END_INTERVAL_TIME) between $3-1 and $4+1
order by db_name, instance_name, snap_id
);
EOF
}
curr_hr=`date '+%H'`
pre_hr=`expr $curr_hr - 3`
DATE=`date '+%Y%m%d'`
#echo $curr_hr $pre_hr
SH_DB_SID=`echo "$1"|awk -F@ '{print $2}'|tr '[a-z]' '[A-Z]'`
showsnap $1 $DATE $pre_hr $curr_hr > tmp_${SH_DB_SID}_${DATE}_load
function format_rpt
{
awk '
BEGIN{
print "#################################################################"
printf "%-65s\n","DB workload "
print "#################################################################"
}
{
printf "%-65s\n",$0
}' $1 > $2
}
format_rpt tmp_${SH_DB_SID}_${DATE}_load ${SH_DB_SID}_${DATE}_load
rm tmp_${SH_DB_SID}_${DATE}_load
cat ${SH_DB_SID}_${DATE}_load
第二个脚本是集成这些输出结果的,使用动态地方式灵活指定监控的指标,
#showall.sh
#get db load input getload
#get db tsps input showtsps
act_type=$1
ksh ${act_type}.sh xxx/xxx@xxxx > tmp_b4 cat b7
比如我们有一个脚本getload.sh是专门监控数据库负载的,就可以运行脚本 showall.sh getload即可。如果要查看表空间使用情况,我们有脚本showtsps.sh,就运行脚本showall.sh showtsps即可。DB_CONN_STR=XXX/XXX
#get db load input getload
#get db tsps input showtsps
act_type=$1
#### DB01
SH_DB_SID=XXX
ksh ${act_type}.sh $DB_CONN_STR@$SH_DB_SID > a1
#### DB02
SH_DB_SID=XXX
ksh ${act_type}.sh $DB_CONN_STR@$SH_DB_SID > a2
#### DB03
SH_DB_SID=XXX
ksh ${act_type}.sh $DB_CONN_STR@$SH_DB_SID > a3
cat a1
paste a2 a3
paste a4 a5
paste a6 a7
cat a8