Script:Tablespace Report

该脚本用以汇总表空间使用情况报告:

REM tablespace report


set linesize 200


select a.tablespace_name,
       round(a.bytes_alloc / 1024 / 1024) megs_alloc,
       round(nvl(b.bytes_free, 0) / 1024 / 1024) megs_free,
       round((a.bytes_alloc - nvl(b.bytes_free, 0)) / 1024 / 1024) megs_used,
       round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_Free,
       100 - round((nvl(b.bytes_free, 0) / a.bytes_alloc) * 100) Pct_used,
       round(maxbytes / 1048576) Max
  from (select f.tablespace_name,
               sum(f.bytes) bytes_alloc,
               sum(decode(f.autoextensible, 'YES', f.maxbytes, 'NO', f.bytes)) maxbytes
          from dba_data_files f
         group by tablespace_name) a,
       (select f.tablespace_name, sum(f.bytes) bytes_free
          from dba_free_space f
         group by tablespace_name) b
 where a.tablespace_name = b.tablespace_name(+)
union all
select h.tablespace_name,
       round(sum(h.bytes_free + h.bytes_used) / 1048576) megs_alloc,
       round(sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
             1048576) megs_free,
       round(sum(nvl(p.bytes_used, 0)) / 1048576) megs_used,
       round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
             sum(h.bytes_used + h.bytes_free)) * 100) Pct_Free,
       100 -
       round((sum((h.bytes_free + h.bytes_used) - nvl(p.bytes_used, 0)) /
             sum(h.bytes_used + h.bytes_free)) * 100) pct_used,
       round(sum(f.maxbytes) / 1048576) max
  from sys.v_$TEMP_SPACE_HEADER h,
       sys.v_$Temp_extent_pool  p,
       dba_temp_files           f
 where p.file_id(+) = h.file_id
   and p.tablespace_name(+) = h.tablespace_name
   and f.file_id = h.file_id
   and f.tablespace_name = h.tablespace_name
 group by h.tablespace_name
 ORDER BY 1
/


    SELECT d.tablespace_name "Name", 
                TO_CHAR(NVL(a.bytes / 1024 / 1024, 0),'99,999,990.900') "Size (M)", 
                TO_CHAR(NVL(t.hwm, 0)/1024/1024,'99999999.999')  "HWM (M)",
                TO_CHAR(NVL(t.hwm / a.bytes * 100, 0), '990.00') "HWM % " ,
                TO_CHAR(NVL(t.bytes/1024/1024, 0),'99999999.999') "Using (M)", 
	        TO_CHAR(NVL(t.bytes / a.bytes * 100, 0), '990.00') "Using %" 
           FROM sys.dba_tablespaces d, 
                (select tablespace_name, sum(bytes) bytes from dba_temp_files group by tablespace_name) a,
                (select tablespace_name, sum(bytes_cached) hwm, sum(bytes_used) bytes from v$temp_extent_pool group by tablespace_name) t
          WHERE d.tablespace_name = a.tablespace_name(+) 
            AND d.tablespace_name = t.tablespace_name(+) 
            AND d.extent_management like 'LOCAL' 
            AND d.contents like 'TEMPORARY'
/


ttitle - 
   center  'Database Freespace Summary'  skip 2 
 
comp sum of nfrags totsiz avasiz on report 
break on report 

set pages 999
col tsname  format     a16 justify c heading 'Tablespace' 
col nfrags  format 999,990 justify c heading 'Free|Frags' 
col mxfrag  format 999,999 justify c heading 'Largest|Frag (MB)' 
col totsiz  format 999,999 justify c heading 'Total|(MB)' 
col avasiz  format 999,999 justify c heading 'Available|(MB)' 
col pctusd  format     990 justify c heading 'Pct|Used' 

select total.TABLESPACE_NAME tsname,
       D nfrags,
       C/1024/1024 mxfrag,
       A/1024/1024 totsiz,
       B/1024/1024 avasiz,
       (1-nvl(B,0)/A)*100 pctusd
from
    (select sum(bytes) A,
            tablespace_name
            from dba_data_files
            group by tablespace_name) TOTAL,
    (select sum(bytes) B,
            max(bytes) C,
            count(bytes) D, 
            tablespace_name
            from dba_free_space
            group by tablespace_name) FREE
where 
      total.TABLESPACE_NAME=free.TABLESPACE_NAME(+)
/


SELECT t.tablespace_name,
       CASE
         WHEN t.contents = 'TEMPORARY' AND t.extent_management = 'LOCAL' THEN
          u.bytes
         ELSE
          df.user_bytes - NVL(fs.bytes, 0)
       END / 1024 / 1024 used_mb,
       CASE
         WHEN t.contents = 'TEMPORARY' AND t.extent_management = 'LOCAL' THEN
          df.user_bytes - NVL(u.bytes, 0)
         ELSE
          NVL(fs.bytes, 0)
       END / 1024 / 1024 free_mb,
       fs.min_fragment / 1024 / 1024 min_fragment_mb,
       fs.max_fragment / 1024 / 1024 max_fragment_mb,
       (fs.bytes / 1024 / 1024) / fs.fragments avg_fragment_mb,
       fs.fragments,
       t.status,
       t.contents,
       t.logging,
       t.extent_management,
       t.allocation_type,
       t.force_logging,
       t.segment_space_management,
       t.def_tab_compression,
       t.retention,
       t.bigfile
  FROM dba_tablespaces t,
       (SELECT tablespace_name,
               SUM(bytes) bytes,
               MIN(min_fragment) min_fragment,
               MAX(max_fragment) max_fragment,
               SUM(fragments) fragments
          FROM (SELECT tablespace_name,
                       SUM(bytes) bytes,
                       MIN(bytes) min_fragment,
                       MAX(bytes) max_fragment,
                       COUNT(*) fragments
                  FROM dba_free_space
                 GROUP BY tablespace_name
                UNION ALL
                SELECT tablespace_name,
                       SUM(bytes) bytes,
                       MIN(bytes) min_fragment,
                       MAX(bytes) max_fragment,
                       COUNT(*) fragments
                  FROM dba_undo_extents
                 WHERE status = 'EXPIRED'
                 GROUP BY tablespace_name)
         GROUP BY tablespace_name) fs,
       (SELECT tablespace_name, SUM(user_bytes) user_bytes
          FROM dba_data_files
         GROUP BY tablespace_name
        UNION ALL
        SELECT tablespace_name, SUM(user_bytes) user_bytes
          FROM dba_temp_files
         GROUP BY tablespace_name) df,
       (SELECT tablespace_name, SUM(bytes_used) bytes
          FROM gv$temp_extent_pool
         GROUP BY tablespace_name) u
 WHERE t.tablespace_name = df.tablespace_name(+)
   AND t.tablespace_name = fs.tablespace_name(+)
   AND t.tablespace_name = u.tablespace_name(+)
/

Script:收集数据库安全风险评估信息

以下脚本可以用于收集数据库安全风险评估信息:

REM list database vulnerability assessment info

set escape on;
set linesize 140 ;
spool db_vulnerability_assessment.log

Select role
  from dba_roles r
 where role not in ('CONNECT',
                    'RESOURCE',
                    'DBA',
                    'SELECT_CATALOG_ROLE',
                    'EXECUTE_CATALOG_ROLE',
                    'DELETE_CATALOG_ROLE',
                    'EXP_FULL_DATABASE',
                    'WM_ADMIN_ROLE',
                    'IMP_FULL_DATABASE',
                    'RECOVERY_CATALOG_OWNER',
                    'AQ_ADMINISTRATOR_ROLE',
                    'AQ_USER_ROLE',
                    'GLOBAL_AQ_USER_ROLE',
                    'OEM_MONITOR',
                    'HS_ADMIN_ROLE')
   and not exists
 (Select 1 from dba_role_privs p where p.granted_role = r.role)
/

select tp.grantee, tp.table_name
  from dba_tab_privs tp, dba_users u
 where tp.owner = 'SYS'
   and (tp.table_name like 'V_$%' or tp.table_name like 'G_V$')
   and tp.grantee = u.username
   and u.username not in ('SYS',
                          'SYSTEM',
                          'SYSMAN',
                          'EXFSYS',
                          'WMSYS',
                          'OLAPSYS',
                          'OUTLN',
                          'DBSNMP',
                          'ORDSYS',
                          'ORDPLUGINS',
                          'MDSYS',
                          'DMSYS',
                          'CTXSYS',
                          'AURORA$ORB$UNAUTHENTICATED',
                          'XDB',
                          'FLOWS_030000',
                          'FLOWS_FILES')
 order by 1, 2
/


select *
  from (select 'Hidden User in DBA_USERS' ddview, name
          from sys.user$
         where type# = 1
        minus
        select 'Hidden User in DBA_USERS', username from SYS.dba_users) q1
union all
select *
  from (select 'Hidden User in ALL_USERS', name
          from sys.user$
         where type# = 1
        minus
        select 'Hidden User in ALL_USERS', username from SYS.all_users) q2
/



select grantee, granted_role
  from dba_role_privs
 where grantee in (select role from dba_roles)
 order by grantee, granted_role
/

select grantee, privilege, admin_option
  from dba_sys_privs sp, dba_users u
 where sp.GRANTEE = u.username
   and grantee not in ('SYS', 'SYSTEM')
   and privilege in (select name
                       from sys.system_privilege_map
                      where 0 = 1
                         or name like '%ANY%'
                         or name like '%DATABASE%'
                         or name like '%DIRECTORY%'
                         or name like '%LIBRARY%'
                         or name like '%LINK%'
                         or name like '%PROFILE%'
                         or name like '%RESTRICTED%'
                         or name like 'SYS%'
                         or name like '%SYSTEM%'
                         or name like '%TABLESPACE%'
                         or name like '%USER%')
 order by 1
/

select role,
       (select count(*)
          from dba_role_privs rp
         where rp.granted_role = r.role) GRANT_COUNT
  from dba_roles r
 where r.role in ('DBA', 'CONNECT', 'RESOURCE')
 order by 1
/

select grantee, granted_role, admin_option
  from dba_role_privs rp, dba_users u
 where rp.grantee = u.username
   and grantee not in ('SYS', 'SYSTEM')
   and granted_role in (select role
                          from dba_roles
                         where 0 = 1
                            or role like '%CATALOG%'
                            or role like '%DATABASE%'
                            or role like '%DBA%')
 order by 1
/

select distinct profile, resource_name, actual_limit 
from (select P.Profile, p.resource_Name,
             decode(p.limit, 'UNLIMITED', '9999999999999999999', 
                   'NULL', null, to_number(p.limit)) limit,
             limit actual_limit
      from ( select profile, resource_name, 
                    decode(resource_name,  'IDLE_TIME', decode(limit, 'DEFAULT', 'UNLIMITED', limit),
                                           'FAILED_LOGIN_ATTEMPTS', decode(limit, 'DEFAULT', '10', limit),
                                           'PASSWORD_LIFE_TIME', decode(limit, 'DEFAULT', 'UNLIMITED', limit),
                                           'PASSWORD_REUSE_MAX', decode(limit, 'DEFAULT', 'UNLIMITED', limit),
                                           'PASSWORD_REUSE_TIME', decode(limit, 'DEFAULT', 'UNLIMITED', limit),
                                           'PASSWORD_GRACE_TIME', decode(limit, 'DEFAULT', 'UNLIMITED', limit),
                                'PASSWORD_VERIFY_FUNCTION', decode(limit, 'NULL', '0', null, 0, 'DEFAULT', 0, 1), limit) limit
              from   dba_profiles
              where resource_name in ('IDLE_TIME', 'FAILED_LOGIN_ATTEMPTS',
                                      'PASSWORD_LIFE_TIME', 'PASSWORD_REUSE_MAX',
                                      'PASSWORD_REUSE_TIME','PASSWORD_GRACE_TIME',
                                      'PASSWORD_VERIFY_FUNCTION')) p ) 
where 1=0 
or    (RESOURCE_NAME = 'IDLE_TIME' AND LIMIT > 60)
or    (RESOURCE_NAME = 'FAILED_LOGIN_ATTEMPTS' AND LIMIT > 3)
or    (RESOURCE_NAME = 'PASSWORD_LIFE_TIME' AND LIMIT > 90)
or    (RESOURCE_NAME = 'PASSWORD_REUSE_MAX' AND LIMIT > 20)
or    (RESOURCE_NAME = 'PASSWORD_REUSE_TIME' AND LIMIT > 180)
or    (RESOURCE_NAME = 'PASSWORD_GRACE_TIME' AND LIMIT > 3)
or    (RESOURCE_NAME = 'PASSWORD_VERIFY_FUNCTION' AND LIMIT = 0)
order by 1,2
/

Select s.owner, s.synonym_name, s.table_owner, s.table_name
  from sys.DBA_synonyms s
 where not exists (Select 'x'
          from sys.DBA_objects o
         where o.owner = s.table_owner
           and o.object_name = s.table_name)
   and db_link is null
   and s.owner <> 'PUBLIC'
 order by 1
/

Select distinct profile
  from dba_profiles
minus
Select distinct profile from dba_users
/

select table_name
  from dba_tab_privs
 where owner = 'SYS'
   and grantee = 'PUBLIC'
   and table_name in ('UTL_SMTP',
                      'UTL_TCP',
                      'UTL_HTTP',
                      'UTL_FILE',
                      'DBMS_RANDOM',
                      'DBMS_LOB',
                      'DBMS_SYS_SQL',
                      'DBMS_BACKUP_RESTORE',
                      'EMD_SYSTEM',
                      'DBMS_NAMESPACE',
                      'DBMS_SCHEDULER')
 order by 1
/ 
 

select username, password from dba_users order by 1
/


select tp.grantee, tp.table_name, tp.privilege
  from dba_tab_privs tp, dba_users u, dba_tables t
 where tp.owner = 'SYS'
   and tp.grantee = u.username
   and tp.owner = t.owner
   and tp.table_name = t.table_name
   and u.username not in ('SYS',
                          'SYSTEM',
                          'SYSMAN',
                          'EXFSYS',
                          'WMSYS',
                          'OLAPSYS',
                          'OUTLN',
                          'DBSNMP',
                          'ORDSYS',
                          'ORDPLUGINS',
                          'MDSYS',
                          'CTXSYS',
                          'AURORA$ORB$UNAUTHENTICATED',
                          'XDB',
                          'FLOWS_030000',
                          'FLOWS_FILES')
 order by 1, 2, 3
/
 
 select sp.grantee, sp.privilege
   from dba_sys_privs sp, dba_users u
  where sp.admin_option = 'YES'
    and u.username = sp.grantee
    and u.username not in ('SYS',
                           'SYSTEM',
                           'SYSMAN',
                           'EXFSYS',
                           'WMSYS',
                           'OLAPSYS',
                           'OUTLN',
                           'DBSNMP',
                           'ORDSYS',
                           'ORDPLUGINS',
                           'MDSYS',
                           'CTXSYS',
                           'AURORA$ORB$UNAUTHENTICATED',
                           'XDB',
                           'FLOWS_030000',
                           'FLOWS_FILES')
  order by 1, 2
/
  
  select p.grantee, p.owner, p.table_name, p.privilege
    from dba_tab_privs p, dba_users u
   where p.grantable = 'YES'
     and u.USERNAME = p.grantee
     and u.username not in ('SYS',
                            'SYSTEM',
                            'SYSMAN',
                            'EXFSYS',
                            'WMSYS',
                            'OLAPSYS',
                            'OUTLN',
                            'DBSNMP',
                            'ORDSYS',
                            'ORDPLUGINS',
                            'MDSYS',
                            'CTXSYS',
                            'AURORA$ORB$UNAUTHENTICATED',
                            'XDB',
                            'FLOWS_030000',
                            'FLOWS_FILES')
   order by 1, 2, 3, 4
/

select username
  from dba_users
 where account_status!='EXPIRED \& LOCKED'
 order by 1
/

Select s.synonym_name, s.table_owner, s.table_name
  from sys.DBA_synonyms s
 where not exists (Select 'x'
          from sys.DBA_objects o
         where o.owner = s.table_owner
           and o.object_name = s.table_name)
   and db_link is null
   and s.owner = 'PUBLIC'
 order by 1
/

select r.grantee, r.granted_role
  from dba_role_privs r, dba_users u
 where r.admin_option = 'YES'
   and u.username = r.grantee
   and u.username not in ('SYS',
                          'SYSTEM',
                          'SYSMAN',
                          'EXFSYS',
                          'WMSYS',
                          'OLAPSYS',
                          'OUTLN',
                          'DBSNMP',
                          'ORDSYS',
                          'ORDPLUGINS',
                          'MDSYS',
                          'CTXSYS',
                          'AURORA$ORB$UNAUTHENTICATED',
                          'XDB',
                          'FLOWS_030000',
                          'FLOWS_FILES')
 order by 1, 2
/


select username
  from dba_users
 where password = 'EXTERNAL'
 order by username
/

Script:Translate RDBA relative data block address

Script:Translate RDBA relative data block address

 

-- scripts/admin/rdba/rdba_to_file_block.sql
select trunc( to_number('&rdba','XXXXXXXX')
            / power(2,22) ) as rfile#
     , trunc(to_number('&rdba','XXXXXXXX')-
          trunc( to_number('&rdba','XXXXXXXX')
               / power(2,22))*power(2,22) ) as block#
  from dual
/

CREATE OR REPLACE FUNCTION getbfno (p_dba IN VARCHAR2)
   RETURN VARCHAR2
IS
   l_str   VARCHAR2 (255) DEFAULT NULL;
   l_fno   VARCHAR2 (15);
   l_bno   VARCHAR2 (15);
BEGIN
   l_fno :=
      DBMS_UTILITY.data_block_address_file (TO_NUMBER (LTRIM (p_dba, '0x'),
                                                       'xxxxxxxx'
                                                      )
                                           );
   l_bno :=
      DBMS_UTILITY.data_block_address_block (TO_NUMBER (LTRIM (p_dba, '0x'),
                                                        'xxxxxxxx'
                                                       )
                                            );
   l_str :=
         'datafile# is:'
      || l_fno
      || CHR (10)
      || 'datablock is:'
      || l_bno
      || CHR (10)
      || 'dump command:alter system dump datafile '
      || l_fno
      || ' block '
      || l_bno
      || ';';
   RETURN l_str;
END;
/

select getbfno('0x00400009') from dual;

脚本:格式化的V$SQL_SHARED_CURSOR报告

The function generates a summary report of the v$sql_shared_cursor view and additional diagnostic information depending on the reason code.
Counts all the versions that have ‘Y’ in any of the columns and if any have all ‘N’ too.

This script may be useful to diagnose ORA-600 [17059] errors

Running the Script
— Generate reports for all cursors with more than 100 versions using SQL_ID (10g and up)
select b.* from v$sqlarea a ,table(version_rpt(a.sql_id)) b where loaded_versions >=100;

— Generate reports for all cursors with more than 100 versions using HASH_VALUE
select b.* from v$sqlarea a ,table(version_rpt(null,a.hash_value)) b where loaded_versions>=100;

— Generate the report for cursor with sql_id cyzznbykb509s
select * from table(version_rpt(‘cyzznbykb509s’));

version_rpt3_12.sql

脚本:监控并行进程状态

脚本正文:

col username for a12
col "QC SID" for A6
col "SID" for A6
col "QC/Slave" for A8
col "Req. DOP" for 9999
col "Actual DOP" for 9999
col "Slaveset" for A8
col "Slave INST" for A9
col "QC INST" for A6
set pages 300 lines 300
col wait_event format a30
select
decode(px.qcinst_id,NULL,username, 
' - '||lower(substr(pp.SERVER_NAME,
length(pp.SERVER_NAME)-4,4) ) )"Username",
decode(px.qcinst_id,NULL, 'QC', '(Slave)') "QC/Slave" ,
to_char( px.server_set) "SlaveSet",
to_char(s.sid) "SID",
to_char(px.inst_id) "Slave INST",
decode(sw.state,'WAITING', 'WAIT', 'NOT WAIT' ) as STATE,     
case  sw.state WHEN 'WAITING' THEN substr(sw.event,1,30) ELSE NULL end as wait_event ,
decode(px.qcinst_id, NULL ,to_char(s.sid) ,px.qcsid) "QC SID",
to_char(px.qcinst_id) "QC INST",
px.req_degree "Req. DOP",
px.degree "Actual DOP"
from gv$px_session px,
gv$session s ,
gv$px_process pp,
gv$session_wait sw
where px.sid=s.sid (+)
and px.serial#=s.serial#(+)
and px.inst_id = s.inst_id(+)
and px.sid = pp.sid (+)
and px.serial#=pp.serial#(+)
and sw.sid = s.sid  
and sw.inst_id = s.inst_id   
order by
  decode(px.QCINST_ID,  NULL, px.INST_ID,  px.QCINST_ID),
  px.QCSID,
  decode(px.SERVER_GROUP, NULL, 0, px.SERVER_GROUP), 
  px.SERVER_SET, 
  px.INST_ID
/

set pages 300 lines 300
col wait_event format a30
select 
  sw.SID as RCVSID,
  decode(pp.server_name, 
         NULL, 'A QC', 
         pp.server_name) as RCVR,
  sw.inst_id as RCVRINST,
case  sw.state WHEN 'WAITING' THEN substr(sw.event,1,30) ELSE NULL end as wait_event ,
  decode(bitand(p1, 65535),
         65535, 'QC', 
         'P'||to_char(bitand(p1, 65535),'fm000')) as SNDR,
  bitand(p1, 16711680) - 65535 as SNDRINST,
  decode(bitand(p1, 65535),
         65535, ps.qcsid,
         (select 
            sid 
          from 
            gv$px_process 
          where 
            server_name = 'P'||to_char(bitand(sw.p1, 65535),'fm000') and
            inst_id = bitand(sw.p1, 16711680) - 65535)
        ) as SNDRSID,
   decode(sw.state,'WAITING', 'WAIT', 'NOT WAIT' ) as STATE     
from 
  gv$session_wait sw,
  gv$px_process pp,
  gv$px_session ps
where
  sw.sid = pp.sid (+) and
  sw.inst_id = pp.inst_id (+) and 
  sw.sid = ps.sid (+) and
  sw.inst_id = ps.inst_id (+) and 
  p1text  = 'sleeptime/senderid' and
  bitand(p1, 268435456) = 268435456
order by
  decode(ps.QCINST_ID,  NULL, ps.INST_ID,  ps.QCINST_ID),
  ps.QCSID,
  decode(ps.SERVER_GROUP, NULL, 0, ps.SERVER_GROUP), 
  ps.SERVER_SET, 
  ps.INST_ID
/



set pages 300 lines 300
col "Username" for a12
col "QC/Slave" for A8
col "Slaveset" for A8
col "Slave INST" for A9
col "QC SID" for A6
col "QC INST" for A6
col "operation_name" for A30
col "target" for A30

select
decode(px.qcinst_id,NULL,username, 
' - '||lower(substr(pp.SERVER_NAME,
length(pp.SERVER_NAME)-4,4) ) )"Username",
decode(px.qcinst_id,NULL, 'QC', '(Slave)') "QC/Slave" ,
to_char( px.server_set) "SlaveSet",
to_char(px.inst_id) "Slave INST",
substr(opname,1,30)  operation_name,
substr(target,1,30) target,
sofar,
totalwork,
units,
start_time,
timestamp,
decode(px.qcinst_id, NULL ,to_char(s.sid) ,px.qcsid) "QC SID",
to_char(px.qcinst_id) "QC INST"
from gv$px_session px,
gv$px_process pp,
gv$session_longops s 
where px.sid=s.sid 
and px.serial#=s.serial#
and px.inst_id = s.inst_id
and px.sid = pp.sid (+)
and px.serial#=pp.serial#(+)
order by
  decode(px.QCINST_ID,  NULL, px.INST_ID,  px.QCINST_ID),
  px.QCSID,
  decode(px.SERVER_GROUP, NULL, 0, px.SERVER_GROUP), 
  px.SERVER_SET, 
  px.INST_ID
/ 

示例输出:

Username     QC/Slave SlaveSet SID    Slave INS STATE    WAIT_EVENT                     QC SID QC INS Req. DOP Actual DOP
------------ -------- -------- ------ --------- -------- ------------------------------ ------ ------ -------- ---------- 
SCOTT      QC                923    1         WAIT     db file sequential read        923
 - p003      (Slave)  1        935    1         WAIT     PX Deq Credit: send blkd       923    1             4          4
 - p001      (Slave)  1        961    1         WAIT     PX Deq: Execution Msg          923    1             4          4
 - p002      (Slave)  1        1035   1         WAIT     PX Deq: Execution Msg          923    1             4          4
 - p004      (Slave)  1        977    1         WAIT     PX Deq Credit: send blkd       923    1             4          4
 - p006      (Slave)  2        609    1         WAIT     PX Deq: Execution Msg          923    1             4          4
 - p007      (Slave)  2        642    1         WAIT     PX Deq: Execution Msg          923    1             4          4
 - p008      (Slave)  2        970    1         WAIT     PX Deq: Execution Msg          923    1             4          4
 - p005      (Slave)  2        953    1         WAIT     PX Deq: Execution Msg          923    1             4          4
SCOTT      QC                1003   1         WAIT     SQL*Net message from client    1003
 - p015      (Slave)  1        608    1         WAIT     PX Deq Credit: send blkd       1003   1             8          8
 - p011      (Slave)  1        639    1         WAIT     PX Deq Credit: send blkd       1003   1             8          8
 - p012      (Slave)  1        1115   1         WAIT     PX Deq: Execution Msg          1003   1             8          8
 - p000      (Slave)  1        1253   1         WAIT     PX Deq Credit: send blkd       1003   1             8          8
 - p010      (Slave)  1        1420   1         WAIT     PX Deq: Execution Msg          1003   1             8          8
 - p009      (Slave)  1        1421   1         WAIT     PX Deq Credit: send blkd       1003   1             8          8
 - p014      (Slave)  1        1417   1         WAIT     PX Deq: Execution Msg          1003   1             8          8
 - p013      (Slave)  1        1180   1         WAIT     PX Deq: Execution Msg          1003   1             8          8
 - p020      (Slave)  2        1422   1         WAIT     PX Deq: Execution Msg          1003   1             8          8
 - p023      (Slave)  2        1423   1         WAIT     PX Deq: Execution Msg          1003   1             8          8
 - p018      (Slave)  2        1424   1         WAIT     PX Deq: Execution Msg          1003   1             8          8
 - p021      (Slave)  2        1426   1         WAIT     PX Deq: Execution Msg          1003   1             8          8
 - p019      (Slave)  2        1428   1         WAIT     PX Deq: Execution Msg          1003   1             8          8
 - p016      (Slave)  2        1429   1         WAIT     PX Deq: Execution Msg          1003   1             8          8
 - p022      (Slave)  2        1427   1         WAIT     PX Deq: Execution Msg          1003   1             8          8
 - p017      (Slave)  2        1425   1         WAIT     PX Deq: Execution Msg          1003   1             8          8 

脚本:监控数据库中的活跃用户及其运行的SQL

脚本正文:

set linesize 120 pagesize 66
col c1 for a9
col c1 heading "OS User"
col c2 for a9
col c2 heading "Oracle User"
col b1 for a9
col b1 heading "Unix PID"
col b2 for 9999 justify left
col b2 heading "SID"
col b3 for 99999 justify left
col b3 heading "SERIAL#"
col sql_text for a35
col event  for a30
break on b1 nodup on c1 nodup on c2 nodup on b2 nodup on b3 skip 3
select c.spid     b1,
       b.osuser   c1,
       b.username c2,
       b.sid      b2,
       b.serial#  b3,
       b.event,
       a.sql_text
  from v$sqltext a, v$session b, v$process c
 where a.address = b.sql_address
      --   and b.status     = 'ACTIVE' /* YOU CAN CHOOSE THIS OPTION ONLY TO SEE
      --                                  ACTVE TRANSACTION ON THAT MOMENT */
   and b.paddr = c.addr
   and a.hash_value = b.sql_hash_value
 order by c.spid, a.hash_value, a.piece
/      		  

REM TOP SESSION

with sessions as
 (select /*+ materialize */
   sess.inst_id,
   sess.sid,
   sess.serial#,
   sess.username,
   sess.module,
   sess.program,
   stat.value cpu_used_by_this_session,
   i.physical_reads,
   i.block_gets,
   sess.command,
   sess.status,
   sess.lockwait,
   decode(sess.sql_hash_value, 0, sess.prev_hash_value, sess.sql_hash_value) sql_hash_value,
   decode(sess.sql_address, '00', sess.prev_sql_addr, sess.sql_address) sql_address
    from gv$sesstat stat, gv$session sess, gv$sess_io i
   where stat.statistic# =
         (select statistic#
            from v$statname
           where name = 'CPU used by this session')
     and stat.sid = sess.sid
     and stat.inst_id = sess.inst_id
     and (stat.value > 100 or i.physical_reads > 100 or i.block_gets > 100)
     and sess.username is not null
     and i.sid = sess.sid
     and i.inst_id = sess.inst_id),
sqlarea as
 (select inst_id, sql_fulltext sql_text, hash_value, address from gv$sqlarea)
select *
  from sessions, sqlarea
 where sessions.inst_id = sqlarea.inst_id and sessions.sql_hash_value = sqlarea.hash_value and sessions.sql_address = sqlarea.address
 order by cpu_used_by_this_session desc
/

脚本:监控临时表空间使用率

针对字典管理临时表空间:

select (s.tot_used_blocks/f.total_blocks)*100 as "percent used" from 
(select sum(used_blocks) tot_used_blocks from v$sort_segment where tablespace_name='TEMP') s, 
(select sum(blocks) total_blocks from dba_data_files where tablespace_name='TEMP') f;

针对本地管理表空间:

select (s.tot_used_blocks/f.total_blocks)*100 as "percent used" from 
(select sum(used_blocks) tot_used_blocks from v$sort_segment where tablespace_name='TEMP') s, 
(select sum(blocks) total_blocks from dba_temp_files where tablespace_name='TEMP') f;

示例输出:

 select (s.tot_used_blocks/f.total_blocks)*100 as "percent used"
  2  from (select sum(used_blocks) tot_used_blocks from 
v$sort_segment where tablespace_name='TEMP') s, 
(select sum(blocks) total_blocks from dba_temp_files where tablespace_name='TEMP') f;

percent used
------------
           0

Script to show Active Distributed Transactions

该脚本可以用于显示活跃的分布式事务(Distributed Transactions from dblink),可以协助诊断dblink远程事务:

 

REM distri.sql
column origin format a13
column GTXID format a35
column LSESSION format a10
column s format a1
column waiting format a15
Select /*+ ORDERED */
    substr(s.ksusemnm,1,10)||'-'|| substr(s.ksusepid,1,10) "ORIGIN",
    substr(g.K2GTITID_ORA,1,35) "GTXID",
    substr(s.indx,1,4)||'.'|| substr(s.ksuseser,1,5) "LSESSION" ,
    substr(decode(bitand(ksuseidl,11),
               1,'ACTIVE',
               0, decode(bitand(ksuseflg,4096),0,'INACTIVE','CACHED'),
               2,'SNIPED',
               3,'SNIPED', 'KILLED'),1,1) "S",
    substr(event,1,10) "WAITING"
from  x$k2gte g, x$ktcxb t, x$ksuse s, v$session_wait w
-- where  g.K2GTeXCB =t.ktcxbxba <= use this if running in Oracle7
where  g.K2GTDXCB =t.ktcxbxba -- comment out if running in Oracle8 or later
   and g.K2GTDSES=t.ktcxbses
   and s.addr=g.K2GTDSES
   and w.sid=s.indx;

REM distri_details.sql
set headin off
select /*+ ORDERED */
'----------------------------------------'||'
Curent Time : '|| substr(to_char(sysdate,'dd-Mon-YYYY HH24.MI.SS'),1,22) ||'
'||'GTXID='||substr(g.K2GTITID_EXT,1,10) ||'
'||'Ascii GTXID='||g.K2GTITID_ORA ||'
'||'Branch= '||g.K2GTIBID ||'
Client Process ID is '|| substr(s.ksusepid,1,10)||'
running in machine : '||substr(s.ksusemnm,1,80)||'
  Local TX Id  ='||substr(t.KXIDUSN||'.'||t.kXIDSLT||'.'||t.kXIDSQN,1,10) ||'
  Local Session SID.SERIAL ='||substr(s.indx,1,4)||'.'|| s.ksuseser ||'
  is : '||decode(bitand(ksuseidl,11),1,'ACTIVE',0,
          decode(bitand(ksuseflg,4096),0,'INACTIVE','CACHED'),
          2,'SNIPED',3,'SNIPED', 'KILLED') ||
  ' and '|| substr(STATE,1,9)||
  ' since '|| to_char(SECONDS_IN_WAIT,'9999')||' seconds' ||'
  Wait Event is :'||'
  '||  substr(event,1,30)||' '||p1text||'='||p1
        ||','||p2text||'='||p2
        ||','||p3text||'='||p3    ||'
  Waited '||to_char(SEQ#,'99999')||' times '||'
  Server for this session:' ||decode(s.ksspatyp,1,'Dedicated Server',
                                          2,'Shared Server',3,
                                         'PSE','None') "Server"
from  x$k2gte g, x$ktcxb t, x$ksuse s, v$session_wait w
-- where  g.K2GTeXCB =t.ktcxbxba <= use this if running Oracle7
where  g.K2GTDXCB =t.ktcxbxba -- comment out if running Oracle8 or later
   and  g.K2GTDSES=t.ktcxbses
   and  s.addr=g.K2GTDSES
   and  w.sid=s.indx;
set headin on
-- end script

 

Gather DBMS_STATS Default parameter

What are the default parameter values ?

   select dbms_stats.get_param('cascade') from dual;
   select dbms_stats.get_param('degree') from dual;
   select dbms_stats.get_param('estimate_percent') from dual;
   select dbms_stats.get_param('method_opt') from dual;
   select dbms_stats.get_param('no_invalidate') from dual;
   select dbms_stats.get_param('granularity') from dual;


DEFAULT PARAMETER

DBMS_STATS.AUTO_CASCADE
NULL
DBMS_STATS.AUTO_SAMPLE_SIZE
FOR ALL COLUMNS SIZE AUTO
DBMS_STATS.AUTO_INVALIDATE
AUTO

Script:Datafile Report

以下脚本用于列出Oracle中数据文件的状况:

REM Datafile Report

set linesize 120 pagesize 1400;

SELECT t.tablespace_name,
       'Datafile' file_type,
       t.status tablespace_status,
       d.status file_status,
       ROUND((d.bytes - NVL(f.sum_bytes, 0)) / 1048576) used_mb,
       ROUND(NVL(f.sum_bytes, 0) / 1048576) free_mb,
       t.initial_extent,
       t.next_extent,
       t.min_extents,
       t.max_extents,
       t.pct_increase,
       d.file_name,
       d.file_id,
       d.autoextensible,
       d.maxblocks,
       d.maxbytes,
       nvl(d.increment_by, 0) increment_by,
       t.block_size
  FROM (SELECT tablespace_name, file_id, SUM(bytes) sum_bytes
          FROM DBA_FREE_SPACE
         GROUP BY tablespace_name, file_id) f,
       DBA_DATA_FILES d,
       DBA_TABLESPACES t
 WHERE t.tablespace_name = d.tablespace_name
   AND f.tablespace_name(+) = d.tablespace_name
   AND f.file_id(+) = d.file_id
 GROUP BY t.tablespace_name,
          d.file_name,
          d.file_id,
          t.initial_extent,
          t.next_extent,
          t.min_extents,
          t.max_extents,
          t.pct_increase,
          t.status,
          d.bytes,
          f.sum_bytes,
          d.status,
          d.AutoExtensible,
          d.maxblocks,
          d.maxbytes,
          d.increment_by,
          t.block_size
UNION ALL
SELECT h.tablespace_name,
       'Tempfile',
       ts.status,
       t.status,
       ROUND(SUM(NVL(p.bytes_used, 0)) / 1048576),
       ROUND(SUM((h.bytes_free + h.bytes_used) - NVL(p.bytes_used, 0)) /
             1048576),
       -1, -- initial extent
       -1, -- initial extent
       -1, -- min extents
       -1, -- max extents
       -1, -- pct increase
       t.file_name,
       t.file_id,
       t.autoextensible,
       t.maxblocks,
       t.maxbytes,
       nvl(t.increment_by, 0) increment_by,
       ts.block_size
  FROM sys.V_$TEMP_SPACE_HEADER h,
       sys.V_$TEMP_EXTENT_POOL  p,
       sys.DBA_TEMP_FILES       t,
       sys.dba_tablespaces      ts
 WHERE p.file_id(+) = h.file_id
   AND p.tablespace_name(+) = h.tablespace_name
   AND h.file_id = t.file_id
   AND h.tablespace_name = t.tablespace_name
   and ts.tablespace_name = h.tablespace_name
 GROUP BY h.tablespace_name,
          t.status,
          t.file_name,
          t.file_id,
          ts.status,
          t.autoextensible,
          t.maxblocks,
          t.maxbytes,
          t.increment_by,
          ts.block_size
 ORDER BY 1, 5 DESC
/

沪ICP备14014813号-2

沪公网安备 31010802001379号