├── LICENSE ├── README.md ├── mystats.sql └── mystats_pkg.sql /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2007-2020 Adrian Billington, www.oracle-developer.net 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # MYSTATS 2 | 3 | ## 1.0 Introduction 4 | This repository contains two versions of the MyStats utility. This reports on the resource usage between two snapshots in an active database session. It is a combination of Jonathan Lewis's SNAP_MY_STATS package and my own re-factoring of Tom Kyte's runstats utility (also available via www.oracle-developer.net or github.com/oracle-developer/runstats). I've also added some functionality and flexibility around the statistics reporting section. 5 | 6 | ## 2.0 Versions 7 | There are two versions provided. 8 | 9 | ### 2.1 mystats_pkg.sql 10 | This creates via a single PL/SQL package named MYSTATS_PKG. This uses invoker rights and dynamic SQL to workaround the common issue whereby developers are not given explicit grants on the required V$ views but have V$ access via a role. See the comments in the package header for more details and usage instructions. 11 | 12 | ### 2.2 mystats.sql 13 | This version is a standalone SQL*Plus script that runs MyStats from your SQLPATH without the need to create any database objects. This can be used if you are not able to create the PL/SQL package version of MyStats. See the comments in the script header for more details and usage instructions. 14 | 15 | ## 3.0 Version History 16 | ``` 17 | Version Date Description 18 | -------- --------------- ---------------------------------------------- 19 | 1.0 June 2007 Original version 20 | 1.1 January 2009 Added extended reporting options 21 | 2.0 October 2011 Re-design for standalone script version 22 | 2.01 November 2011 Bug-fix for numeric overflow 23 | 3.0 November 2015 Added extended snapshot and reporting options 24 | ``` 25 | 26 | ## 4.0 Credits 27 | 1. Credit is given to Jonathan Lewis for his original idea of taking two snapshots to identify resource consumption. 28 | 2. Thanks to Martin Bach for suggesting (and providing a prototype) for extended snapshot and reporting options. 29 | 30 | ## 5.0 License 31 | This project uses the MIT License. 32 | See https://github.com/oracle-developer/mystats/blob/master/LICENSE 33 | 34 | Adrian Billington 35 | (c) www.oracle-developer.net -------------------------------------------------------------------------------- /mystats.sql: -------------------------------------------------------------------------------- 1 | 2 | -- ---------------------------------------------------------------------------------------------- 3 | -- 4 | -- Utility: MyStats 5 | -- 6 | -- Script: mystats.sql 7 | -- 8 | -- Version: 3.0 9 | -- 10 | -- Author: Adrian Billington 11 | -- www.oracle-developer.net 12 | -- (c) oracle-developer.net 13 | -- 14 | -- Description: A free-standing SQL*Plus script to output the resource consumption of a unit or 15 | -- units of work as recorded in v$mystat, v$latch and v$sess_time_model. 16 | -- Based on Jonathan Lewis's SNAP_MY_STATS package but as a standalone script (i.e. 17 | -- no database objects need to be created). 18 | -- 19 | -- Key Differences 20 | -- --------------- 21 | -- 22 | -- a) This is a SQL*Plus script that requires no objects to be created; 23 | -- 24 | -- b) This includes latch statistics and makes use of Tom 25 | -- Kyte's RUNSTATS method for distinguising between stats 26 | -- and latches; 27 | -- 28 | -- c) This includes advanced reporting options (see Usage and Examples 29 | -- sections below for details); 30 | -- 31 | -- d) This includes a session time model report; 32 | -- 33 | -- e) This requires at least version 10.1 to run because it 34 | -- makes use of collection methods such as MEMBER OF and 35 | -- reports on V$SESS_TIME_MODEL statistics. 36 | -- 37 | -- Configuration: Edit the c_ms_rmcmd variable in the Constants section at the start of this 38 | -- script to use the correct file deletion command for your SQL*Plus client 39 | -- platform. It is defaulted to a Windows "del" command, so you will need to 40 | -- change it if you are using a Linux/Unix SQL*Plus client. 41 | -- 42 | -- Reason: To make this run in standalone mode, a couple of temporary files 43 | -- are written to your current directory. These files are automatically 44 | -- removed on completion of this script. 45 | -- 46 | -- Usage: @mystats start [optional statistics type(s)] 47 | -- ---- 48 | -- @mystats stop [optional reporting parameter] 49 | -- 50 | -- Optional statistics types format: 51 | -- 52 | -- Short Format Long Format Equivalent 53 | -- ----------------------- ---------------------- 54 | -- s=[csv] stattypes=[csv] 55 | -- 56 | -- Statistics types values for the csv list are as follows: 57 | -- 58 | -- Statistics Type Short Format Long Format Equivalent 59 | -- --------------- ------------ ---------------------- 60 | -- Statistic s statistic 61 | -- Latch l latch 62 | -- Time Model t time 63 | -- All (default) a all 64 | -- 65 | -- Optional reporting parameter formats: 66 | -- 67 | -- Short Format Long Format Equivalent 68 | -- ----------------------- ---------------------- 69 | -- t= threshold= 70 | -- l= like= 71 | -- n= names= 72 | -- r= regexp= 73 | -- 74 | -- Use double-quotes when the strings contain spaces, 75 | -- e.g. "option=value with space" 76 | -- 77 | -- Examples: 1. Output all statistics 78 | -- ------------------------------------------------------------- 79 | -- @mystats start 80 | -- ---- 81 | -- @mystats stop 82 | -- 83 | -- 2. Output statistics with delta values >= 1,000 84 | -- ------------------------------------------------------------- 85 | -- @mystats start 86 | -- ---- 87 | -- @mystats stop t=1000 88 | -- 89 | -- 3. Output statistics for "redo size" and "user commits" only 90 | -- ------------------------------------------------------------- 91 | -- @mystats start 92 | -- ---- 93 | -- @mystats stop "n=redo size, user commits" 94 | -- 95 | -- 4. Output statistics for those containing the word 'memory' 96 | -- ------------------------------------------------------------- 97 | -- @mystats start 98 | -- ---- 99 | -- @mystats stop l=memory 100 | -- 101 | -- 5. Output statistics for those with I/O, IO, i/o or io in the name 102 | -- ------------------------------------------------------------------ 103 | -- @mystats start 104 | -- ---- 105 | -- @mystats stop r=I/?O\s 106 | -- 107 | -- 6. Capture and output statistics and time model only 108 | -- ------------------------------------------------------------- 109 | -- @mystats start s=s,t 110 | -- ---- 111 | -- @mystats stop 112 | -- 113 | -- 7. Output statistics only for those containing 'parallel' 114 | -- ------------------------------------------------------------- 115 | -- @mystats start s=s 116 | -- ---- 117 | -- @mystats stop l=parallel 118 | -- 119 | -- Notes: 1. See http://www.jlcomp.demon.co.uk/snapshot.html for original 120 | -- version. 121 | -- 122 | -- 2. As described in Configuration above, this script writes and removes 123 | -- a couple of temporary files during execution. 124 | -- 125 | -- 3. A PL/SQL package version of MyStats (v3.0) is also available. 126 | -- 127 | -- 4. Thanks to Martin Bach for the idea to provide a regexp reporting filter 128 | -- option and some example code. 129 | -- 130 | -- Disclaimer: http://www.oracle-developer.net/disclaimer.php 131 | -- 132 | -- ---------------------------------------------------------------------------------------------- 133 | 134 | set define on autoprint off 135 | set serveroutput on format wrapped 136 | 137 | -- Constants... 138 | -- ----------------------------------------------------------------------- 139 | define c_ms_version = 3.0 140 | define c_ms_rmcmd = "del" --Windows 141 | --define c_ms_rmcmd = "rm" --Unix/Linux 142 | define c_ms_init = "_ms_init.sql" 143 | define c_ms_clear = "_ms_teardown.sql" 144 | 145 | 146 | -- Initialise default substitution variables 1 and 2... 147 | -- ----------------------------------------------------------------------- 148 | set termout off 149 | 150 | col 1 new_value 1 151 | col 2 new_value 2 152 | 153 | select null as "1" 154 | , null as "2" 155 | from dual 156 | where 1=2; 157 | 158 | 159 | -- Input parameters... 160 | -- ----------------------------------------------------------------------- 161 | define p_ms_snap = &1 162 | define p_ms_option = "&2" 163 | 164 | 165 | -- Initialisation section... 166 | -- ----------------------------------------------------------------------- 167 | column snap noprint new_value v_ms_snap 168 | column if_start noprint new_value v_ms_if_start 169 | column if_stop noprint new_value v_ms_if_stop 170 | 171 | select snap 172 | , decode(snap, 'start', '', '--') as if_start 173 | , decode(snap, 'stop', '', '--') as if_stop 174 | from ( 175 | select rtrim(lower('&p_ms_snap'),';') as snap 176 | from dual 177 | ); 178 | 179 | spool "&c_ms_init" replace 180 | prompt var bv_ms_&v_ms_snap clob; 181 | prompt var bv_ms_ela_&v_ms_snap number; 182 | prompt var bv_ms_cpu_&v_ms_snap number; 183 | spool off 184 | @"&c_ms_init" 185 | host &c_ms_rmcmd "&c_ms_init" 186 | 187 | 188 | -- Parse the options... 189 | -- ----------------------------------------------------------------------- 190 | column threshold noprint new_value v_ms_threshold 191 | column namelist noprint new_value v_ms_name_list 192 | column namelike noprint new_value v_ms_name_like 193 | column regexplike noprint new_value v_ms_name_regexp 194 | column stattypes noprint new_value v_ms_stattypes 195 | column ms_option noprint new_value v_ms_option 196 | column start_option noprint new_value v_ms_start_option 197 | column stop_option noprint new_value v_ms_stop_option 198 | 199 | select case 200 | when o in ('threshold','t') 201 | then 1 202 | when o in ('names','n') 203 | then 2 204 | when o in ('like','l') 205 | then 3 206 | when o in ('regex','r') 207 | then 4 208 | when o in ('stattype','s') 209 | then 5 210 | else 0 211 | end as ms_option 212 | , case 213 | when o in ('threshold','t') 214 | then to_number(v) 215 | else 0 216 | end as threshold 217 | , case 218 | when o in ('names','n') 219 | then '''' || regexp_replace(v, ' *, *', ''',''') || '''' 220 | else 'null' 221 | end as namelist 222 | , case 223 | when o in ('like','l') 224 | then '''%' || v || '%''' 225 | else 'null' 226 | end as namelike 227 | , case 228 | when o in ('regexp','r') 229 | then '''' || v || '''' 230 | else 'null' 231 | end as regexplike 232 | &v_ms_if_start , case 233 | &v_ms_if_start when o in ('stattype','s') 234 | &v_ms_if_start then regexp_replace(v, ' *, *', ',') 235 | &v_ms_if_start when o is null 236 | &v_ms_if_start then 'all' 237 | &v_ms_if_start end as stattypes 238 | &v_ms_if_start , p as start_option 239 | , p as stop_option 240 | from ( 241 | select trim(regexp_substr(lower('&p_ms_option'), '[^=]+')) as o 242 | , trim(regexp_substr('&p_ms_option', '[^=]+', 1, 2)) as v 243 | , '&p_ms_option' as p 244 | from dual 245 | ); 246 | 247 | 248 | -- Stattypes include/exclude section... 249 | -- ----------------------------------------------------------------------- 250 | column snap noprint 251 | column include_stats noprint new_value v_ms_include_statistics 252 | column include_latches noprint new_value v_ms_include_latches 253 | column include_time noprint new_value v_ms_include_time_model 254 | 255 | select snap 256 | &v_ms_if_start , case when regexp_like('&v_ms_stattypes', '(^|,)(s|statistic|a|all)(,|$)') then 'Y' else 'N' end as include_stats 257 | &v_ms_if_start , case when regexp_like('&v_ms_stattypes', '(^|,)(l|latch|a|all)(,|$)') then 'Y' else 'N' end as include_latches 258 | &v_ms_if_start , case when regexp_like('&v_ms_stattypes', '(^|,)(t|time|a|all)(,|$)') then 'Y' else 'N' end as include_time 259 | from ( 260 | select rtrim(lower('&p_ms_snap'),';') as snap 261 | from dual 262 | ); 263 | 264 | 265 | -- The utility... 266 | -- ----------------------------------------------------------------------- 267 | set termout on 268 | declare 269 | 270 | -- Run constants... 271 | -- ------------------------------------------------------------------------- 272 | c_snap1 constant pls_integer := 1; 273 | c_snap2 constant pls_integer := 2; 274 | 275 | -- Snapshots... 276 | -- ------------------------------------------------------------------------- 277 | type rt_snaps is record 278 | ( snap1 clob 279 | , snap2 clob ); 280 | 281 | g_snaps rt_snaps; 282 | 283 | -- Elapsed time calculation... 284 | -- ------------------------------------------------------------------------- 285 | type rt_time is record 286 | ( ela integer 287 | , cpu integer ); 288 | 289 | type aat_time is table of rt_time 290 | index by pls_integer; 291 | 292 | g_times aat_time; 293 | 294 | -- Utility info... 295 | -- ------------------------------------------------------------------------- 296 | procedure ms_options is 297 | begin 298 | dbms_output.put_line('- Statistics types : ' || nvl('&v_ms_start_option', 'all')); 299 | dbms_output.put_line('- Reporting filter : ' || nvl('&v_ms_stop_option', 'none')); 300 | end ms_options; 301 | 302 | procedure ms_info is 303 | begin 304 | dbms_output.put_line('- MyStats v&c_ms_version by Adrian Billington (http://www.oracle-developer.net)'); 305 | dbms_output.put_line('- Original version based on the SNAP_MY_STATS utility by Jonathan Lewis'); 306 | dbms_output.new_line(); 307 | end ms_info; 308 | 309 | -- Snapshot procedure... 310 | -- ------------------------------------------------------------------------- 311 | procedure ms_snap( p_stats in out clob ) is 312 | begin 313 | select dbms_xmlgen.getxml( 314 | q'[select 'STAT' as type 315 | , a.name 316 | , b.value 317 | from v$statname a 318 | , v$mystat b 319 | where a.statistic# = b.statistic# 320 | and '&v_ms_include_statistics' = 'Y' 321 | union all 322 | select 'LATCH' 323 | , name 324 | , gets 325 | from v$latch 326 | where '&v_ms_include_latches' = 'Y' 327 | union all 328 | select 'TIME' 329 | , stat_name 330 | , value 331 | from v$sess_time_model 332 | where sid = sys_context('userenv','sid') 333 | and '&v_ms_include_time_model' = 'Y']' 334 | ) into p_stats 335 | from dual; 336 | end ms_snap; 337 | 338 | -- Time snapshot... 339 | -- ------------------------------------------------------------------------- 340 | procedure ms_time( p_times in out nocopy aat_time, 341 | p_snap in pls_integer ) is 342 | begin 343 | p_times(p_snap).ela := dbms_utility.get_time; 344 | p_times(p_snap).cpu := dbms_utility.get_cpu_time; 345 | end ms_time; 346 | 347 | -- Reporting procedure... 348 | -- ------------------------------------------------------------------------- 349 | procedure ms_report( p_times in aat_time, 350 | p_snaps in rt_snaps ) is 351 | 352 | procedure div( p_divider in varchar2 default '-', 353 | p_width in pls_integer default 90 ) is 354 | begin 355 | dbms_output.put_line( rpad(p_divider, p_width, p_divider) ); 356 | end div; 357 | 358 | procedure nl( p_newlines in pls_integer default 1 ) is 359 | begin 360 | for i in 1 .. p_newlines loop 361 | dbms_output.put_line(null); 362 | end loop; 363 | end nl; 364 | 365 | procedure sh ( p_title in varchar2, 366 | p_header in boolean default true ) is 367 | begin 368 | nl(2); 369 | div; 370 | dbms_output.put_line(p_title); 371 | div; 372 | if p_header then 373 | nl; 374 | dbms_output.put_line('Type ' || rpad('Statistic Name',64) || lpad('Value',18)); 375 | dbms_output.put_line(rpad('-',6,'-') || ' ' || rpad('-',64,'-') || ' ' || lpad('-',16,'-')); 376 | end if; 377 | end sh; 378 | 379 | begin 380 | 381 | -- Report header... 382 | -- ---------------- 383 | nl; 384 | div('='); 385 | dbms_output.put_line('MyStats report : ' || to_char(sysdate,'dd-MON-YYYY hh24:mi:ss')); 386 | div('='); 387 | 388 | 389 | -- Summary timings... 390 | -- ------------------ 391 | sh('1. Summary Timings'); 392 | dbms_output.put_line(rpad('TIMER', 8) || rpad('snapshot interval (seconds)', 64) || 393 | lpad(to_char(round((p_times(c_snap2).ela-p_times(c_snap1).ela)/100,2), 'fm999,990.00'),18)); 394 | dbms_output.put_line(rpad('TIMER', 8) || rpad('CPU time used (seconds)', 64) || 395 | lpad(to_char(round((p_times(c_snap2).cpu-p_times(c_snap1).cpu)/100,2), 'fm999,990.00'),18)); 396 | 397 | 398 | -- Output the sorted stats... 399 | -- -------------------------- 400 | sh('2. Statistics Report'); 401 | 402 | for r in ( with ms_start as ( 403 | select extractValue(xs.object_value, '/ROW/TYPE') as type 404 | , extractValue(xs.object_value, '/ROW/NAME') as name 405 | , to_number(extractValue(xs.object_value, '/ROW/VALUE')) as value 406 | from table(xmlsequence(extract(xmltype(p_snaps.snap1), '/ROWSET/ROW'))) xs 407 | ) 408 | , ms_stop as ( 409 | select extractValue(xs.object_value, '/ROW/TYPE') as type 410 | , extractValue(xs.object_value, '/ROW/NAME') as name 411 | , to_number(extractValue(xs.object_value, '/ROW/VALUE')) as value 412 | from table(xmlsequence(extract(xmltype(p_snaps.snap2), '/ROWSET/ROW'))) xs 413 | ) 414 | , ms_diffs as ( 415 | select type 416 | , name 417 | , ms_stop.value - ms_start.value as diff 418 | from ms_start 419 | inner join 420 | ms_stop 421 | using (type, name) 422 | ) 423 | select type, name, diff 424 | from ms_diffs 425 | where (&v_ms_option = 1 and abs(diff) >= &v_ms_threshold) 426 | or (&v_ms_option = 2 and name in (&v_ms_name_list)) 427 | or (&v_ms_option = 3 and name like &v_ms_name_like) 428 | or (&v_ms_option = 4 and regexp_like(name, &v_ms_name_regexp, 'i')) 429 | or &v_ms_option = 0 430 | order by 431 | abs(diff) ) 432 | loop 433 | dbms_output.put_line(rpad(r.type,8) || rpad(r.name,64) || 434 | lpad(to_char(r.diff,'999,999,999,999'),18)); 435 | end loop; 436 | 437 | -- Options... 438 | -- ---------- 439 | sh('3. Options Used', false); 440 | ms_options; 441 | 442 | -- About... 443 | -- ------- 444 | sh('4. About', false); 445 | ms_info; 446 | 447 | nl; 448 | div('='); 449 | dbms_output.put_line('End of report'); 450 | div('='); 451 | 452 | end ms_report; 453 | 454 | begin 455 | 456 | -- Runtime program... 457 | -- ------------------------------------------------------------------------- 458 | if '&v_ms_snap' = 'start' then 459 | ms_snap(g_snaps.snap1); 460 | :bv_ms_start := g_snaps.snap1; 461 | ms_time(g_times, c_snap1); 462 | :bv_ms_ela_start := g_times(c_snap1).ela; 463 | :bv_ms_cpu_start := g_times(c_snap1).cpu; 464 | elsif '&v_ms_snap' = 'stop' then 465 | ms_time(g_times, c_snap2); 466 | g_snaps.snap1 := :bv_ms_start; 467 | g_times(c_snap1).ela := :bv_ms_ela_start; 468 | g_times(c_snap1).cpu := :bv_ms_cpu_start; 469 | ms_snap(g_snaps.snap2); 470 | ms_report(g_times, g_snaps); 471 | else 472 | raise_application_error( -20000, 473 | 'Incorrect parameter at position 1 '|| 474 | '[used="&v_ms_snap"; valid="start" or "stop"]', 475 | false ); 476 | end if; 477 | 478 | end; 479 | / 480 | 481 | -- Teardown section... 482 | -- ----------------------------------------------------------------------- 483 | set termout off 484 | spool "&c_ms_clear" replace 485 | prompt &v_ms_if_stop undefine bv_ms_start 486 | prompt &v_ms_if_stop undefine bv_ms_ela_start 487 | prompt &v_ms_if_stop undefine bv_ms_cpu_start 488 | prompt &v_ms_if_stop undefine v_ms_stattypes 489 | prompt &v_ms_if_stop undefine v_ms_include_statistics 490 | prompt &v_ms_if_stop undefine v_ms_include_latches 491 | prompt &v_ms_if_stop undefine v_ms_include_time_model 492 | prompt &v_ms_if_stop undefine v_ms_start_option 493 | prompt &v_ms_if_stop undefine v_ms_stop_option 494 | spool off 495 | @"&c_ms_clear" 496 | host &c_ms_rmcmd "&c_ms_clear" 497 | undefine 1 498 | undefine 2 499 | undefine p_ms_snap 500 | undefine p_ms_option 501 | undefine v_ms_snap 502 | undefine c_ms_rmcmd 503 | undefine c_ms_init 504 | undefine c_ms_clear 505 | undefine v_ms_if_stop 506 | undefine v_ms_if_start 507 | undefine v_ms_threshold 508 | undefine v_ms_name_list 509 | undefine v_ms_name_like 510 | undefine v_ms_name_regexp 511 | undefine v_ms_option 512 | undefine c_ms_version 513 | set termout on 514 | -------------------------------------------------------------------------------- /mystats_pkg.sql: -------------------------------------------------------------------------------- 1 | create or replace package mystats_pkg authid current_user as 2 | 3 | /* 4 | || ---------------------------------------------------------------------------- 5 | || 6 | || Utility: MyStats 7 | || 8 | || Package: MYSTATS_PKG 9 | || 10 | || Script: mystats_pkg.sql 11 | || 12 | || Version: 3.0 13 | || 14 | || Author: Adrian Billington 15 | || www.oracle-developer.net 16 | || (c) oracle-developer.net 17 | || 18 | || Description: PL/SQL-only version of Jonathan Lewis's SNAP_MY_STATS package. 19 | || This package is used to output the resource usage as recorded 20 | || in V$MYSTAT and V$LATCH. 21 | || 22 | || Key Differences 23 | || --------------- 24 | || 25 | || a) All logic is encapsulated in a single PL/SQL package 26 | || (no stats view); 27 | || 28 | || b) This uses invoker rights and dynamic SQL to workaround 29 | || the sites where developers cannot get explicit grants 30 | || on the required V$ views, but instead have access via 31 | || roles or other privileges; 32 | || 33 | || c) This includes latch statistics and makes use of Tom 34 | || Kyte's RUNSTATS method for distinguising between stats 35 | || and latches; 36 | || 37 | || d) This includes advanced reporting options (see Usage 38 | || section below for details); 39 | || 40 | || e) This includes a session time model report; 41 | || 42 | || f) This requires at least version 10.1 to run because it 43 | || makes use of collection methods such as MEMBER OF and 44 | || also reports on V$SESS_TIME_MODEL statistics. 45 | || 46 | || Usage: exec mystats_pkg.ms_start( [optional statistics include/exclude parameters] ) 47 | || ---- 48 | || exec mystats_pkg.ms_stop( [optional reporting parameters] ) 49 | || 50 | || Optional statistics types are selected during calls to the MS_START procedure 51 | || and are all included by default: 52 | || 53 | || 1. Statistics (V$SESSTAT) 54 | || 2. Latches (V$LATCH) 55 | || 3. Time Model (V$SESS_TIME_MODEL) 56 | || 57 | || Optional reporting parameters are specified during calls to the MS_STOP procedure 58 | || and take one of the following formats: 59 | || 60 | || 1. Threshold (numeric, using P_THRESHOLD parameter (numeric)) 61 | || 2. Statistic names (array of statnames, using P_STATNAMES parameter (collection)) 62 | || 3. Statistic name LIKE pattern (statname pattern, using P_STATNAME_LIKE parameter (string)) 63 | || 4. Statistic name REGEXP pattern (statname pattern, using P_STATNAME_LIKE and P_USE_REGEXP parameters (string and boolean)) 64 | || 65 | || See examples below. 66 | || 67 | || 1. Output all statistics 68 | || ------------------------------------------------------------- 69 | || exec mystats_pkg.ms_start; 70 | || ---- 71 | || exec mystats_pkg.ms_stop; 72 | || 73 | || 2. Output statistics with delta values >= 1,000 74 | || ------------------------------------------------------------- 75 | || exec mystats_pkg.ms_start; 76 | || ---- 77 | || exec mystats_pkg.ms_stop(p_threshold=>1000); 78 | || 79 | || 3. Output statistics for "redo size" and "user commits" only 80 | || ------------------------------------------------------------- 81 | || exec mystats_pkg.ms_start; 82 | || ---- 83 | || exec mystats_pkg.ms_stop(p_statnames=>mystats_pkg.statname_ntt('redo size', 'user commits')); 84 | || 85 | || 4. Output statistics for those containing the word 'memory' 86 | || ----------------------------------------------------------- 87 | || exec mystats_pkg.ms_start; 88 | || ---- 89 | || exec mystats_pkg.ms_stop(p_statname_like=>'memory'); 90 | || 91 | || 5. Output statistics for those with I/O, IO, i/o or io in the name 92 | || ------------------------------------------------------------------ 93 | || exec mystats_pkg.ms_start; 94 | || ---- 95 | || exec mystats_pkg.ms_stop(p_statname_like=>'I/?O\s', p_use_regexp=>true); 96 | || 97 | || 6. Capture and output statistics and time model only (exclude latches) 98 | || ---------------------------------------------------------------------- 99 | || exec mystats_pkg.ms_start(p_include_latches=>false); 100 | || ---- 101 | || exec mystats_pkg.ms_stop; 102 | || 103 | || 7. Output statistics only for those containing 'parallel' 104 | || ------------------------------------------------------------- 105 | || exec mystats_pkg.ms_start(p_include_latches=>false, p_include_time_model=>false); 106 | || ---- 107 | || exec mystats_pkg.ms_stop(p_statname_like=>'parallel'); 108 | || 109 | || Notes: 1. Serveroutput must be on (and set higher than default); 110 | || 111 | || 2. See http://www.jlcomp.demon.co.uk/snapshot.html for original 112 | || version. 113 | || 114 | || 3. A free-standing, SQL*Plus-script version of MyStats is also 115 | || available. The script version works without creating any 116 | || database objects. 117 | || 118 | || Disclaimer: http://www.oracle-developer.net/disclaimer.php 119 | || 120 | || ---------------------------------------------------------------------------- 121 | */ 122 | 123 | type statname_ntt is table of varchar2(64); 124 | 125 | procedure ms_start( p_include_statistics in boolean default true, 126 | p_include_latches in boolean default true, 127 | p_include_time_model in boolean default true ); 128 | 129 | procedure ms_stop; 130 | 131 | procedure ms_stop( p_threshold in integer ); 132 | 133 | procedure ms_stop( p_statnames in mystats_pkg.statname_ntt ); 134 | 135 | procedure ms_stop( p_statname_like in varchar2, 136 | p_use_regexp in boolean default false ); 137 | 138 | end mystats_pkg; 139 | / 140 | 141 | create or replace package body mystats_pkg as 142 | 143 | -- A range of (sub)types for capturing statistics information... 144 | -- ------------------------------------------------------------- 145 | subtype st_option_flag is varchar2(1); 146 | subtype st_stattype is varchar2(6); 147 | subtype st_statname is varchar2(64); 148 | subtype st_statvalue is integer; 149 | subtype st_output is varchar2(255); 150 | 151 | type rt_statistic is record 152 | ( type st_stattype 153 | , name st_statname 154 | , value st_statvalue ); 155 | 156 | type aat_statistic is table of rt_statistic 157 | index by st_statname; 158 | 159 | type aat_mystats is table of aat_statistic 160 | index by pls_integer; 161 | 162 | -- This is the "mystats array" to hold two snapshots... 163 | -- ---------------------------------------------------- 164 | ga_mystats aat_mystats; 165 | 166 | -- Array offsets into the main mystats array, used to 167 | -- determine the start and end points of a run... 168 | -- -------------------------------------------------- 169 | c_run1 constant pls_integer := 1; 170 | c_run2 constant pls_integer := 2; 171 | 172 | -- Globals for elapsed time calculation... 173 | -- --------------------------------------- 174 | type rt_time is record 175 | ( ela_time integer 176 | , cpu_time integer ); 177 | 178 | g_start_time rt_time; 179 | g_end_time rt_time; 180 | 181 | -- Globals to capture snapshot options... 182 | g_include_statistics st_option_flag; 183 | g_include_latches st_option_flag; 184 | g_include_time_model st_option_flag; 185 | 186 | ------------------------------------------------------------------------------ 187 | procedure ms_options( p_threshold in pls_integer, 188 | p_statnames in mystats_pkg.statname_ntt, 189 | p_statname_like in varchar2, 190 | p_statname_regexp in varchar2 ) is 191 | v_filter varchar2(4000); 192 | begin 193 | dbms_output.put('- Statistics types : '); 194 | dbms_output.put('statistics=' || g_include_statistics || ', '); 195 | dbms_output.put('latches=' || g_include_latches || ', '); 196 | dbms_output.put_line('time model=' || g_include_time_model); 197 | if p_threshold is not null then 198 | v_filter := 'threshold=' || p_threshold; 199 | elsif p_statname_like is not null then 200 | v_filter := 'statnames like=' || p_statname_like || ', regular expression=N'; 201 | elsif p_statname_regexp is not null then 202 | v_filter := 'statnames like=' || p_statname_regexp || ', regular expression=Y'; 203 | elsif p_statnames is not null and p_statnames is not empty then 204 | v_filter := 'statnames in='; 205 | for i in 1 .. p_statnames.count loop 206 | v_filter := v_filter || p_statnames(i) || ','; 207 | end loop; 208 | v_filter := rtrim(v_filter, ','); 209 | else 210 | v_filter := 'None'; 211 | end if; 212 | dbms_output.put_line('- Reporting filter : ' || v_filter); 213 | end ms_options; 214 | 215 | ------------------------------------------------------------------------------ 216 | procedure ms_info is 217 | begin 218 | dbms_output.put_line('- MyStats v3.0 by Adrian Billington (http://www.oracle-developer.net)'); 219 | dbms_output.put_line('- Based on the SNAP_MY_STATS utility by Jonathan Lewis'); 220 | end ms_info; 221 | 222 | ------------------------------------------------------------------------------ 223 | procedure ms_snap( p_run in pls_integer, 224 | p_mystats in out nocopy aat_mystats, 225 | p_time in out rt_time ) is 226 | 227 | rc_stat sys_refcursor; 228 | type aat_statistic is table of rt_statistic 229 | index by pls_integer; 230 | aa_stats aat_statistic; 231 | 232 | procedure snap_time is 233 | begin 234 | p_time.ela_time := dbms_utility.get_time; 235 | p_time.cpu_time := dbms_utility.get_cpu_time; 236 | end snap_time; 237 | 238 | begin 239 | 240 | if p_run = c_run2 then 241 | snap_time; 242 | end if; 243 | 244 | -- Dynamic SQL (combined with invoker rights in the spec) works around 245 | -- the need to have explicit select granted on the referenced v$ views. 246 | -- Of course, we still need access granted via a role or other privilege 247 | -- but I've always been able to get the latter and rarely the former... 248 | -- --------------------------------------------------------------------- 249 | open rc_stat for q'[select 'STAT' as type 250 | , a.name 251 | , b.value 252 | from v$statname a 253 | , v$mystat b 254 | where a.statistic# = b.statistic# 255 | and :g_include_statistics = 'Y' 256 | union all 257 | select 'LATCH' 258 | , name 259 | , gets 260 | from v$latch 261 | where :g_include_latches = 'Y' 262 | union all 263 | select 'TIME' 264 | , 'elapsed time' 265 | , hsecs 266 | from v$timer 267 | where :g_include_time_model = 'Y' 268 | union all 269 | select 'TIME' 270 | , stat_name 271 | , value 272 | from v$sess_time_model 273 | where sid = sys_context('userenv','sid') 274 | and :g_include_time_model = 'Y']' 275 | using g_include_statistics, g_include_latches, g_include_time_model, g_include_time_model; 276 | fetch rc_stat bulk collect into aa_stats; 277 | close rc_stat; 278 | for i in 1 .. aa_stats.count loop 279 | p_mystats(p_run)(aa_stats(i).name).type := aa_stats(i).type; 280 | p_mystats(p_run)(aa_stats(i).name).value := aa_stats(i).value; 281 | end loop; 282 | 283 | if p_run = c_run1 then 284 | snap_time; 285 | end if; 286 | 287 | end ms_snap; 288 | 289 | ------------------------------------------------------------------------------ 290 | procedure ms_report( p_threshold in pls_integer default null, 291 | p_statnames in mystats_pkg.statname_ntt default null, 292 | p_statname_like in varchar2 default null, 293 | p_statname_regexp in varchar2 default null ) is 294 | 295 | v_name st_statname; --<-- offset for varchar2 associative arrays 296 | v_indx pls_integer; --<-- offset for pls_integer associative arrays 297 | v_type st_stattype; --<-- statistic type 298 | v_value st_statvalue; --<-- snapshot value for a statistic 299 | 300 | -- Downside of using associative arrays is that we have to sort 301 | -- the output. So here's a couple of types and a variable to enable us 302 | -- to do that... 303 | -- ------------------------------------------------------------------- 304 | type aat_mystats_output is table of st_output 305 | index by st_statname; 306 | type aat_mystats_sorted is table of aat_mystats_output 307 | index by pls_integer; 308 | aa_mystats_sorted aat_mystats_sorted; 309 | 310 | -- Procedure to add a statistic to the sorted mystats array... 311 | -- ----------------------------------------------------------- 312 | procedure sort ( p_stattype in st_stattype, 313 | p_statname in st_statname, 314 | p_value in number ) is 315 | v_offset pls_integer; 316 | v_output st_output; 317 | begin 318 | -- Workaround the offset limits of a PLS_INTEGER associative array... 319 | -- ------------------------------------------------------------------ 320 | v_offset := least(abs(p_value),2147483647); 321 | v_output := rpad(p_stattype, 8) || rpad(p_statname, 64) || 322 | lpad(to_char(p_value,'999,999,999,999'),18); 323 | aa_mystats_sorted(v_offset)(p_statname) := v_output; 324 | end sort; 325 | 326 | -- Report formatting procedures... 327 | -- ------------------------------- 328 | procedure div( p_divider in varchar2 default '-', 329 | p_width in pls_integer default 90 ) is 330 | begin 331 | dbms_output.put_line( rpad(p_divider, p_width, p_divider) ); 332 | end div; 333 | 334 | procedure nl( p_newlines in pls_integer default 1 ) is 335 | begin 336 | for i in 1 .. p_newlines loop 337 | dbms_output.put_line(null); 338 | end loop; 339 | end nl; 340 | 341 | procedure sh ( p_title in varchar2, 342 | p_header in boolean default true ) is 343 | begin 344 | nl(2); 345 | div; 346 | dbms_output.put_line(p_title); 347 | div; 348 | if p_header then 349 | nl; 350 | dbms_output.put_line('Type ' || rpad('Statistic Name',64) || lpad('Value',18)); 351 | dbms_output.put_line(rpad('-',6,'-') || ' ' || rpad('-',64,'-') || ' ' || lpad('-',16,'-')); 352 | end if; 353 | end sh; 354 | 355 | begin 356 | 357 | -- Report header... 358 | -- ---------------- 359 | nl; 360 | div('='); 361 | dbms_output.put_line('MyStats report : ' || to_char(sysdate,'dd-MON-YYYY hh24:mi:ss')); 362 | div('='); 363 | 364 | -- Summary timings... 365 | -- ------------------ 366 | sh('1. Summary Timings'); 367 | dbms_output.put_line(rpad('TIMER', 8) || rpad('snapshot interval (seconds)', 64) || 368 | lpad(to_char(round((g_end_time.ela_time-g_start_time.ela_time)/100,2), 'fm999,990.00'),18)); 369 | dbms_output.put_line(rpad('TIMER', 8) || rpad('CPU time used (seconds)', 64) || 370 | lpad(to_char(round((g_end_time.cpu_time-g_start_time.cpu_time)/100,2), 'fm999,990.00'),18)); 371 | 372 | -- Now sort the output according to difference. A fudge is that we have to sort 373 | -- it manually and also work around the offset limits of an associative array... 374 | -- ----------------------------------------------------------------------------- 375 | v_name := ga_mystats(c_run1).first; 376 | while v_name is not null loop 377 | 378 | -- Retrieve stattype... 379 | -- -------------------- 380 | v_type := ga_mystats(c_run1)(v_name).type; 381 | 382 | -- Calculate the value of the current statistic... 383 | -- ----------------------------------------------- 384 | v_value := ga_mystats(c_run2)(v_name).value - ga_mystats(c_run1)(v_name).value; 385 | 386 | -- If it's greater than the threshold or a statistic we are interested in, 387 | -- then output it. The downside of using purely associative arrays is that 388 | -- we don't have any easy way of sorting. So we have to do it ourselves... 389 | -- ----------------------------------------------------------------------- 390 | if (p_threshold is not null and abs(v_value) >= p_threshold) 391 | or (p_statnames is not empty and v_name member of p_statnames) 392 | or (p_statname_like is not null and v_name like '%'||p_statname_like||'%') 393 | or (p_statname_regexp is not null and regexp_like(v_name, p_statname_regexp, 'i')) 394 | then 395 | -- Fix for bug 1713403. If redo goes over 2Gb then it is reported as a negative 396 | -- number. Recommended workaround (prior to fix in 10g) is to use redo blocks written 397 | -- but this seems to be 0 in V$MYSTAT or V$SESSTAT. Output a bug message... 398 | -- ---------------------------------------------------------------------------------- 399 | if v_name = 'redo size' and v_value < 0 then 400 | sort('BUG','redo size > 2gb gives -ve value. Use redo blocks written',0); 401 | else 402 | sort(v_type, v_name, v_value); 403 | end if; 404 | end if; 405 | 406 | -- Next statname please... 407 | -- ----------------------- 408 | v_name := ga_mystats(c_run1).next(v_name); 409 | 410 | end loop; 411 | 412 | -- Now we can output the sorted snapshot... 413 | -- ---------------------------------------- 414 | sh('2. Statistics Report'); 415 | 416 | v_indx := aa_mystats_sorted.first; 417 | while v_indx is not null loop 418 | 419 | v_name := aa_mystats_sorted(v_indx).first; 420 | while v_name is not null loop 421 | dbms_output.put_line( aa_mystats_sorted(v_indx)(v_name) ); 422 | v_name := aa_mystats_sorted(v_indx).next(v_name); 423 | end loop; 424 | 425 | v_indx := aa_mystats_sorted.next(v_indx); 426 | 427 | end loop; 428 | 429 | -- Options... 430 | -- ------- 431 | sh('3. Options', false); 432 | ms_options(p_threshold, p_statnames, p_statname_like, p_statname_regexp); 433 | 434 | -- Info... 435 | -- ------- 436 | sh('4. About', false); 437 | ms_info; 438 | 439 | nl; 440 | div('='); 441 | dbms_output.put_line('End of report'); 442 | div('='); 443 | 444 | end ms_report; 445 | 446 | ------------------------------------------------------------------------------ 447 | procedure ms_set_snap_options( p_include_statistics in boolean, 448 | p_include_latches in boolean, 449 | p_include_time_model in boolean ) is 450 | function ms_set_option( p_option in boolean ) return varchar2 is 451 | begin 452 | return case 453 | when p_option 454 | then 'Y' 455 | else 'N' 456 | end; 457 | end ms_set_option; 458 | begin 459 | g_include_statistics := ms_set_option(p_include_statistics); 460 | g_include_latches := ms_set_option(p_include_latches); 461 | g_include_time_model := ms_set_option(p_include_time_model); 462 | end ms_set_snap_options; 463 | 464 | ------------------------------------------------------------------------------ 465 | procedure ms_reset is 466 | begin 467 | ga_mystats.delete; 468 | g_start_time := null; 469 | g_end_time := null; 470 | g_include_statistics := null; 471 | g_include_latches := null; 472 | g_include_time_model := null; 473 | end ms_reset; 474 | 475 | ------------------------------------------------------------------------------ 476 | procedure ms_start( p_include_statistics in boolean default true, 477 | p_include_latches in boolean default true, 478 | p_include_time_model in boolean default true ) is 479 | begin 480 | ms_reset; 481 | ms_set_snap_options(p_include_statistics, p_include_latches, p_include_time_model); 482 | ms_snap(c_run1, ga_mystats, g_start_time); 483 | end ms_start; 484 | 485 | ------------------------------------------------------------------------------ 486 | procedure ms_stop_internal( p_threshold in integer default null, 487 | p_statnames in mystats_pkg.statname_ntt default null, 488 | p_statname_like in varchar2 default null, 489 | p_statname_regexp in varchar2 default null ) is 490 | begin 491 | if g_start_time.ela_time is not null then 492 | ms_snap(c_run2, ga_mystats, g_end_time); 493 | case 494 | when p_threshold is not null 495 | then ms_report(p_threshold => p_threshold); 496 | when p_statnames is not null 497 | then ms_report(p_statnames => p_statnames); 498 | when p_statname_like is not null 499 | then ms_report(p_statname_like => p_statname_like); 500 | when p_statname_regexp is not null 501 | then ms_report(p_statname_regexp => p_statname_regexp); 502 | else ms_report; 503 | end case; 504 | ms_reset; 505 | else 506 | raise_application_error( 507 | -20001, 'Error: must call ms_start before ms_stop.' 508 | ); 509 | end if; 510 | end ms_stop_internal; 511 | 512 | ------------------------------------------------------------------------------ 513 | procedure ms_stop is 514 | begin 515 | ms_stop_internal(p_threshold => 0); 516 | end ms_stop; 517 | 518 | ------------------------------------------------------------------------------ 519 | procedure ms_stop( p_threshold in integer ) is 520 | begin 521 | ms_stop_internal(p_threshold => p_threshold); 522 | end ms_stop; 523 | 524 | ------------------------------------------------------------------------------ 525 | procedure ms_stop( p_statnames in mystats_pkg.statname_ntt ) is 526 | begin 527 | ms_stop_internal(p_statnames => p_statnames); 528 | end ms_stop; 529 | 530 | ------------------------------------------------------------------------------ 531 | procedure ms_stop( p_statname_like in varchar2, 532 | p_use_regexp in boolean default false ) is 533 | begin 534 | if p_use_regexp then 535 | ms_stop_internal(p_statname_regexp => p_statname_like); 536 | else 537 | ms_stop_internal(p_statname_like => p_statname_like); 538 | end if; 539 | end ms_stop; 540 | 541 | end mystats_pkg; 542 | / 543 | 544 | create or replace public synonym mystats_pkg for mystats_pkg; 545 | grant execute on mystats_pkg to public; 546 | --------------------------------------------------------------------------------