perf-oci8.inc.php 24 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703
  1. <?php
  2. /*
  3. @version v5.20.17 31-Mar-2020
  4. @copyright (c) 2000-2013 John Lim (jlim#natsoft.com). All rights reserved.
  5. @copyright (c) 2014 Damien Regad, Mark Newnham and the ADOdb community
  6. Released under both BSD license and Lesser GPL library license.
  7. Whenever there is any discrepancy between the two licenses,
  8. the BSD license will take precedence. See License.txt.
  9. Set tabs to 4 for best viewing.
  10. Latest version is available at http://adodb.org/
  11. Library for basic performance monitoring and tuning
  12. */
  13. // security - hide paths
  14. if (!defined('ADODB_DIR')) die();
  15. class perf_oci8 extends ADODB_perf{
  16. var $noShowIxora = 15; // if the sql for suspicious sql is taking too long, then disable ixora
  17. var $tablesSQL = "select segment_name as \"tablename\", sum(bytes)/1024 as \"size_in_k\",tablespace_name as \"tablespace\",count(*) \"extents\" from sys.user_extents
  18. group by segment_name,tablespace_name";
  19. var $version;
  20. var $createTableSQL = "CREATE TABLE adodb_logsql (
  21. created date NOT NULL,
  22. sql0 varchar(250) NOT NULL,
  23. sql1 varchar(4000) NOT NULL,
  24. params varchar(4000),
  25. tracer varchar(4000),
  26. timer decimal(16,6) NOT NULL
  27. )";
  28. var $settings = array(
  29. 'Ratios',
  30. 'data cache hit ratio' => array('RATIOH',
  31. "select round((1-(phy.value / (cur.value + con.value)))*100,2)
  32. from v\$sysstat cur, v\$sysstat con, v\$sysstat phy
  33. where cur.name = 'db block gets' and
  34. con.name = 'consistent gets' and
  35. phy.name = 'physical reads'",
  36. '=WarnCacheRatio'),
  37. 'sql cache hit ratio' => array( 'RATIOH',
  38. 'select round(100*(sum(pins)-sum(reloads))/sum(pins),2) from v$librarycache',
  39. 'increase <i>shared_pool_size</i> if too ratio low'),
  40. 'datadict cache hit ratio' => array('RATIOH',
  41. "select
  42. round((1 - (sum(getmisses) / (sum(gets) +
  43. sum(getmisses))))*100,2)
  44. from v\$rowcache",
  45. 'increase <i>shared_pool_size</i> if too ratio low'),
  46. 'memory sort ratio' => array('RATIOH',
  47. "SELECT ROUND((100 * b.VALUE) /DECODE ((a.VALUE + b.VALUE),
  48. 0,1,(a.VALUE + b.VALUE)),2)
  49. FROM v\$sysstat a,
  50. v\$sysstat b
  51. WHERE a.name = 'sorts (disk)'
  52. AND b.name = 'sorts (memory)'",
  53. "% of memory sorts compared to disk sorts - should be over 95%"),
  54. 'IO',
  55. 'data reads' => array('IO',
  56. "select value from v\$sysstat where name='physical reads'"),
  57. 'data writes' => array('IO',
  58. "select value from v\$sysstat where name='physical writes'"),
  59. 'Data Cache',
  60. 'data cache buffers' => array( 'DATAC',
  61. "select a.value/b.value from v\$parameter a, v\$parameter b
  62. where a.name = 'db_cache_size' and b.name= 'db_block_size'",
  63. 'Number of cache buffers. Tune <i>db_cache_size</i> if the <i>data cache hit ratio</i> is too low.'),
  64. 'data cache blocksize' => array('DATAC',
  65. "select value from v\$parameter where name='db_block_size'",
  66. '' ),
  67. 'Memory Pools',
  68. 'Mem Max Target (11g+)' => array( 'DATAC',
  69. "select value from v\$parameter where name = 'memory_max_target'",
  70. 'The memory_max_size is the maximum value to which memory_target can be set.' ),
  71. 'Memory target (11g+)' => array( 'DATAC',
  72. "select value from v\$parameter where name = 'memory_target'",
  73. 'If memory_target is defined then SGA and PGA targets are consolidated into one memory_target.' ),
  74. 'SGA Max Size' => array( 'DATAC',
  75. "select nvl(value,0)/1024.0/1024 || 'M' from v\$parameter where name = 'sga_max_size'",
  76. 'The sga_max_size is the maximum value to which sga_target can be set.' ),
  77. 'SGA target' => array( 'DATAC',
  78. "select nvl(value,0)/1024.0/1024 || 'M' from v\$parameter where name = 'sga_target'",
  79. 'If sga_target is defined then data cache, shared, java and large pool size can be 0. This is because all these pools are consolidated into one sga_target.' ),
  80. 'PGA aggr target' => array( 'DATAC',
  81. "select nvl(value,0)/1024.0/1024 || 'M' from v\$parameter where name = 'pga_aggregate_target'",
  82. 'If pga_aggregate_target is defined then this is the maximum memory that can be allocated for cursor operations such as sorts, group by, joins, merges. When in doubt, set it to 20% of sga_target.' ),
  83. 'data cache size' => array('DATAC',
  84. "select value from v\$parameter where name = 'db_cache_size'",
  85. 'db_cache_size' ),
  86. 'shared pool size' => array('DATAC',
  87. "select value from v\$parameter where name = 'shared_pool_size'",
  88. 'shared_pool_size, which holds shared sql, stored procedures, dict cache and similar shared structs' ),
  89. 'java pool size' => array('DATAJ',
  90. "select value from v\$parameter where name = 'java_pool_size'",
  91. 'java_pool_size' ),
  92. 'large pool buffer size' => array('CACHE',
  93. "select value from v\$parameter where name='large_pool_size'",
  94. 'this pool is for large mem allocations (not because it is larger than shared pool), for MTS sessions, parallel queries, io buffers (large_pool_size) ' ),
  95. 'dynamic memory usage' => array('CACHE', "select '-' from dual", '=DynMemoryUsage'),
  96. 'Connections',
  97. 'current connections' => array('SESS',
  98. 'select count(*) from sys.v_$session where username is not null',
  99. ''),
  100. 'max connections' => array( 'SESS',
  101. "select value from v\$parameter where name='sessions'",
  102. ''),
  103. 'Memory Utilization',
  104. 'data cache utilization ratio' => array('RATIOU',
  105. "select round((1-bytes/sgasize)*100, 2)
  106. from (select sum(bytes) sgasize from sys.v_\$sgastat) s, sys.v_\$sgastat f
  107. where name = 'free memory' and pool = 'shared pool'",
  108. 'Percentage of data cache actually in use - should be over 85%'),
  109. 'shared pool utilization ratio' => array('RATIOU',
  110. 'select round((sga.bytes/case when p.value=0 then sga.bytes else to_number(p.value) end)*100,2)
  111. from v$sgastat sga, v$parameter p
  112. where sga.name = \'free memory\' and sga.pool = \'shared pool\'
  113. and p.name = \'shared_pool_size\'',
  114. 'Percentage of shared pool actually used - too low is bad, too high is worse'),
  115. 'large pool utilization ratio' => array('RATIOU',
  116. "select round((1-bytes/sgasize)*100, 2)
  117. from (select sum(bytes) sgasize from sys.v_\$sgastat) s, sys.v_\$sgastat f
  118. where name = 'free memory' and pool = 'large pool'",
  119. 'Percentage of large_pool actually in use - too low is bad, too high is worse'),
  120. 'sort buffer size' => array('CACHE',
  121. "select value from v\$parameter where name='sort_area_size'",
  122. 'max in-mem sort_area_size (per query), uses memory in pga' ),
  123. /*'pga usage at peak' => array('RATIOU',
  124. '=PGA','Mb utilization at peak transactions (requires Oracle 9i+)'),*/
  125. 'Transactions',
  126. 'rollback segments' => array('ROLLBACK',
  127. "select count(*) from sys.v_\$rollstat",
  128. ''),
  129. 'peak transactions' => array('ROLLBACK',
  130. "select max_utilization tx_hwm
  131. from sys.v_\$resource_limit
  132. where resource_name = 'transactions'",
  133. 'Taken from high-water-mark'),
  134. 'max transactions' => array('ROLLBACK',
  135. "select value from v\$parameter where name = 'transactions'",
  136. 'max transactions / rollback segments < 3.5 (or transactions_per_rollback_segment)'),
  137. 'Parameters',
  138. 'cursor sharing' => array('CURSOR',
  139. "select value from v\$parameter where name = 'cursor_sharing'",
  140. 'Cursor reuse strategy. Recommended is FORCE (8i+) or SIMILAR (9i+). See <a href=http://www.praetoriate.com/oracle_tips_cursor_sharing.htm>cursor_sharing</a>.'),
  141. /*
  142. 'cursor reuse' => array('CURSOR',
  143. "select count(*) from (select sql_text_wo_constants, count(*)
  144. from t1
  145. group by sql_text_wo_constants
  146. having count(*) > 100)",'These are sql statements that should be using bind variables'),*/
  147. 'index cache cost' => array('COST',
  148. "select value from v\$parameter where name = 'optimizer_index_caching'",
  149. '=WarnIndexCost'),
  150. 'random page cost' => array('COST',
  151. "select value from v\$parameter where name = 'optimizer_index_cost_adj'",
  152. '=WarnPageCost'),
  153. 'Waits',
  154. 'Recent wait events' => array('WAITS','select \'Top 5 events\' from dual','=TopRecentWaits'),
  155. // 'Historical wait SQL' => array('WAITS','select \'Last 2 days\' from dual','=TopHistoricalWaits'), -- requires AWR license
  156. 'Backup',
  157. 'Achivelog Mode' => array('BACKUP', 'select log_mode from v$database', '=LogMode'),
  158. 'DBID' => array('BACKUP','select dbid from v$database','Primary key of database, used for recovery with an RMAN Recovery Catalog'),
  159. 'Archive Log Dest' => array('BACKUP', "SELECT NVL(v1.value,v2.value)
  160. FROM v\$parameter v1, v\$parameter v2 WHERE v1.name='log_archive_dest' AND v2.name='log_archive_dest_10'", ''),
  161. 'Flashback Area' => array('BACKUP', "select nvl(value,'Flashback Area not used') from v\$parameter where name=lower('DB_RECOVERY_FILE_DEST')", 'Flashback area is a folder where all backup data and logs can be stored and managed by Oracle. If Error: message displayed, then it is not in use.'),
  162. 'Flashback Usage' => array('BACKUP', "select nvl('-','Flashback Area not used') from v\$parameter where name=lower('DB_RECOVERY_FILE_DEST')", '=FlashUsage', 'Flashback area usage.'),
  163. 'Control File Keep Time' => array('BACKUP', "select value from v\$parameter where name='control_file_record_keep_time'",'No of days to keep RMAN info in control file. Recommended set to x2 or x3 times the frequency of your full backup.'),
  164. 'Recent RMAN Jobs' => array('BACKUP', "select '-' from dual", "=RMAN"),
  165. // 'Control File Keep Time' => array('BACKUP', "select value from v\$parameter where name='control_file_record_keep_time'",'No of days to keep RMAN info in control file. I recommend it be set to x2 or x3 times the frequency of your full backup.'),
  166. 'Storage', 'Tablespaces' => array('TABLESPACE', "select '-' from dual", "=TableSpace"),
  167. false
  168. );
  169. function __construct(&$conn)
  170. {
  171. global $gSQLBlockRows;
  172. $gSQLBlockRows = 1000;
  173. $savelog = $conn->LogSQL(false);
  174. $this->version = $conn->ServerInfo();
  175. $conn->LogSQL($savelog);
  176. $this->conn = $conn;
  177. }
  178. function LogMode()
  179. {
  180. $mode = $this->conn->GetOne("select log_mode from v\$database");
  181. if ($mode == 'ARCHIVELOG') return 'To turn off archivelog:<br>
  182. <pre><font size=-2>
  183. SQLPLUS> connect sys as sysdba;
  184. SQLPLUS> shutdown immediate;
  185. SQLPLUS> startup mount exclusive;
  186. SQLPLUS> alter database noarchivelog;
  187. SQLPLUS> alter database open;
  188. </font></pre>';
  189. return 'To turn on archivelog:<br>
  190. <pre><font size=-2>
  191. SQLPLUS> connect sys as sysdba;
  192. SQLPLUS> shutdown immediate;
  193. SQLPLUS> startup mount exclusive;
  194. SQLPLUS> alter database archivelog;
  195. SQLPLUS> archive log start;
  196. SQLPLUS> alter database open;
  197. </font></pre>';
  198. }
  199. function TopRecentWaits()
  200. {
  201. $rs = $this->conn->Execute("select * from (
  202. select event, round(100*time_waited/(select sum(time_waited) from v\$system_event where wait_class <> 'Idle'),1) \"% Wait\",
  203. total_waits,time_waited, average_wait,wait_class from v\$system_event where wait_class <> 'Idle' order by 2 desc
  204. ) where rownum <=5");
  205. $ret = rs2html($rs,false,false,false,false);
  206. return "&nbsp;<p>".$ret."&nbsp;</p>";
  207. }
  208. function TopHistoricalWaits()
  209. {
  210. $days = 2;
  211. $rs = $this->conn->Execute("select * from ( SELECT
  212. b.wait_class,B.NAME,
  213. round(sum(wait_time+TIME_WAITED)/1000000) waitsecs,
  214. parsing_schema_name,
  215. C.SQL_TEXT, a.sql_id
  216. FROM V\$ACTIVE_SESSION_HISTORY A
  217. join V\$EVENT_NAME B on A.EVENT# = B.EVENT#
  218. join V\$SQLAREA C on A.SQL_ID = C.SQL_ID
  219. WHERE A.SAMPLE_TIME BETWEEN sysdate-$days and sysdate
  220. and parsing_schema_name not in ('SYS','SYSMAN','DBSNMP','SYSTEM')
  221. GROUP BY b.wait_class,parsing_schema_name,C.SQL_TEXT, B.NAME,A.sql_id
  222. order by 3 desc) where rownum <=10");
  223. $ret = rs2html($rs,false,false,false,false);
  224. return "&nbsp;<p>".$ret."&nbsp;</p>";
  225. }
  226. function TableSpace()
  227. {
  228. $rs = $this->conn->Execute(
  229. "select tablespace_name,round(sum(bytes)/1024/1024) as Used_MB,round(sum(maxbytes)/1024/1024) as Max_MB, round(sum(bytes)/sum(maxbytes),4) * 100 as PCT
  230. from dba_data_files
  231. group by tablespace_name order by 2 desc");
  232. $ret = "<p><b>Tablespace</b>".rs2html($rs,false,false,false,false);
  233. $rs = $this->conn->Execute("select * from dba_data_files order by tablespace_name, 1");
  234. $ret .= "<p><b>Datafile</b>".rs2html($rs,false,false,false,false);
  235. return "&nbsp;<p>".$ret."&nbsp;</p>";
  236. }
  237. function RMAN()
  238. {
  239. $rs = $this->conn->Execute("select * from (select start_time, end_time, operation, status, mbytes_processed, output_device_type
  240. from V\$RMAN_STATUS order by start_time desc) where rownum <=10");
  241. $ret = rs2html($rs,false,false,false,false);
  242. return "&nbsp;<p>".$ret."&nbsp;</p>";
  243. }
  244. function DynMemoryUsage()
  245. {
  246. if (@$this->version['version'] >= 11) {
  247. $rs = $this->conn->Execute("select component, current_size/1024./1024 as \"CurrSize (M)\" from V\$MEMORY_DYNAMIC_COMPONENTS");
  248. } else
  249. $rs = $this->conn->Execute("select name, round(bytes/1024./1024,2) as \"CurrSize (M)\" from V\$sgainfo");
  250. $ret = rs2html($rs,false,false,false,false);
  251. return "&nbsp;<p>".$ret."&nbsp;</p>";
  252. }
  253. function FlashUsage()
  254. {
  255. $rs = $this->conn->Execute("select * from V\$FLASH_RECOVERY_AREA_USAGE");
  256. $ret = rs2html($rs,false,false,false,false);
  257. return "&nbsp;<p>".$ret."&nbsp;</p>";
  258. }
  259. function WarnPageCost($val)
  260. {
  261. if ($val == 100 && $this->version['version'] < 10) $s = '<font color=red><b>Too High</b>. </font>';
  262. else $s = '';
  263. return $s.'Recommended is 20-50 for TP, and 50 for data warehouses. Default is 100. See <a href=http://www.dba-oracle.com/oracle_tips_cost_adj.htm>optimizer_index_cost_adj</a>. ';
  264. }
  265. function WarnIndexCost($val)
  266. {
  267. if ($val == 0 && $this->version['version'] < 10) $s = '<font color=red><b>Too Low</b>. </font>';
  268. else $s = '';
  269. return $s.'Percentage of indexed data blocks expected in the cache.
  270. Recommended is 20 (fast disk array) to 30 (slower hard disks). Default is 0.
  271. See <a href=http://www.dba-oracle.com/oracle_tips_cbo_part1.htm>optimizer_index_caching</a>.';
  272. }
  273. function PGA()
  274. {
  275. //if ($this->version['version'] < 9) return 'Oracle 9i or later required';
  276. }
  277. function PGA_Advice()
  278. {
  279. $t = "<h3>PGA Advice Estimate</h3>";
  280. if ($this->version['version'] < 9) return $t.'Oracle 9i or later required';
  281. $rs = $this->conn->Execute('select a.MB,
  282. case when a.targ = 1 then \'<<= Current \'
  283. when a.targ < 1 or a.pct <= b.pct then null
  284. else
  285. \'- BETTER than Current by \'||round(a.pct/b.pct*100-100,2)||\'%\' end as "Percent Improved",
  286. a.targ as "PGA Size Factor",a.pct "% Perf"
  287. from
  288. (select round(pga_target_for_estimate/1024.0/1024.0,0) MB,
  289. pga_target_factor targ,estd_pga_cache_hit_percentage pct,rownum as r
  290. from v$pga_target_advice) a left join
  291. (select round(pga_target_for_estimate/1024.0/1024.0,0) MB,
  292. pga_target_factor targ,estd_pga_cache_hit_percentage pct,rownum as r
  293. from v$pga_target_advice) b on
  294. a.r = b.r+1 where
  295. b.pct < 100');
  296. if (!$rs) return $t."Only in 9i or later";
  297. // $rs->Close();
  298. if ($rs->EOF) return $t."PGA could be too big";
  299. return $t.rs2html($rs,false,false,true,false);
  300. }
  301. function Explain($sql,$partial=false)
  302. {
  303. $savelog = $this->conn->LogSQL(false);
  304. $rs = $this->conn->SelectLimit("select ID FROM PLAN_TABLE");
  305. if (!$rs) {
  306. echo "<p><b>Missing PLAN_TABLE</b></p>
  307. <pre>
  308. CREATE TABLE PLAN_TABLE (
  309. STATEMENT_ID VARCHAR2(30),
  310. TIMESTAMP DATE,
  311. REMARKS VARCHAR2(80),
  312. OPERATION VARCHAR2(30),
  313. OPTIONS VARCHAR2(30),
  314. OBJECT_NODE VARCHAR2(128),
  315. OBJECT_OWNER VARCHAR2(30),
  316. OBJECT_NAME VARCHAR2(30),
  317. OBJECT_INSTANCE NUMBER(38),
  318. OBJECT_TYPE VARCHAR2(30),
  319. OPTIMIZER VARCHAR2(255),
  320. SEARCH_COLUMNS NUMBER,
  321. ID NUMBER(38),
  322. PARENT_ID NUMBER(38),
  323. POSITION NUMBER(38),
  324. COST NUMBER(38),
  325. CARDINALITY NUMBER(38),
  326. BYTES NUMBER(38),
  327. OTHER_TAG VARCHAR2(255),
  328. PARTITION_START VARCHAR2(255),
  329. PARTITION_STOP VARCHAR2(255),
  330. PARTITION_ID NUMBER(38),
  331. OTHER LONG,
  332. DISTRIBUTION VARCHAR2(30)
  333. );
  334. </pre>";
  335. return false;
  336. }
  337. $rs->Close();
  338. // $this->conn->debug=1;
  339. if ($partial) {
  340. $sqlq = $this->conn->qstr($sql.'%');
  341. $arr = $this->conn->GetArray("select distinct sql1 from adodb_logsql where sql1 like $sqlq");
  342. if ($arr) {
  343. foreach($arr as $row) {
  344. $sql = reset($row);
  345. if (crc32($sql) == $partial) break;
  346. }
  347. }
  348. }
  349. $s = "<p><b>Explain</b>: ".htmlspecialchars($sql)."</p>";
  350. $this->conn->BeginTrans();
  351. $id = "ADODB ".microtime();
  352. $rs = $this->conn->Execute("EXPLAIN PLAN SET STATEMENT_ID='$id' FOR $sql");
  353. $m = $this->conn->ErrorMsg();
  354. if ($m) {
  355. $this->conn->RollbackTrans();
  356. $this->conn->LogSQL($savelog);
  357. $s .= "<p>$m</p>";
  358. return $s;
  359. }
  360. $rs = $this->conn->Execute("
  361. select
  362. '<pre>'||lpad('--', (level-1)*2,'-') || trim(operation) || ' ' || trim(options)||'</pre>' as Operation,
  363. object_name,COST,CARDINALITY,bytes
  364. FROM plan_table
  365. START WITH id = 0 and STATEMENT_ID='$id'
  366. CONNECT BY prior id=parent_id and statement_id='$id'");
  367. $s .= rs2html($rs,false,false,false,false);
  368. $this->conn->RollbackTrans();
  369. $this->conn->LogSQL($savelog);
  370. $s .= $this->Tracer($sql,$partial);
  371. return $s;
  372. }
  373. function CheckMemory()
  374. {
  375. if ($this->version['version'] < 9) return 'Oracle 9i or later required';
  376. $rs = $this->conn->Execute("
  377. select a.name Buffer_Pool, b.size_for_estimate as cache_mb_estimate,
  378. case when b.size_factor=1 then
  379. '&lt;&lt;= Current'
  380. when a.estd_physical_read_factor-b.estd_physical_read_factor > 0.001 and b.estd_physical_read_factor<1 then
  381. '- BETTER than current by ' || round((1-b.estd_physical_read_factor)/b.estd_physical_read_factor*100,2) || '%'
  382. else ' ' end as RATING,
  383. b.estd_physical_read_factor \"Phys. Reads Factor\",
  384. round((a.estd_physical_read_factor-b.estd_physical_read_factor)/b.estd_physical_read_factor*100,2) as \"% Improve\"
  385. from (select size_for_estimate,size_factor,estd_physical_read_factor,rownum r,name from v\$db_cache_advice order by name,1) a ,
  386. (select size_for_estimate,size_factor,estd_physical_read_factor,rownum r,name from v\$db_cache_advice order by name,1) b
  387. where a.r = b.r-1 and a.name = b.name
  388. ");
  389. if (!$rs) return false;
  390. /*
  391. The v$db_cache_advice utility show the marginal changes in physical data block reads for different sizes of db_cache_size
  392. */
  393. $s = "<h3>Data Cache Advice Estimate</h3>";
  394. if ($rs->EOF) {
  395. $s .= "<p>Cache that is 50% of current size is still too big</p>";
  396. } else {
  397. $s .= "Ideal size of Data Cache is when %BETTER gets close to zero.";
  398. $s .= rs2html($rs,false,false,false,false);
  399. }
  400. return $s.$this->PGA_Advice();
  401. }
  402. /*
  403. Generate html for suspicious/expensive sql
  404. */
  405. function tohtml(&$rs,$type)
  406. {
  407. $o1 = $rs->FetchField(0);
  408. $o2 = $rs->FetchField(1);
  409. $o3 = $rs->FetchField(2);
  410. if ($rs->EOF) return '<p>None found</p>';
  411. $check = '';
  412. $sql = '';
  413. $s = "\n\n<table border=1 bgcolor=white><tr><td><b>".$o1->name.'</b></td><td><b>'.$o2->name.'</b></td><td><b>'.$o3->name.'</b></td></tr>';
  414. while (!$rs->EOF) {
  415. if ($check != $rs->fields[0].'::'.$rs->fields[1]) {
  416. if ($check) {
  417. $carr = explode('::',$check);
  418. $prefix = "<a href=\"?$type=1&sql=".rawurlencode($sql).'&x#explain">';
  419. $suffix = '</a>';
  420. if (strlen($prefix)>2000) {
  421. $prefix = '';
  422. $suffix = '';
  423. }
  424. $s .= "\n<tr><td align=right>".$carr[0].'</td><td align=right>'.$carr[1].'</td><td>'.$prefix.$sql.$suffix.'</td></tr>';
  425. }
  426. $sql = $rs->fields[2];
  427. $check = $rs->fields[0].'::'.$rs->fields[1];
  428. } else
  429. $sql .= $rs->fields[2];
  430. if (substr($sql,strlen($sql)-1) == "\0") $sql = substr($sql,0,strlen($sql)-1);
  431. $rs->MoveNext();
  432. }
  433. $rs->Close();
  434. $carr = explode('::',$check);
  435. $prefix = "<a target=".rand()." href=\"?&hidem=1&$type=1&sql=".rawurlencode($sql).'&x#explain">';
  436. $suffix = '</a>';
  437. if (strlen($prefix)>2000) {
  438. $prefix = '';
  439. $suffix = '';
  440. }
  441. $s .= "\n<tr><td align=right>".$carr[0].'</td><td align=right>'.$carr[1].'</td><td>'.$prefix.$sql.$suffix.'</td></tr>';
  442. return $s."</table>\n\n";
  443. }
  444. // code thanks to Ixora.
  445. // http://www.ixora.com.au/scripts/query_opt.htm
  446. // requires oracle 8.1.7 or later
  447. function SuspiciousSQL($numsql=10)
  448. {
  449. $sql = "
  450. select
  451. substr(to_char(s.pct, '99.00'), 2) || '%' load,
  452. s.executions executes,
  453. p.sql_text
  454. from
  455. (
  456. select
  457. address,
  458. buffer_gets,
  459. executions,
  460. pct,
  461. rank() over (order by buffer_gets desc) ranking
  462. from
  463. (
  464. select
  465. address,
  466. buffer_gets,
  467. executions,
  468. 100 * ratio_to_report(buffer_gets) over () pct
  469. from
  470. sys.v_\$sql
  471. where
  472. command_type != 47 and module != 'T.O.A.D.'
  473. )
  474. where
  475. buffer_gets > 50 * executions
  476. ) s,
  477. sys.v_\$sqltext p
  478. where
  479. s.ranking <= $numsql and
  480. p.address = s.address
  481. order by
  482. 1 desc, s.address, p.piece";
  483. global $ADODB_CACHE_MODE;
  484. if (isset($_GET['expsixora']) && isset($_GET['sql'])) {
  485. $partial = empty($_GET['part']);
  486. echo "<a name=explain></a>".$this->Explain($_GET['sql'],$partial)."\n";
  487. }
  488. if (isset($_GET['sql'])) return $this->_SuspiciousSQL($numsql);
  489. $s = '';
  490. $timer = time();
  491. $s .= $this->_SuspiciousSQL($numsql);
  492. $timer = time() - $timer;
  493. if ($timer > $this->noShowIxora) return $s;
  494. $s .= '<p>';
  495. $save = $ADODB_CACHE_MODE;
  496. $ADODB_CACHE_MODE = ADODB_FETCH_NUM;
  497. if ($this->conn->fetchMode !== false) $savem = $this->conn->SetFetchMode(false);
  498. $savelog = $this->conn->LogSQL(false);
  499. $rs = $this->conn->SelectLimit($sql);
  500. $this->conn->LogSQL($savelog);
  501. if (isset($savem)) $this->conn->SetFetchMode($savem);
  502. $ADODB_CACHE_MODE = $save;
  503. if ($rs) {
  504. $s .= "\n<h3>Ixora Suspicious SQL</h3>";
  505. $s .= $this->tohtml($rs,'expsixora');
  506. }
  507. return $s;
  508. }
  509. // code thanks to Ixora.
  510. // http://www.ixora.com.au/scripts/query_opt.htm
  511. // requires oracle 8.1.7 or later
  512. function ExpensiveSQL($numsql = 10)
  513. {
  514. $sql = "
  515. select
  516. substr(to_char(s.pct, '99.00'), 2) || '%' load,
  517. s.executions executes,
  518. p.sql_text
  519. from
  520. (
  521. select
  522. address,
  523. disk_reads,
  524. executions,
  525. pct,
  526. rank() over (order by disk_reads desc) ranking
  527. from
  528. (
  529. select
  530. address,
  531. disk_reads,
  532. executions,
  533. 100 * ratio_to_report(disk_reads) over () pct
  534. from
  535. sys.v_\$sql
  536. where
  537. command_type != 47 and module != 'T.O.A.D.'
  538. )
  539. where
  540. disk_reads > 50 * executions
  541. ) s,
  542. sys.v_\$sqltext p
  543. where
  544. s.ranking <= $numsql and
  545. p.address = s.address
  546. order by
  547. 1 desc, s.address, p.piece
  548. ";
  549. global $ADODB_CACHE_MODE;
  550. if (isset($_GET['expeixora']) && isset($_GET['sql'])) {
  551. $partial = empty($_GET['part']);
  552. echo "<a name=explain></a>".$this->Explain($_GET['sql'],$partial)."\n";
  553. }
  554. if (isset($_GET['sql'])) {
  555. $var = $this->_ExpensiveSQL($numsql);
  556. return $var;
  557. }
  558. $s = '';
  559. $timer = time();
  560. $s .= $this->_ExpensiveSQL($numsql);
  561. $timer = time() - $timer;
  562. if ($timer > $this->noShowIxora) return $s;
  563. $s .= '<p>';
  564. $save = $ADODB_CACHE_MODE;
  565. $ADODB_CACHE_MODE = ADODB_FETCH_NUM;
  566. if ($this->conn->fetchMode !== false) $savem = $this->conn->SetFetchMode(false);
  567. $savelog = $this->conn->LogSQL(false);
  568. $rs = $this->conn->Execute($sql);
  569. $this->conn->LogSQL($savelog);
  570. if (isset($savem)) $this->conn->SetFetchMode($savem);
  571. $ADODB_CACHE_MODE = $save;
  572. if ($rs) {
  573. $s .= "\n<h3>Ixora Expensive SQL</h3>";
  574. $s .= $this->tohtml($rs,'expeixora');
  575. }
  576. return $s;
  577. }
  578. function clearsql()
  579. {
  580. $perf_table = adodb_perf::table();
  581. // using the naive "delete from $perf_table where created<".$this->conn->sysTimeStamp will cause the table to lock, possibly
  582. // for a long time
  583. $sql =
  584. "DECLARE cnt pls_integer;
  585. BEGIN
  586. cnt := 0;
  587. FOR rec IN (SELECT ROWID AS rr FROM $perf_table WHERE created<SYSDATE)
  588. LOOP
  589. cnt := cnt + 1;
  590. DELETE FROM $perf_table WHERE ROWID=rec.rr;
  591. IF cnt = 1000 THEN
  592. COMMIT;
  593. cnt := 0;
  594. END IF;
  595. END LOOP;
  596. commit;
  597. END;";
  598. $ok = $this->conn->Execute($sql);
  599. }
  600. }