业务人员告诉我某系统磁盘IO持续高达300MB/s,系统平台为AIX,遂 topas 查看果然如此。
用下面脚本到Oracle数据库中看了一下:
?
SELECT Disk_Reads DiskReads, Executions, SQL_ID, SQL_Text SQLText,
SQL_FullText SQLFullText
FROM
(
SELECT Disk_Reads, Executions, SQL_ID, LTRIM(SQL_Text) SQL_Text,
SQL_FullText, Operation, Options,
Row_Number() OVER
(Partition By sql_text ORDER BY Disk_Reads * Executions DESC)
KeepHighSQL
FROM
(
SELECT Avg(Disk_Reads) OVER (Partition By sql_text) Disk_Reads,
Max(Executions) OVER (Partition By sql_text) Executions,
t.SQL_ID, sql_text, sql_fulltext, p.operation,p.options
FROM v$sql t, v$sql_plan p
WHERE t.hash_value=p.hash_value AND p.operation='TABLE ACCESS'
AND p.options='FULL' AND p.object_owner NOT IN ('SYS','SYSTEM')
AND t.Executions > 1
)
ORDER BY DISK_READS * EXECUTIONS DESC
)
WHERE KeepHighSQL = 1
AND rownum <=5;
这里当时没有保存记录,总之跟后来AWR收集的是一样的sql,如下所示。
?

可以看到第一个sql的物理读非常高。遂看了一下执行计划
?
SYS@zbdba>select * from table(dbms_xplan.display_cursor('54043712',null,'advanced'));
PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
HASH_VALUE 54043712, child number 0
------------------------------------
SELECT D.MODEL_ID, D.OBJ_ID, D.OBJ_TYPE, D.DATA_TYPE, D.DATA_DATE, D.DATA_FROM_DATE, D.DATA_TO_DATE,
D.DATA_FLAG FROM zbdba1 D, zbdba2 C WHERE D.MODEL_ID = C.MODEL_ID AND C.COLLECT_ID =
:COLLECT_ID AND D.DATA_DATE = :DATA_DATE AND D.DATA_TYPE = :DATA_TYPE AND D.VALUE_FLAG = 0
Plan hash value: 1780662521
-------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
-------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 9 (100)| | | |
| 1 | NESTED LOOPS | | 1 | 61 | 9 (0)| 00:00:01 | | |
| 2 | PARTITION RANGE SINGLE | | 1 | 51 | 8 (0)| 00:00:01 | KEY | KEY |
|* 3 | TABLE ACCESS FULL | zbdba1 | 1 | 51 | 8 (0)| 00:00:01 | KEY | KEY |
|* 4 | TABLE ACCESS BY INDEX ROWID| zbdba2 | 1 | 10 | 1 (0)| 00:00:01 | | |
|* 5 | INDEX UNIQUE SCAN | PK_zbdba2 | 1 | | 0 (0)| | | |
-------------------------------------------------------------------------------------------------------------------------
Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------
1 - SEL$1
3 - SEL$1 / D@SEL$1
4 - SEL$1 / C@SEL$1
5 - SEL$1 / C@SEL$1
Outline Data
-------------
/*+
BEGIN_OUTLINE_DATA
IGNORE_OPTIM_EMBEDDED_HINTS
OPTIMIZER_FEATURES_ENABLE('10.2.0.5')
ALL_ROWS
OUTLINE_LEAF(@"SEL$1")
FULL(@"SEL$1" "D"@"SEL$1")
INDEX_RS_ASC(@"SEL$1" "C"@"SEL$1" ("zbdba2"."MODEL_ID"))
LEADING(@"SEL$1" "D"@"SEL$1" "C"@"SEL$1")
USE_NL(@"SEL$1" "C"@"SEL$1")
END_OUTLINE_DATA
*/
Peeked Binds (identified by position):
--------------------------------------
1 - :COLLECT_ID (VARCHAR2(30), CSID=852): '70350'
2 - :DATA_DATE (DATE): 06/01/15 00:00:00
3 - :DATA_TYPE (VARCHAR2(30), CSID=852): '02'
Predicate Information (identified by operation id):
---------------------------