Chinaunix首页 | 论坛 | 博客
  • 博客访问: 3383391
  • 博文数量: 631
  • 博客积分: 10716
  • 博客等级: 上将
  • 技术积分: 8397
  • 用 户 组: 普通用户
  • 注册时间: 2008-04-01 22:35
文章分类

全部博文(631)

文章存档

2020年(2)

2019年(22)

2018年(4)

2017年(37)

2016年(22)

2015年(1)

2013年(12)

2012年(20)

2011年(19)

2010年(20)

2009年(282)

2008年(190)

分类: Oracle

2016-11-11 20:50:08

1、查询碎片程度高的表条件为什么block>100,因为一些很小的表,只有几行数据实际大小很小,但是block一次性分配就是5个(11g开始默认一次性分配1M的block大小了,见create table storged的NEXT参数),5个block相对于几行小表数据来说就相差太大了。
算法中/0.9是因为块的pfree一般为10%,所以一个块最多只用了90%,而且一行数据大于8KB时容易产生行链接,把一行分片存储,一样的一个块连90%都用不满、
AVG_ROW_LEN还是比较准的,比如个人实验情况一表6个字段,一个number,其他5个都是char(100)但是实际数据都是’1111111’7位,AVG_ROW_LEN显示依然为513SELECT TABLE_NAME,(BLOCKS*8192/1024/1024)"理论大小M",(NUM_ROWS*AVG_ROW_LEN/1024/1024/0.9)"实际大小M",
round((NUM_ROWS*AVG_ROW_LEN/1024/1024/0.9)/(BLOCKS*8192/1024/1024),3)*100||'%' "实际使用率%"
FROM USER_TABLES where blocks>100 and (NUM_ROWS*AVG_ROW_LEN/1024/1024/0.9)/(BLOCKS*8192/1024/1024)<0.3order by (NUM_ROWS*AVG_ROW_LEN/1024/1024/0.9)/(BLOCKS*8192/1024/1024) desc
2、查询索引碎片的比例select name,del_lf_rows,lf_rows, round(del_lf_rows/decode(lf_rows,0,1,lf_rows)*100,0)||'%' frag_pct from index_stats where round(del_lf_rows/decode(lf_rows,0,1,lf_rows)*100,0)>30;
3、集群因子clustering_factor高的表
集群因子越接近块数越好,接近行数则说明索引列的列值相等的行分布极度散列,可能不走索引扫描而走全表扫描select tab.table_name,tab.blocks,tab.num_rows,ind.index_name,ind.clustering_factor,round(nvl(ind.clustering_factor,1)/decode(tab.num_rows,0,1,tab.num_rows),3)*100||'%' "集群因子接近行数"from user_tables tab, user_indexes ind where tab.table_name=ind.table_nameand tab.blocks>100and nvl(ind.clustering_factor,1)/decode(tab.num_rows,0,1,tab.num_rows) between 0.35 and 3
4、根据sid查spid或根据spid查sidselect s.sid,s.serial#,s.LOGON_TIME,s.machine,p.spid,p.terminal from v$session s,v$process p where  s.paddr=p.addr and s.sid=XX or p.spid=YY
5、根据sid查看具体的sql语句select username,sql_text,machine,osuser from v$session a,v$sqltext_with_newlines b  where DECODE(a.sql_hash_value, 0, prev_hash_value, sql_hash_value)=b.hash_value and a.sid=&sid order by piece;
6、根据spid查询具体的sql语句select ss.SID, pr.SPID, ss.action, sa.SQL_FULLTEXT, ss.TERMINAL, ss.PROGRAM, ss.SERIAL#, ss.USERNAME, ss.STATUS, ss.OSUSER, ss.last_call_etfrom v$process pr, v$session ss, v$sqlarea sawhere ss.status='ACTIVE' and  ss.username is not null and pr.ADDR = ss.PADDRand ss.SQL_ADDRESS = sa.ADDRESS and ss.SQL_HASH_VALUE = sa.HASH_VALUEand pr.spid = XX
7、查看历史session_id的SQL来自哪个IP(当然这是个误解,都是历史的了,怎么可能还查到spid,其实查看trace文件名就可以知道spid,trace文件里面有sid和具体sql,如果trace存在incident,那trace就看不到具体sql,但是可以在incident文件中看到具体的sql,如DW_ora_17751.trc中17751就是spid,里面有这样的内容Incident 115 created, dump file: /XX/incident/incdir_115/DW_ora_17751_i115.trc,那么在DW_ora_17751_i115.trc就可以看到具体的sql语句)
DB_ora_29349.trc中出现如下*** SESSION ID:(5057.12807) 2016-10-26 14:45:52.726
通过表V$ACTIVE_SESSION_HISTORY来查,如下select a.sql_id,a.machine,a.* from V$ACTIVE_SESSION_HISTORY a where a.session_id=5057 and a.SESSION_SERIAL#=12807
查询上面的machine的IP是多少select s.sid,s.serial#,s.LOGON_TIME,s.machine,p.spid,p.terminal from v$session s,v$process p where  s.paddr=p.addr and s.machine='localhost'
通过上面的spid在oracle服务器上执行netstat -anp |grep spid即可[oracle@dwdb trace]$ netstat -anp |grep 17630tcp      210      0 192.168.64.228:11095        192.168.21.16:1521          ESTABLISHED 17630/oracleDBtcp        0      0 ::ffff:192.168.64.228:1521  ::ffff:192.168.64.220:59848 ESTABLISHED 17630/oracleDB
出现两个,说明来自220,连接了228数据库服务器,但是又通过228服务器的dblink去连接了16服务器
8、查询DML死锁会话sid,及引起死锁的堵塞者会话blocking_sessionselect sid, blocking_session, LOGON_TIME,sql_id,status,event,seconds_in_wait,state, BLOCKING_SESSION_STATUS from v$session where event like 'enq%' and state='WAITING' and BLOCKING_SESSION_STATUS='VALID'
BLOCKING_SESSION:Session identifier of the blocking session. This column is valid only if BLOCKING_SESSION_STATUS has the value VALID.
可以在v$session.LOGON_TIME上看到引起死锁的堵塞者会话比等待者要早
如果遇到RAC环境,一定要用gv$来查,并且执行alter system kill session 'sid,serial#'要到RAC对应的实例上去执行
或如下也可以select           (select username from v$session where sid=a.sid) blocker,         a.sid,         a.id1,         a.id2,       ' is blocking ' "IS BLOCKING",         (select username from v$session where sid=b.sid) blockee,             b.sid    from v$lock a, v$lock b   where a.block = 1     and b.request > 0     and a.id1 = b.id1     and a.id2 = b.id2;
9、查询DDL锁的sql
SELECT sid, event, p1raw, seconds_in_wait, wait_timeFROM sys.v_$session_waitWHERE event like 'library cache %'p1raw结果为'0000000453992440'
SELECT s.sid, kglpnmod "Mode", kglpnreq "Req", s.LOGON_TIMEFROM x$kglpn p, v$session sWHERE p.kglpnuse=s.saddrAND kglpnhdl='0000000453992440';结果为671 0 3 2011-11-1 12:00:00      525 2 0 2011-11-4 12:00:00
10、查询锁住的DDL对象select d.session_id,s.SERIAL#,d.name from dba_ddl_locks d,v$session s where d.owner='MKLMIGEM' and d.SESSION_ID=s.sid
11、查询当前正在执行的sqlSELECT s.sid,s.serial#,s.username,spid,v$sql.sql_id,machine,s.terminal,s.program,sql_textFROM v$process,v$session s,v$sql WHERE addr=paddr and s.sql_id=v$sql.sql_id AND sql_hash_value=hash_value
12、查询正在执行的SCHEDULER_JOBselect owner,job_name,sid,b.SERIAL#,b.username,spid from ALL_SCHEDULER_RUNNING_JOBS,v$session b,v$process  where session_id=sid and paddr=addr
13、查询正在执行的dbms_jobselect job,b.sid,b.SERIAL#,b.username,spid from DBA_JOBS_RUNNING a ,v$session b,v$process  where a.sid=b.sid and paddr=addr
14、查询一个会话session、process平均消耗多少内存,查看下面avg_used_M值select round(sum(pga_used_mem)/1024/1024,0) total_used_M, round(sum(pga_used_mem)/count(1)/1024/1024,0) avg_used_M,round(sum(pga_alloc_mem)/1024/1024,0) total_alloc_M, round(sum(pga_alloc_mem)/count(1)/1024/1024,0) avg_alloc_M from v$process;
15、TOP 10 执行次数排序select *from (select executions,username,PARSING_USER_ID,sql_id,sql_text     from v$sql,dba_users where user_id=PARSING_USER_ID order by executions desc)where rownum <=5;
16、TOP 10 物理读排序select *from (select DISK_READS,username,PARSING_USER_ID,sql_id,ELAPSED_TIME/1000000,sql_text     from v$sql,dba_users where user_id=PARSING_USER_ID order by DISK_READS desc)where rownum <=5;
(不要使用DISK_READS/ EXECUTIONS来排序,因为任何一条语句不管执行几次都会耗逻辑读和cpu,可能不会耗物理读(遇到LRU还会耗物理读,LRU规则是执行最不频繁的且最后一次执行时间距离现在最久远的就会被交互出buffer cache),是因为buffer cache存放的是数据块,去数据块里找行一定会消耗cpu和逻辑读的。Shared pool执行存放sql的解析结果,sql执行的时候只是去share pool中找hash value,如果有匹配的就是软解析。所以物理读逻辑读是在buffer cache中,软解析硬解析是在shared pool)
17、TOP 10 逻辑读排序select *from (select BUFFER_GETS,username,PARSING_USER_ID,sql_id,ELAPSED_TIME/1000000,sql_text     from v$sql,dba_users where user_id=PARSING_USER_ID order by BUFFER_GETS desc)where rownum <=5;
(不要使用BUFFER_GETS/ EXECUTIONS来排序,原因同16)
18、TOP 10 CPU排序select *from (select CPU_TIME/1000000,username,PARSING_USER_ID,sql_id,ELAPSED_TIME/1000000,sql_text     from v$sql,dba_users where user_id=PARSING_USER_ID order by CPU_TIME/1000000 desc)where rownum <=5;
(不要使用CPU_TIME/ EXECUTIONS来排序,原因同16)
19、查询等待事件select event,sum(decode(wait_time,0,0,1)) "之前等待次数", sum(decode(wait_time,0,1,0))  "正在等待次数",count(*) from v$session_wait  group by event order by 4 desc
20、查询当前正在消耗temp空间的sql语句Select distinct se.username,         se.sid,         su.blocks * to_number(rtrim(p.value))/1024/1024 as space_G,         su.tablespace,         sql_text    from V$TEMPSEG_USAGE su, v$parameter p, v$session se, v$sql s   where p.name = 'db_block_size'     and su.session_addr=se.saddr     and su.sqlhash=s.hash_value     and su.sqladdr=s.address
21、查询需要使用绑定变量的sql,10G以后推荐第二种(任何一条执行过的语句不管执行了几次在V$SQL中都只有一条记录,V$SQL中会记录执行了几次。两条一模一样的语句但是在不同的schema下执行的两种结果,如select * from t1.test在sye、system下执行则V$SQL只有一条记录(谁先执行则PARSING_SCHEMA_NAME显示谁)。如在sys和system都执行select * from test则V$SQL中有两条记录,两条记录的CHILD_NUMBER和PARSING_SCHEMA_NAME不一样。同一个用户下执行一样的语句如果大小写不一样或加了hint的话则会出现多个V$SQL记录,说明V$SQL对应的sql语句必须一模一样,如果alter system flush shared_pool(主站慎用)后再执行一样的语句,发现语句在V$SQL中的SQL_ID和HASH_VALUE与之前的一样,说明SQL_ID和HASH_VALUE应该是oracle自己的一套算法来的,只是根据sql语句内容来进行转换,sql语句不变则SQL_ID和HASH_VALUE也不变。)
第一种select * from (select count(*),sql_id, substr(sql_text,1,40)from v$sqlgroup by sql_id, substr(sql_text,1,40) having count(*) > 10 order by count(*) desc) where rownum<10
第二种count(1)>10表示类语句运行了10次以上select sql_id, FORCE_MATCHING_SIGNATURE, sql_textfrom v$SQLwhere FORCE_MATCHING_SIGNATURE in(select /*+ unnest */FORCE_MATCHING_SIGNATUREfrom v$sqlwhere FORCE_MATCHING_SIGNATURE > 0and FORCE_MATCHING_SIGNATURE != EXACT_MATCHING_SIGNATUREgroup by FORCE_MATCHING_SIGNATUREhaving count(1) > 10)
22、查看数据文件可用百分比select b.file_id,b.tablespace_name,b.file_name,b.AUTOEXTENSIBLE,ROUND(b.bytes/1024/1024/1024,2) ||'G'  "文件总容量",ROUND((b.bytes-sum(nvl(a.bytes,0)))/1024/1024/1024,2)||'G' "文件已用容量",ROUND(sum(nvl(a.bytes,0))/1024/1024/1024,2)||'G' "文件可用容量",ROUND(sum(nvl(a.bytes,0))/(b.bytes),2)*100||'%' "文件可用百分比"from dba_free_space a,dba_data_files bwhere a.file_id=b.file_idgroup by b.tablespace_name,b.file_name,b.file_id,b.bytes,b.AUTOEXTENSIBLEorder by b.tablespace_name;
23、查看数据文件可用百分比
select b.file_id,b.tablespace_name,b.file_name,b.AUTOEXTENSIBLE,ROUND(b.MAXBYTES/1024/1024/1024,2) ||'G'  "文件最大可用总容量",ROUND((b.bytes-sum(nvl(a.bytes,0)))/1024/1024/1024,2)||'G' "文件已用容量",ROUND(((b.MAXBYTES/1024/1024/1024)-((b.bytes-sum(nvl(a.bytes,0)))/1024/1024/1024))/(b.MAXBYTES/1024/1024/1024),2)*100||'%' "文件可用百分比"from dba_free_space a,dba_data_files bwhere a.file_id=b.file_id and b.file_id>4group by b.tablespace_name,b.file_name,b.file_id,b.bytes,b.AUTOEXTENSIBLE,b.MAXBYTESorder by b.tablespace_name;
24、查看表空间可用百分比select b.tablespace_name,a.total,b.free,round((b.free/a.total)*100) "% Free" from(select tablespace_name, sum(bytes/(1024*1024)) total from dba_data_files group by tablespace_name) a,(select tablespace_name, round(sum(bytes/(1024*1024))) free from dba_free_space group by tablespace_name) bWHERE a.tablespace_name = b.tablespace_nameorder by "% Free";
25、查看临时表空间使用率SELECT temp_used.tablespace_name,total,used,           total - used as "Free",           round(nvl(total-used, 0) * 100/total,3) "Free percent"      FROM (SELECT tablespace_name, SUM(bytes_used)/1024/1024 used              FROM GV_$TEMP_SPACE_HEADER             GROUP BY tablespace_name) temp_used,           (SELECT tablespace_name, SUM(bytes)/1024/1024 total              FROM dba_temp_files             GROUP BY tablespace_name) temp_total     WHERE temp_used.tablespace_name = temp_total.tablespace_name
26、查询undo表空间使用情况select tablespace_name,status,sum(bytes)/1024/1024 M from dba_undo_extents group by tablespace_name,status
27、查看ASM磁盘组使用率select name,round(total_mb/1024) "总容量",round(free_mb/1024) "空闲空间",round((free_mb/total_mb)*100) "可用空间比例" from gv$asm_diskgroup
28、统计每个用户使用表空间率SELECT c.owner                                  "用户",       a.tablespace_name                        "表空间名",       total/1024/1024                          "表空间大小M",       free/1024/1024                           "表空间剩余大小M",       ( total - free )/1024/1024               "表空间使用大小M",       Round(( total - free ) / total, 4) * 100 "表空间总计使用率   %",       c.schemas_use/1024/1024                  "用户使用表空间大小M",       round((schemas_use)/total,4)*100         "用户使用表空间率  %"
FROM   (SELECT tablespace_name,               Sum(bytes) free        FROM   DBA_FREE_SPACE        GROUP  BY tablespace_name) a,       (SELECT tablespace_name,               Sum(bytes) total        FROM   DBA_DATA_FILES        GROUP  BY tablespace_name) b,       (Select owner ,Tablespace_Name,                Sum(bytes) schemas_use        From Dba_Segments        Group By owner,Tablespace_Name) cWHERE  a.tablespace_name = b.tablespace_nameand a.tablespace_name =c.Tablespace_Nameorder by "用户","表空间名"
29、查看闪回区\快速恢复区空间使用率select sum(percent_space_used)||'%' "已使用空间比例" from V$RECOVERY_AREA_USAGE
30、查看僵死进程,分两种alter system kill session一执行则session即标记为KILLED,但是如果会话产生的数据量大则这个kill可能会比较久,在这个过程中session标记为KILLED但是这个会话还在V$session中,则V$session.paddr还在,所以可以匹配到V$process.addr,所以process进程还在;当kill过程执行完毕,则这个会话即不在V$session中
会话不在的select * from v$process where addr not in (select paddr from v$session) and pid not in (1,17,18)
会话还在的,但是会话标记为killedselect * from v$process where addr in (select paddr from v$session where status='KILLED')
再根据上述结果中的SPID通过如下命令可以查看到process的启动时间
ps auxw|head -1;ps auxw|grep SPID
31、查看行迁移或行链接的表select * From dba_tables where nvl(chain_cnt,0)<>0chain_cnt :Number of rows in the table that are chained from one data block to another or that have migrated to a new block, requiring a link to preserve the old rowid. This column is updated only after you analyze the table.
32、数据缓冲区命中率LECT a.VALUE+b.VALUE logical_reads, c.VALUE phys_reads,round(100*(1-c.value/(a.value+b.value)),2)||'%' hit_ratioFROM v$sysstat a,v$sysstat b,v$sysstat cWHERE a.NAME='db block gets'AND b.NAME='consistent gets'AND c.NAME='physical reads';或SELECT DB_BLOCK_GETS+CONSISTENT_GETS Logical_reads,PHYSICAL_READS phys_reads,round(100*(1-(PHYSICAL_READS/(DB_BLOCK_GETS+CONSISTENT_GETS))),2)||'%' "Hit Ratio"FROM V$BUFFER_POOL_STATISTICS WHERE NAME='DEFAULT';
33、共享池命中率以下两者应该都可以,看个人怎么理解select sum(pinhits)/sum(pins)*100 from v$librarycache;select sum(pinhits-reloads)/sum(pins)*100 from v$librarycache;
34、查询归档日志切换频率select sequence#,to_char(first_time,'yyyymmdd_hh24:mi:ss')firsttime,round((first_time-lag(first_time) over(order by first_time))*24*60,2) minutes fromv$log_history where first_time > sysdate - 3 order by first_time,minutes;
或select sequence#,to_char(first_time,'yyyy-mm-dd hh24:mi:ss') First_time,First_change#,switch_change# fromv$loghist where first_time>sysdate-3 order by 1;
35、查询lgwr进程写日志时每执行一次lgwr需要多少秒,在state是waiting的情况下,某个等待编号seq#下,seconds_in_wait达多少秒,就是lgwr进程写一次IO需要多少秒select event,state,seq#,seconds_in_wait,program from v$session where program like '%LGWR%'  and state='WAITING'
36、查询没有索引的表Select table_name from user_tables where table_name not in (select table_name from user_indexes)Select table_name from user_tables where table_name not in (select table_name from user_ind_columns)
37、查询7天的db timeTH sysstat AS (select sn.begin_interval_time begin_interval_time,         sn.end_interval_time end_interval_time,         ss.stat_name stat_name,         ss.value e_value,         lag(ss.value, 1) over(order by ss.snap_id) b_value    from dba_hist_sysstat ss, dba_hist_snapshot sn   where trunc(sn.begin_interval_time) >= sysdate - 7     and ss.snap_id = sn.snap_id     and ss.dbid = sn.dbid     and ss.instance_number = sn.instance_number     and ss.dbid = (select dbid from v$database)     and ss.instance_number = (select instance_number from v$instance)     and ss.stat_name = 'DB time')select to_char(BEGIN_INTERVAL_TIME, 'mm-dd hh24:mi') ||       to_char(END_INTERVAL_TIME, ' hh24:mi') date_time,       stat_name,       round((e_value - nvl(b_value, 0)) /             (extract(day from(end_interval_time - begin_interval_time)) * 24 * 60 * 60 +             extract(hour from(end_interval_time - begin_interval_time)) * 60 * 60 +             extract(minute from(end_interval_time - begin_interval_time)) * 60 +             extract(second from(end_interval_time - begin_interval_time))),             0) per_sec  from sysstat where (e_value - nvl(b_value, 0)) > 0   and nvl(b_value, 0) > 0
38、查询产生热块较多的对象x$bh .tch(Touch)表示访问次数越高,热点快竞争问题就存在SELECT e.owner, e.segment_name, e.segment_typeFROM dba_extents e,(SELECT *FROM (SELECT addr,ts#,file#,dbarfil,dbablk,tchFROM x$bhORDER BY tch DESC)WHERE ROWNUM < 11) bWHERE e.relative_fno = b.dbarfilAND e.block_id <= b.dbablkAND e.block_id + e.blocks > b.dbablk;
39、导出AWR报告的SQL语句select * from dba_hist_snapshot select * from table(dbms_workload_repository.awr_report_html(DBID, INSTANCE_NUMBER, startsnapid,endsnapid)) select * from TABLE(DBMS_WORKLOAD_REPOSITORY.awr_diff_report_html(DBID, INSTANCE_NUMBER, startsnapid,endsnapid, DBID, INSTANCE_NUMBER, startsnapid,endsnapid));
40、查询某个SQL的执行计划select a.hash_value,a.* from v$sql a where sql_id='0n4qfzbqfsjm3'
select * from table(dbms_xplan.display_cursor(v$sql.hash_value,0,'advanced'));
含顺序的select * from table(xplan.display_cursor('v$sql.sql_id',0,'advanced'));
不过要先创建xplan包,再执行SQL> CREATE PUBLIC SYNONYM XPLAN FOR SYS.XPLAN;SQL> grant execute on sys.xplan to public;
阅读(2419) | 评论(0) | 转发(0) |
给主人留下些什么吧!~~