├── LICENSE ├── README.md ├── moats.pkb ├── moats.pks ├── moats_install.sql ├── moats_privs_grant.sql ├── moats_privs_revoke.sql ├── moats_remove.sql ├── moats_settings.sql ├── moats_types.sql └── moats_views.sql /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright 2011-2020 Adrian Billington (www.oracle-developer.net) & Tanel Poder (www.tanelpoder.com) 2 | 3 | Licensed under the Apache License, Version 2.0 (the "License"); 4 | you may not use this file except in compliance with the License. 5 | You may obtain a copy of the License at 6 | 7 | http://www.apache.org/licenses/LICENSE-2.0 8 | 9 | Unless required by applicable law or agreed to in writing, software 10 | distributed under the License is distributed on an "AS IS" BASIS, 11 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 12 | See the License for the specific language governing permissions and 13 | limitations under the License. 14 | 15 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | 2 | # Mother Of All Tuning Scripts (MOATS) 3 | * Adrian Billington (www.oracle-developer.net) 4 | * Tanel Poder (www.tanelpoder.com) 5 | 6 | ## Version 7 | MOATS v1.06, April 2011 8 | 9 | ## License 10 | This project uses the Apache License Version 2.0. 11 | See https://github.com/oracle-developer/moats/blob/master/LICENSE 12 | 13 | ## Contents 14 | ``` 15 | 1.0 Introduction 16 | 2.0 Supported Versions 17 | 3.0 Installation & Removal 18 | 3.1 Prerequisites 19 | 3.1.1 System Privileges 20 | 3.1.2 Object Privileges 21 | 3.2 Installation 22 | 3.3 Removal 23 | 4.0 Usage 24 | 4.1 SQL*Plus Setup 25 | 4.1.1 Window Size 26 | 4.1.2 SQL*Plus Settings 27 | 4.2 MOATS TOP Usage 28 | 4.2.1 Using MOATS.TOP directly 29 | 4.2.2 Using the TOP view 30 | 4.3 Other MOATS APIs 31 | 5.0 Roadmap 32 | 6.0 Disclaimer 33 | 7.0 Acknowledgements 34 | ``` 35 | 36 | ### 1.0 Introduction 37 | MOATS is a simple tuning tool that samples active sessions and reports top database activity in regular screen refreshes at specified intervals (similar to the TOP utility for UNIX). MOATS is designed to run in sqlplus only and has recommended display settings to enable screen refreshes. 38 | 39 | Examples of how this application might be used: 40 | 41 | ``` 42 | -- To report top session and instance activity at 5 second intervals... 43 | -- -------------------------------------------------------------------- 44 | 45 | SQL> set arrays 72 lines 110 head off tab off pages 0 46 | 47 | SQL> SELECT * FROM TABLE(moats.top(5)); 48 | ``` 49 | 50 | ``` 51 | -- Sample output... 52 | -- -------------------------------------------------------------------- 53 | 54 | MOATS: The Mother Of All Tuning Scripts v1.0 by Adrian Billington & Tanel Poder 55 | http://www.oracle-developer.net & http://www.e2sn.com 56 | 57 | + INSTANCE SUMMARY ------------------------------------------------------------------------------------------+ 58 | | Instance: ora112 | Execs/s: 2.0 | sParse/s: 0.0 | LIOs/s: 219637.3 | Read MB/s: 0.0 | 59 | | Cur Time: 13-Aug 19:25:14 | Calls/s: 0.0 | hParse/s: 0.0 | PhyRD/s: 0.5 | Write MB/s: 0.0 | 60 | | History: 0h 0m 26s | Commits/s: 0.0 | ccHits/s: 1.5 | PhyWR/s: 2.9 | Redo MB/s: 0.0 | 61 | +------------------------------------------------------------------------------------------------------------+ 62 | 63 | + TOP SQL_ID (child#) -----+ TOP SESSIONS ---------+ + TOP WAITS -------------------------+ WAIT CLASS -+ 64 | | 50% | bwx4var9q4y9f (0) | 71 | | 100% | latch: cache buffers chains | Concurrency | 65 | | 50% | bq2qr0bhjyv1c (0) | 133 | | 50% | SQL*Net message to client | Network | 66 | | 50% | 799uuu8tpf6rk (0) | 6 | | | | 67 | +--------------------------------------------------+ +--------------------------------------------------+ 68 | 69 | + TOP SQL_ID ----+ PLAN_HASH_VALUE + SQL TEXT ---------------------------------------------------------------+ 70 | | bwx4var9q4y9f | 2119813036 | select /*+ full(a) full(b) use_nl(a b) */ count(*) from sys.obj$ a, | 71 | | | | ys.obj$ b where a.name = b.name and rownum <= 1000002 | 72 | + ---------------------------------------------------------------------------------------------------------- + 73 | | bq2qr0bhjyv1c | 644658511 | select moats_ash_ot( systimestamp, saddr, sid, serial#, audsid, paddr, | 74 | | | | er#, username, command, ownerid, taddr | 75 | + ---------------------------------------------------------------------------------------------------------- + 76 | | 799uuu8tpf6rk | 2119813036 | select /*+ full(a) full(b) use_nl(a b) */ count(*) from sys.obj$ a, | 77 | | | | ys.obj$ b where a.name = b.name and rownum <= 1000001 | 78 | + ---------------------------------------------------------------------------------------------------------- + 79 | ``` 80 | 81 | ### 2.0 Supported Versions 82 | MOATS supports all Oracle versions of 10g Release 2 and above. 83 | 84 | 85 | ### 3.0 Installation & Removal 86 | MOATS requires several database objects to be created. The privileges, installation and removal steps are described below. 87 | 88 | #### 3.1 Prerequisites 89 | It is recommended that this application is installed in a "TOOLS" schema, but whichever schema is used requires the following privileges. Note that any or all of these grants can be assigned to either the MOATS target schema itself or a role that is granted to the MOATS target schema. 90 | 91 | ##### 3.1.1 System Privileges 92 | * `CREATE TYPE` 93 | * `CREATE TABLE` 94 | * `CREATE VIEW` 95 | * `CREATE PROCEDURE` 96 | 97 | ##### 3.1.2 Object Privileges 98 | * `EXECUTE ON SYS.DBMS_LOCK` 99 | * `SELECT ON V_$SESSION` 100 | * `SELECT ON V_$STATNAME` 101 | * `SELECT ON V_$SYSSTAT` 102 | * `SELECT ON V_$LATCH` 103 | * `SELECT ON V_$TIMER` 104 | * `SELECT ON V_$SQL` 105 | 106 | **Notes:** 107 | 108 | 1. `SELECT ANY DICTIONARY` can be granted in place of the specific V$ view grants above 109 | 2. Supplied scripts will grant/revoke all of the above to/from the MOATS target schema/role. 110 | 111 | #### 3.2 Installation 112 | MOATS can be installed using sqlplus or any tools that fully support sqlplus commands. 113 | 114 | To install MOATS: 115 | 116 | 1. Ensure that the MOATS owner schema has the required privileges described in Section 3.1 above. A script named `moats_privs_grant.sql` is supplied if required (this will need to be run as a user with admin grant rights on SYS objects. This script will prompt for the name of the target MOATS schema). 117 | 118 | 2. To install MOATS, login as the target schema and run the `moats_install.sql` script. A warning will prompt for a continue/cancel option. 119 | 120 | #### 3.3 Removal 121 | To remove MOATS, login as the MOATS owner schema and run the `moats_remove.sql` script. A warning will prompt for a continue/cancel option. 122 | 123 | To revoke all related privileges from the MOATS owner schema, a script named `moats_privs_revoke.sql` is supplied if required (this will need to be run as a user with admin grant rights on SYS objects. This script will prompt for the name of the target MOATS schema). 124 | 125 | ### 4.0 Usage 126 | MOATS is simple to use. It is designed for sqlplus only and makes use of sqlplus and PL/SQL functionality to provide real-time screen refreshes. To make the most of MOATS v1.0, follow the steps below. 127 | 128 | #### 4.1 SQL*Plus Setup 129 | MOATS TOP output is of a fixed size so needs some specific settings. 130 | 131 | ##### 4.1.1 Setting Window Size 132 | The `MOATS.FORMAT_WINDOW` procedure is a visual aid to setting the right screen size for MOATS. To run it, login to sqlplus and do the following: 133 | 134 | 1. `set serveroutput on format wrapped` 135 | 2. `exec moats.format_window` 136 | 3. resize window to the dotted lines at the top and bottom of the FORMAT_WINDOW output 137 | 138 | Window size should be at least 110 x 36 but the FORMAT_WINDOW procedure is the best way to get accurate and optimal settings for MOATS. 139 | 140 | ##### 4.1.2 SQL*Plus Settings 141 | MOATS comes with a `moats_settings.sql` file that does the following: 142 | 143 | * `set arrays 72` 144 | * `set lines 110` 145 | * `set head off` 146 | * `set tab off` 147 | * `set pages 0` 148 | * `set serveroutput on format wrapped` 149 | 150 | These are optimal sqlplus settings for the MOATS TOP utility and need to be set before running it (see Usage below). 151 | 152 | #### 4.2 MOATS TOP Usage 153 | `MOATS.TOP` is a pipelined function that outputs instance performance statistics at a given refresh interval. Before running TOP, the `moats_settings.sql` script (or equivalent) should be run in the sqlplus session. The following example refreshes the instance statistics at the default 10 seconds: 154 | 155 | ##### 4.2.1 Using `MOATS.TOP` directly 156 | 157 | ``` 158 | +-------------------------------------+ 159 | | SQL> @moats_settings.sql | 160 | | | 161 | | SQL> SELECT * | 162 | | 2 FROM TABLE(moats.top); | 163 | +-------------------------------------+ 164 | ``` 165 | 166 | To use a non-default refresh rate, supply it as follows: 167 | 168 | ``` 169 | +-------------------------------------+ 170 | | SQL> SELECT * | 171 | | 2 FROM TABLE(moats.top(5)); | 172 | +-------------------------------------+ 173 | ``` 174 | 175 | This example uses a 5 second refresh rate. 176 | 177 | To stop `MOATS.TOP` refreshes, use a Ctrl-C interrupt. 178 | 179 | ##### 4.2.2 Using the `TOP` view 180 | A view named `TOP` is included with MOATS for convenience. 181 | 182 | ``` 183 | +-------------------------------------+ 184 | | SQL> @moats_settings.sql | 185 | | | 186 | | SQL> SELECT * FROM top; | 187 | +-------------------------------------+ 188 | ``` 189 | 190 | To set a non-default value for refresh rate, set the MOATS refresh rate parameter, as follows. 191 | 192 | ``` 193 | +--------------------------------------------------------------+ 194 | | SQL> @moats_settings.sql | 195 | | | 196 | | SQL> exec moats.set_parameter(moats.gc_top_refresh_rate, 3); | 197 | | | 198 | | SQL> SELECT * FROM top; | 199 | +--------------------------------------------------------------+ 200 | ``` 201 | 202 | This example uses a 3 second refresh rate. 203 | 204 | #### 4.3 Other MOATS APIs 205 | MOATS contains several other public APIs that are currently for internal use only. These will be fully described and "released" with future MOATS versions but are currently only supported for use by `MOATS.TOP`. They include pipelined functions to query the active session data that MOATS gathers. 206 | 207 | ### 5.0 Roadmap 208 | There is no fixed roadmap at the time of writing. Features that Tanel and Adrian would like to add are (but are not limited to) the following: 209 | 210 | * formally expose the active session query functions for custom-reporting 211 | * add drill-down functionality for SQL statements of interest in the TOP output 212 | 213 | ### 6.0 Disclaimer 214 | This software is supplied in good faith and is free for download, but any subsequent use is entirely at the end-users' risk. Adrian Billington/www.oracle-developer.net and Tanel Poder/www.tanelpoder.com do not accept any responsibility for problems arising as a result of using MOATS. All users are strongly advised to read the installation and removal scripts prior to running them and test the application in an appropriate environment. 215 | 216 | ### 7.0 Acknowledgements 217 | Many thanks to Randolf Geist for his contributions to MOATS, including several bug-fixes to the original alpha version. 218 | -------------------------------------------------------------------------------- /moats.pkb: -------------------------------------------------------------------------------- 1 | create or replace package body moats as 2 | 3 | -- -------------------------------------------------------------------------- 4 | -- MOATS v1.0 (c) Tanel Poder & Adrian Billington, 2010 5 | -- 6 | -- See supplied README for usage and disclaimers. 7 | -- 8 | -- http://www.tanelpoder.com 9 | -- http://www.oracle-developer.net 10 | -- -------------------------------------------------------------------------- 11 | 12 | -- Internal types and global arrays for caching collections of 13 | -- SYSSTAT/ASH data for querying within MOATS... 14 | -- ------------------------------------------------------------------ 15 | type moats_stat_ntt_aat is table of moats_stat_ntt 16 | index by pls_integer; 17 | g_stats moats_stat_ntt_aat; 18 | 19 | type moats_ash_ntt_aat is table of moats_ash_ntt 20 | index by pls_integer; 21 | g_ash moats_ash_ntt_aat; 22 | 23 | -- Internal type and variable for storing simple MOATS parameters... 24 | -- ----------------------------------------------------------------- 25 | type parameter_aat is table of integer 26 | index by pls_integer; 27 | g_params parameter_aat; 28 | 29 | -- Variables for maintaining ASH/SYSSTAT collections... 30 | -- ---------------------------------------------------- 31 | g_ash_size pls_integer := 0; 32 | g_stat_size pls_integer := 0; 33 | 34 | -- General constants... 35 | -- -------------------- 36 | gc_space constant moats_output_ot := moats_output_ot(null); 37 | gc_mb constant pls_integer := 1048576; 38 | gc_gb constant pls_integer := 1048576*1024; 39 | gc_screen_size constant pls_integer := 36; 40 | gc_newline constant varchar2(1) := chr(10); 41 | 42 | ---------------------------------------------------------------------------- 43 | procedure p( p_str in varchar2 ) is 44 | begin 45 | dbms_output.put_line(p_str); 46 | end p; 47 | 48 | ---------------------------------------------------------------------------- 49 | procedure po( p_str in moats_output_ot ) is 50 | begin 51 | p(p_str.output); 52 | end po; 53 | 54 | -- ---------------------------------------------------------------------------- 55 | -- procedure dump_ash is 56 | -- pragma autonomous_transaction; 57 | -- begin 58 | -- insert into moats_ash_dump select * from table(moats.get_ash); 59 | -- commit; 60 | -- end dump_ash; 61 | 62 | ---------------------------------------------------------------------------- 63 | procedure show_snaps is 64 | v_indx pls_integer; 65 | begin 66 | p('ASH snaps...'); 67 | p('------------------------------------'); 68 | v_indx := g_ash.first; 69 | while v_indx is not null loop 70 | p(utl_lms.format_message('Index=[%d] Count=[%d]', v_indx, g_ash(v_indx).count)); 71 | v_indx := g_ash.next(v_indx); 72 | end loop; 73 | p('STAT snaps...'); 74 | p('------------------------------------'); 75 | v_indx := g_stats.first; 76 | while v_indx is not null loop 77 | p(utl_lms.format_message('Index=[%d] Count=[%d]', v_indx, g_stats(v_indx).count)); 78 | v_indx := g_stats.next(v_indx); 79 | end loop; 80 | end show_snaps; 81 | 82 | ---------------------------------------------------------------------------- 83 | function banner return moats_output_ntt is 84 | begin 85 | return moats_output_ntt( 86 | moats_output_ot('MOATS: The Mother Of All Tuning Scripts v1.0 by Adrian Billington & Tanel Poder'), 87 | moats_output_ot(' http://www.oracle-developer.net & http://www.e2sn.com') 88 | ); 89 | end banner; 90 | 91 | ---------------------------------------------------------------------------- 92 | function to_string ( p_collection in moats_v2_ntt, 93 | p_delimiter in varchar2 default ',', 94 | p_elements in pls_integer default null ) return varchar2 is 95 | v_str varchar2(4000); 96 | begin 97 | for i in 1 .. least(nvl(p_elements, p_collection.count), p_collection.count) loop 98 | v_str := v_str || p_delimiter || p_collection(i); 99 | end loop; 100 | return ltrim(v_str, p_delimiter); 101 | end to_string; 102 | 103 | ---------------------------------------------------------------------------- 104 | procedure format_window is 105 | v_banner moats_output_ntt := banner(); 106 | c_boundary varchar2(110) := rpad('-',110,'-'); 107 | procedure spaces( p_spaces in pls_integer ) is 108 | begin 109 | for i in 1 .. p_spaces loop 110 | po(gc_space); 111 | end loop; 112 | end spaces; 113 | begin 114 | p(c_boundary); 115 | spaces(2); 116 | for i in 1 .. v_banner.count loop 117 | p(v_banner(i).output); 118 | end loop; 119 | spaces(3); 120 | p(' MOATS.FORMAT_WINDOW'); 121 | p(' -------------------'); 122 | p(' Align sqlplus window size to dotted lines for optimal output'); 123 | spaces(gc_screen_size-10); 124 | p(c_boundary); 125 | end format_window; 126 | 127 | ---------------------------------------------------------------------------- 128 | procedure set_parameter( p_parameter_code in pls_integer, 129 | p_parameter_value in integer ) is 130 | begin 131 | g_params(p_parameter_code) := p_parameter_value; 132 | end set_parameter; 133 | 134 | ---------------------------------------------------------------------------- 135 | function get_parameter ( p_parameter_code in pls_integer ) return integer is 136 | begin 137 | return g_params(p_parameter_code); 138 | end get_parameter; 139 | 140 | ---------------------------------------------------------------------------- 141 | procedure restore_default_parameters is 142 | begin 143 | set_parameter(moats.gc_ash_polling_rate, 1); 144 | set_parameter(moats.gc_ash_threshold, 1000); 145 | set_parameter(moats.gc_top_refresh_rate, 10); 146 | -- By default don't use a trailing ASH window 147 | set_parameter(moats.gc_ash_window_size, NULL); 148 | end restore_default_parameters; 149 | 150 | ---------------------------------------------------------------------------- 151 | function get_sql( p_select in varchar2, 152 | p_from in varchar2, 153 | p_where in varchar2, 154 | p_group_by in varchar2, 155 | p_order_by in varchar2 ) return varchar2 is 156 | v_sql varchar2(32767); 157 | begin 158 | v_sql := 'select ' || nvl(p_select, '*') || ' from ' || p_from; 159 | if p_where is not null then 160 | v_sql := v_sql || ' where ' || p_where; 161 | end if; 162 | if p_group_by is not null then 163 | v_sql := v_sql || ' group by ' || p_group_by; 164 | end if; 165 | if p_order_by is not null then 166 | v_sql := v_sql || ' order by ' || p_order_by; 167 | end if; 168 | return v_sql; 169 | end get_sql; 170 | 171 | ---------------------------------------------------------------------------- 172 | function ash_history return interval day to second is 173 | begin 174 | return g_ash(g_ash.last)(1).snaptime - g_ash(g_ash.first)(1).snaptime; 175 | end ash_history; 176 | 177 | ---------------------------------------------------------------------------- 178 | function ash_sample_count( p_lower_snap in pls_integer, 179 | p_upper_snap in pls_integer ) return pls_integer is 180 | v_samples pls_integer := 0; 181 | v_snap pls_integer; 182 | v_exit boolean := false; 183 | begin 184 | v_snap := p_lower_snap; 185 | while v_snap is not null and not v_exit loop 186 | -- Ignore dummy record 187 | if not (g_ash(v_snap).count = 1 and g_ash(v_snap)(1).sid is null) then 188 | v_samples := v_samples + g_ash(v_snap).count; 189 | end if; 190 | v_exit := (v_snap = p_upper_snap); 191 | v_snap := g_ash.next(v_snap); 192 | end loop; 193 | return greatest(v_samples,1); 194 | end ash_sample_count; 195 | 196 | ---------------------------------------------------------------------------- 197 | procedure maintain_ash_collection( p_index in pls_integer ) is 198 | begin 199 | if g_ash(p_index).count = 0 then 200 | g_ash.delete(p_index); 201 | else 202 | g_ash_size := g_ash_size + g_ash(p_index).count; 203 | while g_ash_size > g_params(moats.gc_ash_threshold) loop 204 | g_ash_size := g_ash_size - g_ash(g_ash.first).count; 205 | g_ash.delete(g_ash.first); 206 | end loop; 207 | end if; 208 | end maintain_ash_collection; 209 | 210 | ---------------------------------------------------------------------------- 211 | procedure snap_ash( p_index in pls_integer ) is 212 | v_sql_template varchar2(32767); 213 | v_sql varchar2(32767); 214 | begin 215 | 216 | -- TODO: conditional compilation to get correct column list for version or 217 | -- select a small bunch of useful columns 218 | 219 | -- Use dynamic SQL to avoid explicit grants on V$SESSION. Prepare the start 220 | -- of the SQL as it will be used twice... 221 | -- ------------------------------------------------------------------------ 222 | v_sql_template := q'[select moats_ash_ot( 223 | systimestamp, saddr, %sid%, serial#, audsid, paddr, user#, 224 | username, command, ownerid, taddr, lockwait, 225 | status, server, schema#, schemaname, osuser, 226 | process, machine, terminal, program, type, 227 | sql_address, sql_hash_value, sql_id, sql_child_number, 228 | prev_sql_addr, prev_hash_value, prev_sql_id, 229 | prev_child_number, module, module_hash, action, 230 | action_hash, client_info, fixed_table_sequence, 231 | row_wait_obj#, row_wait_file#, row_wait_block#, 232 | row_wait_row#, logon_time, last_call_et, pdml_enabled, 233 | failover_type, failover_method, failed_over, 234 | resource_consumer_group, pdml_status, pddl_status, 235 | pq_status, current_queue_duration, client_identifier, 236 | blocking_session_status, blocking_instance, 237 | blocking_session, seq#, event#, case when state = 'WAITING' then event else 'ON CPU' end, p1text, p1, 238 | p1raw, p2text, p2, p2raw, p3text, p3, p3raw, 239 | wait_class_id, wait_class#, case when state = 'WAITING' then wait_class else 'ON CPU' end, wait_time, 240 | seconds_in_wait, state, service_name, sql_trace, 241 | sql_trace_waits, sql_trace_binds 242 | ) 243 | from v$session 244 | where %preds%]'; 245 | 246 | v_sql := replace( v_sql_template, '%sid%', 'sid'); 247 | v_sql := replace( v_sql, '%preds%', q'[ status = 'ACTIVE' 248 | and (wait_class != 'Idle' or state != 'WAITING') 249 | and sid != sys_context('userenv', 'sid')]' ); 250 | 251 | execute immediate v_sql bulk collect into g_ash(p_index); 252 | 253 | -- If we have nothing to snap, add a dummy record that will be ignored 254 | -- in GET_ASH and GET_ASH_SAMPLE_COUNT... 255 | -- ------------------------------------------------------------------- 256 | if g_ash(p_index).count = 0 then 257 | v_sql := replace( v_sql_template, '%sid%', 'null'); 258 | v_sql := replace( v_sql, '%preds%', q'[sid = sys_context('userenv', 'sid')]' ); 259 | execute immediate v_sql bulk collect into g_ash(p_index); 260 | end if; 261 | 262 | maintain_ash_collection(p_index); 263 | 264 | end snap_ash; 265 | 266 | ---------------------------------------------------------------------------- 267 | procedure reset_stats_collection is 268 | begin 269 | g_stats.delete; 270 | end reset_stats_collection; 271 | 272 | ---------------------------------------------------------------------------- 273 | procedure snap_stats( p_index in pls_integer, 274 | p_reset in boolean default false ) is 275 | begin 276 | 277 | if p_reset then 278 | reset_stats_collection(); 279 | end if; 280 | 281 | -- Use dynamic SQL to avoid explicit grants on V$ views... 282 | -- ------------------------------------------------------- 283 | execute immediate 284 | q'[select moats_stat_ot(type, name, value) 285 | from ( 286 | select 'STAT' as type 287 | , sn.name 288 | , ss.value 289 | from v$statname sn 290 | , v$sysstat ss 291 | where sn.statistic# = ss.statistic# 292 | union all 293 | select 'LATCH' 294 | , name 295 | , gets 296 | from v$latch 297 | union all 298 | select 'TIMER' 299 | , 'moats timer' 300 | , hsecs 301 | from v$timer 302 | )]' 303 | bulk collect into g_stats(p_index); 304 | 305 | end snap_stats; 306 | 307 | ---------------------------------------------------------------------------- 308 | function instance_summary ( p_lower_snap in pls_integer, 309 | p_upper_snap in pls_integer ) return moats_output_ntt is 310 | 311 | type metric_aat is table of number 312 | index by pls_integer; 313 | v_rows moats_output_ntt := moats_output_ntt(); 314 | v_metrics metric_aat; 315 | v_secs number; --<-- seconds between 2 stats snaps 316 | v_hivl interval day to second; --<-- interval of ASH history saved 317 | v_hstr varchar2(30); --<-- formatted hh:mi:ss string of history 318 | 319 | begin 320 | 321 | -- Get long and short metrics for range of stats. Order for fixed array offset... 322 | -- ------------------------------------------------------------------------------ 323 | select upr.value - lwr.value 324 | bulk collect into v_metrics 325 | from table(g_stats(p_lower_snap)) lwr 326 | , table(g_stats(p_upper_snap)) upr 327 | where lwr.name = upr.name 328 | and lwr.name in ('execute count', 'parse count (hard)', 'parse count (total)', 329 | 'physical read total IO requests', 'physical read total bytes', 330 | 'physical write total IO requests', 'physical write total bytes', 331 | 'redo size', 'redo writes', 'session cursor cache hits', 332 | 'session logical reads', 'user calls', 'user commits', 333 | 'moats timer') 334 | order by 335 | lwr.name; 336 | 337 | -- 1 execute count 338 | -- 2 moats timer 339 | -- 3 parse count (hard) 340 | -- 4 parse count (total) 341 | -- 5 physical read total IO requests 342 | -- 6 physical read total bytes 343 | -- 7 physical write total IO requests 344 | -- 8 physical write total bytes 345 | -- 9 redo size 346 | -- 10 redo writes 347 | -- 11 session cursor cache hits 348 | -- 12 session logical reads 349 | -- 13 user calls 350 | -- 14 user commits 351 | 352 | -- Execs/s: execute count 353 | -- sParse/s: parse count (total) 354 | -- LIOs/s: session logical reads 355 | -- Read MB/s: physical read total bytes / 1048576 356 | -- Calls/s: user calls 357 | -- hParse/s: parse count (hard) 358 | -- PhyRD/s: physical read total IO requests 359 | -- PhyWR/s: physical write total IO requests 360 | -- Write MB/s: physical write total bytes / 1048576 361 | -- History: 362 | -- Commits/s: user commits 363 | -- ccHits/s: session cursor cache hits 364 | -- Redo MB/s: redo size 365 | 366 | -- Calculate number of seconds... 367 | -- ------------------------------ 368 | v_secs := v_metrics(2)/100; 369 | 370 | -- Calculate ASH history... 371 | -- ------------------------ 372 | v_hivl := ash_history(); 373 | v_hstr := to_char(extract(hour from v_hivl)) || 'h ' || 374 | to_char(extract(minute from v_hivl)) || 'm ' || 375 | to_char(trunc(extract(second from v_hivl))) || 's'; 376 | 377 | -- Set the instance summary output... 378 | -- ---------------------------------- 379 | v_rows.extend(5); 380 | v_rows(1) := moats_output_ot(rpad('+ INSTANCE SUMMARY ',109,'-') || '+'); 381 | v_rows(2) := moats_output_ot( 382 | rpad('| Instance: ' || sys_context('userenv','instance_name'), 28) || 383 | ' | Execs/s: ' || lpad(to_char(v_metrics(1)/v_secs, 'fm99990.0'), 7) || 384 | ' | sParse/s: ' || lpad(to_char((v_metrics(4)-v_metrics(3))/v_secs, 'fm99990.0'), 7) || 385 | ' | LIOs/s: ' || lpad(to_char(v_metrics(12)/v_secs, 'fm9999990.0'), 9) || 386 | ' | Read MB/s: ' || lpad(to_char(v_metrics(6)/v_secs/gc_mb, 'fm99990.0'), 7) || 387 | ' |'); 388 | v_rows(3) := moats_output_ot( 389 | rpad('| Cur Time: ' || to_char(sysdate, 'DD-Mon hh24:mi:ss'), 28) || 390 | ' | Calls/s: ' || lpad(to_char(v_metrics(13)/v_secs, 'fm99990.0'), 7) || 391 | ' | hParse/s: ' || lpad(to_char(v_metrics(3)/v_secs, 'fm99990.0'), 7) || 392 | ' | PhyRD/s: ' || lpad(to_char(v_metrics(5)/v_secs, 'fm999990.0'), 8) || 393 | ' | Write MB/s: ' || lpad(to_char(v_metrics(8)/v_secs/gc_mb, 'fm9990.0'), 6) || 394 | ' |'); 395 | v_rows(4) := moats_output_ot( 396 | rpad('| History: ' || v_hstr, 28) || 397 | ' | Commits/s: ' || lpad(to_char(v_metrics(14)/v_secs, 'fm990.0'), 5) || 398 | ' | ccHits/s: ' || lpad(to_char(v_metrics(11)/v_secs, 'fm99990.0'), 7) || 399 | ' | PhyWR/s: ' || lpad(to_char(v_metrics(7)/v_secs, 'fm999990.0'), 8) || 400 | ' | Redo MB/s: ' || lpad(to_char(v_metrics(9)/v_secs/gc_mb, 'fm99990.0'), 7) || 401 | ' |'); 402 | v_rows(5) := moats_output_ot(rpad('+-',109,'-') || '+'); 403 | 404 | return v_rows; 405 | 406 | end instance_summary; 407 | 408 | ---------------------------------------------------------------------------- 409 | function top_summary ( p_lower_snap in pls_integer, 410 | p_upper_snap in pls_integer ) return moats_output_ntt is 411 | 412 | type top_sql_rt is record 413 | ( sql_id varchar2(64) 414 | , sql_child_number number 415 | , occurrences number 416 | , top_sids moats_v2_ntt ); 417 | 418 | type top_waits_rt is record 419 | ( wait_name varchar2(64) 420 | , wait_class varchar2(64) 421 | , occurrences number ); 422 | 423 | type top_sql_aat is table of top_sql_rt 424 | index by pls_integer; 425 | 426 | type top_waits_aat is table of top_waits_rt 427 | index by pls_integer; 428 | 429 | v_row varchar2(4000); 430 | v_rows moats_output_ntt := moats_output_ntt(); 431 | v_top_sqls top_sql_aat; 432 | v_top_waits top_waits_aat; 433 | v_samples pls_integer; 434 | 435 | begin 436 | 437 | -- Calculate number of ASH samples for this output... 438 | -- -------------------------------------------------- 439 | v_samples := ash_sample_count( p_lower_snap => p_lower_snap, 440 | p_upper_snap => p_upper_snap ); 441 | 442 | -- Begin TOP summary... 443 | -- -------------------- 444 | v_rows.extend; 445 | v_rows(1) := moats_output_ot( 446 | rpad('+ TOP SQL_ID (child#) ',27,'-') || 447 | rpad('+ TOP SESSIONS ',24,'-') || 448 | rpad('+',7) || 449 | rpad('+ TOP WAITS ',37,'-') || '+ WAIT CLASS -+' 450 | ); 451 | 452 | -- Top SQL_IDs... 453 | -- -------------- 454 | with ash_data as ( 455 | select sid, sql_id, sql_child_number 456 | from table( 457 | moats.get_ash( 458 | p_lower_snap, p_upper_snap, moats.gc_all_rows)) 459 | ) 460 | select o_ash.sql_id 461 | , o_ash.sql_child_number 462 | , o_ash.occurrences 463 | , cast( 464 | multiset( 465 | select i_ash.sid 466 | from ash_data i_ash 467 | where i_ash.sql_id = o_ash.sql_id 468 | and i_ash.sql_child_number = o_ash.sql_child_number 469 | group by 470 | i_ash.sid 471 | order by 472 | count(*) desc 473 | ) as moats_v2_ntt) as top_sids 474 | bulk collect into v_top_sqls 475 | from ( 476 | select sql_id 477 | , sql_child_number 478 | , count(*) as occurrences 479 | from ash_data 480 | group by 481 | sql_id 482 | , sql_child_number 483 | order by 484 | count(*) desc 485 | ) o_ash 486 | where rownum <= 5; 487 | 488 | -- Top waits... 489 | -- ------------ 490 | select substr(event,1,48) 491 | , wait_class 492 | , occurrences 493 | bulk collect into v_top_waits 494 | from ( 495 | select event 496 | , wait_class 497 | , count(*) as occurrences 498 | from table( 499 | moats.get_ash( 500 | p_lower_snap, p_upper_snap, moats.gc_all_rows)) 501 | group by 502 | event 503 | , wait_class 504 | order by 505 | count(*) desc 506 | ) 507 | where rownum <= 5; 508 | 509 | -- Summary output... 510 | -- ----------------- 511 | for i in 1 .. greatest(v_top_sqls.count, v_top_waits.count) loop 512 | v_rows.extend; 513 | v_row := case 514 | when v_top_sqls.exists(i) 515 | then '|' || lpad(to_char((v_top_sqls(i).occurrences/v_samples)*100, 'fm9999'),4) || '% ' || 516 | rpad('| ' || v_top_sqls(i).sql_id || ' (' || v_top_sqls(i).sql_child_number || ')', 20) || 517 | rpad('| ' || to_string(v_top_sqls(i).top_sids, p_elements => 5), 23) || 518 | rpad(' |', 8) 519 | else rpad('|', 7) || 520 | rpad('| ', 20) || 521 | rpad('| ', 23) || 522 | rpad(' |', 8) 523 | end; 524 | v_row := v_row || 525 | case 526 | when v_top_waits.exists(i) 527 | then '|' || lpad(to_char((v_top_waits(i).occurrences/v_samples)*100, 'fm9999'),4) || '% ' || 528 | rpad('| ' || substr(v_top_waits(i).wait_name,1,35), 29) || 529 | rpad(' | ' || v_top_waits(i).wait_class, 15) || '|' 530 | else rpad('|', 7) || 531 | rpad('| ', 29) || 532 | rpad(' | ', 15) || 533 | '|' 534 | end; 535 | 536 | v_rows(v_rows.last) := moats_output_ot(v_row); 537 | end loop; 538 | 539 | v_rows.extend(2); 540 | v_rows(v_rows.last-1) := moats_output_ot( 541 | rpad('+',51,'-') || rpad('+',7) || rpad('+',51,'-') || '+' 542 | ); 543 | v_rows(v_rows.last) := gc_space; 544 | 545 | -- Top SQL output - we're going to deliberately loop r-b-r for the sql_ids... 546 | -- -------------------------------------------------------------------------- 547 | v_rows.extend; 548 | v_rows(v_rows.last) := moats_output_ot( 549 | rpad('+ TOP SQL_ID ----+ PLAN_HASH_VALUE + SQL TEXT ', 109, '-') || '+' 550 | ); 551 | for i in 1 .. v_top_sqls.count loop 552 | for r_sql in (select sql_id, child_number, sql_text, plan_hash_value 553 | from v$sql 554 | where sql_id = v_top_sqls(i).sql_id 555 | and child_number = v_top_sqls(i).sql_child_number) 556 | loop 557 | v_rows.extend; 558 | v_rows(v_rows.last) := moats_output_ot( 559 | rpad('| ' || r_sql.sql_id, 17) || 560 | rpad('| ' || r_sql.plan_hash_value, 18) || 561 | rpad('| ' || substr(r_sql.sql_text, 1, 71), 73) || ' |' 562 | ); 563 | if length(r_sql.sql_text) > 74 then 564 | v_rows.extend; 565 | v_rows(v_rows.last) := moats_output_ot( 566 | rpad('| ', 17) || 567 | rpad('| ', 18) || 568 | rpad('| ' || substr(r_sql.sql_text, 72, 71), 73) || ' |' 569 | ); 570 | end if; 571 | v_rows.extend; 572 | v_rows(v_rows.last) := moats_output_ot( 573 | rpad('+ ', 17, '-') || 574 | rpad('-', 18, '-') || 575 | rpad('-', 73, '-') || ' +' 576 | ); 577 | end loop; 578 | end loop; 579 | 580 | return v_rows; 581 | 582 | end top_summary; 583 | 584 | ---------------------------------------------------------------------------- 585 | procedure poll( p_refresh_rate in integer, 586 | p_include_ash in boolean, 587 | p_include_stat in boolean, 588 | p_lower_snap out pls_integer, 589 | p_upper_snap out pls_integer ) is 590 | 591 | v_index pls_integer; 592 | v_refresh_rate integer := nvl(p_refresh_rate, g_params(moats.gc_top_refresh_rate)); 593 | 594 | function snap_index return pls_integer is 595 | begin 596 | return dbms_utility.get_time(); 597 | end snap_index; 598 | 599 | begin 600 | 601 | -- Set starting snap index... 602 | -- -------------------------- 603 | v_index := snap_index(); 604 | p_lower_snap := v_index; 605 | 606 | -- Snap SYSSTAT if required... 607 | -- --------------------------- 608 | if p_include_stat then 609 | snap_stats(v_index, true); 610 | end if; 611 | 612 | -- Snap ASH if required... 613 | -- ----------------------- 614 | if p_include_ash then 615 | for i in 1 .. ceil(v_refresh_rate/g_params(moats.gc_ash_polling_rate)) loop 616 | if i > 1 then 617 | v_index := snap_index; 618 | end if; 619 | snap_ash(v_index); 620 | dbms_lock.sleep(g_params(moats.gc_ash_polling_rate)); 621 | end loop; 622 | end if; 623 | 624 | -- If no ASH samples taken, sleep for refresh rate instead... 625 | -- ---------------------------------------------------------- 626 | if p_include_stat and not p_include_ash then 627 | dbms_lock.sleep(v_refresh_rate); 628 | v_index := snap_index; 629 | end if; 630 | 631 | -- Snap SYSSTAT again if required... 632 | -- --------------------------------- 633 | if p_include_stat then 634 | snap_stats(v_index); 635 | end if; 636 | 637 | -- Set end snap index... 638 | -- --------------------- 639 | p_upper_snap := v_index; 640 | 641 | end poll; 642 | 643 | ---------------------------------------------------------------------------- 644 | -- Determine ASH trailing window size 645 | ---------------------------------------------------------------------------- 646 | function get_ash_window_lower_snap ( 647 | p_lower_snap in pls_integer, 648 | p_upper_snap in pls_integer, 649 | p_refresh_rate in pls_integer, 650 | p_ash_window_size in pls_integer 651 | ) return pls_integer is 652 | 653 | v_snap_count pls_integer; 654 | v_snap pls_integer; 655 | v_ash_window_size pls_integer; 656 | begin 657 | v_ash_window_size := nvl(p_ash_window_size, get_parameter(moats.gc_ash_window_size)); 658 | -- By default no ASH trailing window or if refresh rate greater than window size 659 | -- ----------------------------------------------------------------------------- 660 | if v_ash_window_size is null or p_refresh_rate >= v_ash_window_size then 661 | v_snap := p_lower_snap; 662 | else 663 | v_snap_count := 1; 664 | v_snap := p_upper_snap; 665 | while v_snap_count < v_ash_window_size and g_ash.prior(v_snap) is not null loop 666 | v_snap_count := v_snap_count + 1; 667 | v_snap := g_ash.prior(v_snap); 668 | end loop; 669 | end if; 670 | 671 | return v_snap; 672 | end get_ash_window_lower_snap; 673 | 674 | ---------------------------------------------------------------------------- 675 | function top ( 676 | p_refresh_rate in integer default null, 677 | p_ash_window_size in integer default null 678 | ) return moats_output_ntt pipelined is 679 | 680 | v_lower_snap pls_integer; 681 | v_upper_snap pls_integer; 682 | v_row varchar2(4000); 683 | v_rows moats_output_ntt := moats_output_ntt(); 684 | v_cnt pls_integer := 0; 685 | 686 | begin 687 | 688 | -- Initial clear screen and stabiliser... 689 | -- -------------------------------------- 690 | v_rows := banner(); 691 | -- fill the initial "blank screen" (this is needed for arraysize = 72 to work) 692 | for i in 1 .. gc_screen_size loop 693 | pipe row (gc_space); 694 | end loop; 695 | -- print banner onto the top of the screen 696 | for i in 1 .. v_rows.count loop 697 | pipe row (v_rows(i)); 698 | end loop; 699 | -- fill the rest of the visible screen 700 | for i in 1 .. gc_screen_size-(v_rows.count+1) loop 701 | pipe row (gc_space); 702 | end loop; 703 | pipe row (moats_output_ot('Please wait : fetching data for first refresh...')); 704 | 705 | -- Begin TOP refreshes... 706 | -- ---------------------- 707 | loop 708 | 709 | -- Clear screen... 710 | -- --------------- 711 | for i in 1 .. gc_screen_size loop 712 | pipe row (gc_space); 713 | end loop; 714 | 715 | -- Take some ASH/STAT samples... 716 | -- ----------------------------- 717 | poll( p_refresh_rate => p_refresh_rate, 718 | p_include_ash => true, 719 | p_include_stat => true, 720 | p_lower_snap => v_lower_snap, 721 | p_upper_snap => v_upper_snap ); 722 | 723 | -- Banner... 724 | -- --------- 725 | v_rows := banner(); 726 | for i in 1 .. v_rows.count loop 727 | pipe row (v_rows(i)); 728 | end loop; 729 | pipe row (gc_space); 730 | v_cnt := v_rows.count + 1; 731 | 732 | -- Instance summary... 733 | -- ------------------- 734 | v_rows := instance_summary( p_lower_snap => v_lower_snap, 735 | p_upper_snap => v_upper_snap ); 736 | for i in 1 .. v_rows.count loop 737 | pipe row (v_rows(i)); 738 | end loop; 739 | pipe row (gc_space); 740 | v_cnt := v_cnt + v_rows.count + 1; 741 | 742 | v_lower_snap := get_ash_window_lower_snap( p_lower_snap => v_lower_snap, 743 | p_upper_snap => v_upper_snap, 744 | p_refresh_rate => p_refresh_rate, 745 | p_ash_window_size => p_ash_window_size ); 746 | 747 | -- Top SQL and waits section... 748 | -- ---------------------------- 749 | v_rows := top_summary( p_lower_snap => v_lower_snap, 750 | p_upper_snap => v_upper_snap ); 751 | for i in 1 .. v_rows.count loop 752 | pipe row (v_rows(i)); 753 | end loop; 754 | pipe row (gc_space); 755 | v_cnt := v_cnt + v_rows.count + 1; 756 | 757 | -- Some blank output... 758 | -- -------------------- 759 | if v_cnt < (gc_screen_size) then 760 | for i in 1 .. (gc_screen_size)-v_cnt loop 761 | pipe row (gc_space); 762 | end loop; 763 | end if; 764 | 765 | end loop; 766 | return; 767 | 768 | exception 769 | when no_data_found then 770 | raise_application_error(-20000, 'Error: '||sqlerrm||' at:'||chr(10)||dbms_utility.format_error_backtrace); 771 | end top; 772 | 773 | ---------------------------------------------------------------------------- 774 | function ash ( 775 | p_refresh_rate in integer default null, 776 | p_select in varchar2 default null, 777 | p_where in varchar2 default null, 778 | p_group_by in varchar2 default null, 779 | p_order_by in varchar2 default null 780 | ) return moats_output_ntt pipelined is 781 | 782 | v_lower_snap pls_integer; 783 | v_upper_snap pls_integer; 784 | v_row varchar2(4000); 785 | v_cnt pls_integer := 0; 786 | 787 | -- DBMS_SQL variables... 788 | -- --------------------- 789 | v_sql varchar2(32767); 790 | v_cursor binary_integer; 791 | v_execute integer; 792 | v_desc dbms_sql.desc_tab2; 793 | v_cols integer; 794 | v_value varchar2(4000); 795 | 796 | begin 797 | 798 | -- Build up the dynamic SQL... 799 | -- --------------------------- 800 | v_sql := get_sql( p_select => p_select, 801 | p_from => 'TABLE(moats.get_ash(:b1, :b2))', 802 | p_where => p_where, 803 | p_group_by => p_group_by, 804 | p_order_by => p_order_by ); 805 | 806 | -- Open a cursor for the ASH queries, parse and describe it... 807 | -- ----------------------------------------------------------- 808 | v_cursor := dbms_sql.open_cursor; 809 | dbms_sql.parse(v_cursor, v_sql, dbms_sql.native); 810 | dbms_sql.describe_columns2(v_cursor, v_cols, v_desc); 811 | 812 | -- Take some ASH samples... 813 | -- ------------------------ 814 | poll( p_refresh_rate => p_refresh_rate, 815 | p_include_ash => true, 816 | p_include_stat => false, 817 | p_lower_snap => v_lower_snap, 818 | p_upper_snap => v_upper_snap ); 819 | 820 | -- Bind the ASH snapshots... 821 | -- ------------------------- 822 | dbms_sql.bind_variable(v_cursor, 'b1', v_lower_snap); 823 | dbms_sql.bind_variable(v_cursor, 'b2', v_upper_snap); 824 | 825 | -- Define the columns and variable we are fetching into... 826 | -- ------------------------------------------------------- 827 | for i in 1 .. v_cols loop 828 | dbms_sql.define_column(v_cursor, i, v_value, 4000); 829 | end loop; 830 | 831 | -- Output the heading... 832 | -- --------------------- 833 | for i in 1 .. v_cols loop 834 | v_row := v_row || '|' || v_desc(i).col_name; 835 | end loop; 836 | pipe row (moats_output_ot(v_row)); 837 | v_row := null; 838 | 839 | -- Start fetching... 840 | -- ----------------- 841 | v_execute := dbms_sql.execute(v_cursor); 842 | 843 | while dbms_sql.fetch_rows(v_cursor) > 0 loop 844 | for i in 1 .. v_cols loop 845 | dbms_sql.column_value(v_cursor, i, v_value); 846 | v_row := v_row || '|' || v_value; 847 | end loop; 848 | pipe row (moats_output_ot(v_row)); 849 | v_row := null; 850 | end loop; 851 | dbms_sql.close_cursor(v_cursor); --<-- will never be reached on an infinite loop with ctrl-c 852 | 853 | return; 854 | 855 | exception 856 | when others then 857 | dbms_sql.close_cursor(v_cursor); 858 | raise_application_error (-20000, 'Error: ' || sqlerrm || ' at:' || chr(10) || dbms_utility.format_error_backtrace, true); 859 | end ash; 860 | 861 | ---------------------------------------------------------------------------- 862 | function get_ash ( 863 | p_lower_snap in pls_integer default null, 864 | p_upper_snap in pls_integer default null, 865 | p_return_set in pls_integer default moats.gc_all_rows 866 | ) return moats_ash_ntt pipelined is 867 | v_lower_snap pls_integer := nvl(p_lower_snap, g_ash.first); 868 | v_upper_snap pls_integer := nvl(p_upper_snap, g_ash.last); 869 | v_snap pls_integer; 870 | v_exit boolean := false; 871 | begin 872 | v_snap := v_lower_snap; 873 | while v_snap is not null and not v_exit loop 874 | for i in 1 .. g_ash(v_snap).count loop 875 | -- Ignore dummy records 876 | if g_ash(v_snap)(i).sid is not null then 877 | pipe row (g_ash(v_snap)(i)); 878 | end if; 879 | end loop; 880 | v_exit := (v_snap = v_upper_snap); 881 | v_snap := case p_return_set 882 | when moats.gc_all_rows 883 | then g_ash.next(v_snap) 884 | else v_upper_snap 885 | end; 886 | end loop; 887 | return; 888 | end get_ash; 889 | 890 | begin 891 | restore_default_parameters(); 892 | end moats; 893 | / 894 | -------------------------------------------------------------------------------- /moats.pks: -------------------------------------------------------------------------------- 1 | create or replace package moats as 2 | 3 | -- -------------------------------------------------------------------------- 4 | -- MOATS v1.0 (c) Tanel Poder & Adrian Billington, 2010 5 | -- 6 | -- See supplied README for usage and disclaimers. 7 | -- 8 | -- http://www.tanelpoder.com 9 | -- http://www.oracle-developer.net 10 | -- -------------------------------------------------------------------------- 11 | 12 | -- Pipelined function to show TOP instance summary activity. The refresh rate 13 | -- defines how many ASH/SYSSTAT samples to take and is roughly equivalent to 14 | -- the number of seconds between screen refreshes... 15 | -- -------------------------------------------------------------------------- 16 | function top ( 17 | p_refresh_rate in integer default null, 18 | p_ash_window_size in integer default null 19 | ) return moats_output_ntt pipelined; 20 | 21 | -- Helper procedure to size window to TOP output... 22 | -- -------------------------------------------------------------------------- 23 | procedure format_window; 24 | 25 | -- Internal Use Only 26 | -- ----------------- 27 | -- All functions and procedures from this point onwards are for internal use 28 | -- only in v1.01. Some of these will be exposed in future versions of MOATS. 29 | 30 | -- Pipelined function to return dynamic samples, queries, aggregations etc 31 | -- of active session data. The refresh rate defines (in seconds) how many 32 | -- ASH samples to take before running the query components... 33 | -- -------------------------------------------------------------------------- 34 | function ash ( 35 | p_refresh_rate in integer default null, 36 | p_select in varchar2 default null, 37 | p_where in varchar2 default null, 38 | p_group_by in varchar2 default null, 39 | p_order_by in varchar2 default null 40 | ) return moats_output_ntt pipelined; 41 | 42 | -- Until 11g you can't bind UDTs into DBMS_SQL cursors, so this is an 43 | -- internal workaround. Can also be used to query all of the collected ASH 44 | -- samples. Note that gc_all_rows returns all ASH records between the two 45 | -- snapshots and gc_deltas returns only the lower and upper snapshots... 46 | -- -------------------------------------------------------------------------- 47 | gc_all_rows constant pls_integer := 0; 48 | gc_deltas constant pls_integer := 1; 49 | 50 | function get_ash ( 51 | p_lower_snap in pls_integer default null, 52 | p_upper_snap in pls_integer default null, 53 | p_return_set in pls_integer default moats.gc_all_rows 54 | ) return moats_ash_ntt pipelined; 55 | 56 | -- Constants, get/set for moats parameters such as polling rate, ASH size... 57 | -- -------------------------------------------------------------------------- 58 | gc_ash_polling_rate constant pls_integer := 0; 59 | gc_ash_threshold constant pls_integer := 1; 60 | gc_top_refresh_rate constant pls_integer := 2; 61 | gc_ash_window_size constant pls_integer := 3; 62 | 63 | procedure set_parameter( 64 | p_parameter_code in pls_integer, 65 | p_parameter_value in integer 66 | ); 67 | 68 | function get_parameter( 69 | p_parameter_code in pls_integer 70 | ) return integer; 71 | 72 | procedure restore_default_parameters; 73 | 74 | -- Debugging... 75 | -- -------------------------------------------------------------------------- 76 | procedure show_snaps; 77 | 78 | end moats; 79 | / 80 | 81 | -------------------------------------------------------------------------------- /moats_install.sql: -------------------------------------------------------------------------------- 1 | 2 | set define off 3 | set pause on 4 | 5 | prompt 6 | prompt 7 | prompt ************************************************************************** 8 | prompt ************************************************************************** 9 | prompt 10 | prompt MOATS Installer (for 10.2+ databases) 11 | prompt ===================================== 12 | prompt 13 | prompt This will install MOATS v1.0 into the current schema. 14 | prompt 15 | prompt Ensure that the target schema has the necessary privileges described 16 | prompt in the README.txt file. 17 | prompt 18 | prompt To continue press Enter. To quit press Ctrl-C. 19 | prompt 20 | prompt (c) www.oracle-developer.net & www.tanelpoder.com 21 | prompt 22 | prompt ************************************************************************** 23 | prompt ************************************************************************** 24 | prompt 25 | prompt 26 | 27 | pause 28 | 29 | prompt Creating types... 30 | @@moats_types.sql 31 | 32 | prompt Creating package... 33 | @@moats.pks 34 | @@moats.pkb 35 | 36 | prompt Creating view... 37 | @@moats_views.sql 38 | 39 | set define on 40 | set pause off 41 | 42 | -------------------------------------------------------------------------------- /moats_privs_grant.sql: -------------------------------------------------------------------------------- 1 | 2 | set pause on 3 | 4 | define moats_priv_target = &moats_priv_target; 5 | 6 | prompt 7 | prompt 8 | prompt ************************************************************************** 9 | prompt ************************************************************************** 10 | prompt 11 | prompt MOATS Installer: Privileges 12 | prompt =========================== 13 | prompt 14 | prompt This will grant required privileges to &moats_priv_target.. 15 | prompt 16 | prompt To continue press Enter. To quit press Ctrl-C. 17 | prompt 18 | prompt (c) www.oracle-developer.net, www.tanelpoder.com 19 | prompt 20 | prompt ************************************************************************** 21 | prompt ************************************************************************** 22 | prompt 23 | prompt 24 | 25 | pause 26 | 27 | grant create view to &moats_priv_target; 28 | grant create type to &moats_priv_target; 29 | grant create table to &moats_priv_target; 30 | grant create procedure to &moats_priv_target; 31 | grant execute on dbms_lock to &moats_priv_target; 32 | grant select on v_$session to &moats_priv_target; 33 | grant select on v_$statname to &moats_priv_target; 34 | grant select on v_$sysstat to &moats_priv_target; 35 | grant select on v_$latch to &moats_priv_target; 36 | grant select on v_$timer to &moats_priv_target; 37 | grant select on v_$sql to &moats_priv_target; 38 | 39 | undefine moats_priv_target; 40 | 41 | set pause off 42 | -------------------------------------------------------------------------------- /moats_privs_revoke.sql: -------------------------------------------------------------------------------- 1 | 2 | set define on 3 | set pause on 4 | 5 | define moats_priv_target = &moats_priv_target; 6 | 7 | prompt 8 | prompt 9 | prompt ************************************************************************** 10 | prompt ************************************************************************** 11 | prompt 12 | prompt MOATS Uninstaller: Revoke Privileges 13 | prompt ==================================== 14 | prompt 15 | prompt This will revoke MOATS privileges from &moats_priv_target.. 16 | prompt 17 | prompt To continue press Enter. To quit press Ctrl-C. 18 | prompt 19 | prompt (c) www.oracle-developer.net, www.tanelpoder.com 20 | prompt 21 | prompt ************************************************************************** 22 | prompt ************************************************************************** 23 | prompt 24 | prompt 25 | 26 | pause 27 | 28 | revoke create view from &moats_priv_target; 29 | revoke create type from &moats_priv_target; 30 | revoke create table from &moats_priv_target; 31 | revoke create procedure from &moats_priv_target; 32 | revoke execute on dbms_lock from &moats_priv_target; 33 | revoke select on v_$session from &moats_priv_target; 34 | revoke select on v_$statname from &moats_priv_target; 35 | revoke select on v_$sysstat from &moats_priv_target; 36 | revoke select on v_$latch from &moats_priv_target; 37 | revoke select on v_$timer from &moats_priv_target; 38 | revoke select on v_$sql from &moats_priv_target; 39 | 40 | undefine moats_priv_target; 41 | 42 | set pause off 43 | -------------------------------------------------------------------------------- /moats_remove.sql: -------------------------------------------------------------------------------- 1 | 2 | set define off 3 | set pause on 4 | 5 | prompt 6 | prompt 7 | prompt ************************************************************************** 8 | prompt ************************************************************************** 9 | prompt 10 | prompt MOATS Uninstaller 11 | prompt ================= 12 | prompt 13 | prompt This will uninstall MOATS. 14 | prompt 15 | prompt To continue press Enter. To quit press Ctrl-C. 16 | prompt 17 | prompt (c) www.oracle-developer.net & www.tanelpoder.com 18 | prompt 19 | prompt ************************************************************************** 20 | prompt ************************************************************************** 21 | prompt 22 | prompt 23 | 24 | pause 25 | 26 | prompt Removing MOATS... 27 | 28 | drop view top; 29 | drop package moats; 30 | drop type moats_output_ntt; 31 | drop type moats_output_ot; 32 | drop type moats_v2_ntt; 33 | drop type moats_ash_ntt; 34 | drop type moats_ash_ot; 35 | drop type moats_stat_ntt; 36 | drop type moats_stat_ot; 37 | 38 | prompt 39 | prompt 40 | prompt ************************************************************************** 41 | prompt Uninstall complete. 42 | prompt ************************************************************************** 43 | 44 | -------------------------------------------------------------------------------- /moats_settings.sql: -------------------------------------------------------------------------------- 1 | 2 | set arrays 72 3 | set lines 110 4 | set head off 5 | set tab off 6 | set pages 0 7 | set serveroutput on format wrapped 8 | -------------------------------------------------------------------------------- /moats_types.sql: -------------------------------------------------------------------------------- 1 | 2 | create type moats_v2_ntt as table of varchar2(4000); 3 | / 4 | 5 | create type moats_output_ot as object 6 | ( output varchar2(4000) 7 | ); 8 | / 9 | 10 | create type moats_output_ntt as table of moats_output_ot; 11 | / 12 | 13 | create type moats_ash_ot as object 14 | ( snaptime timestamp 15 | , saddr raw(8) 16 | , sid number 17 | , serial# number 18 | , audsid number 19 | , paddr raw(8) 20 | , user# number 21 | , username varchar2(64) 22 | , command number 23 | , ownerid number 24 | , taddr varchar2(64) 25 | , lockwait varchar2(64) 26 | , status varchar2(64) 27 | , server varchar2(64) 28 | , schema# number 29 | , schemaname varchar2(64) 30 | , osuser varchar2(64) 31 | , process varchar2(64) 32 | , machine varchar2(64) 33 | , terminal varchar2(64) 34 | , program varchar2(64) 35 | , type varchar2(64) 36 | , sql_address raw(8) 37 | , sql_hash_value number 38 | , sql_id varchar2(64) 39 | , sql_child_number number 40 | , prev_sql_addr raw(8) 41 | , prev_hash_value number 42 | , prev_sql_id varchar2(64) 43 | , prev_child_number number 44 | , module varchar2(64) 45 | , module_hash number 46 | , action varchar2(64) 47 | , action_hash number 48 | , client_info varchar2(64) 49 | , fixed_table_sequence number 50 | , row_wait_obj# number 51 | , row_wait_file# number 52 | , row_wait_block# number 53 | , row_wait_row# number 54 | , logon_time date 55 | , last_call_et number 56 | , pdml_enabled varchar2(64) 57 | , failover_type varchar2(64) 58 | , failover_method varchar2(64) 59 | , failed_over varchar2(64) 60 | , resource_consumer_group varchar2(64) 61 | , pdml_status varchar2(64) 62 | , pddl_status varchar2(64) 63 | , pq_status varchar2(64) 64 | , current_queue_duration number 65 | , client_identifier varchar2(64) 66 | , blocking_session_status varchar2(64) 67 | , blocking_instance number 68 | , blocking_session number 69 | , seq# number 70 | , event# number 71 | , event varchar2(64) 72 | , p1text varchar2(64) 73 | , p1 number 74 | , p1raw raw(8) 75 | , p2text varchar2(64) 76 | , p2 number 77 | , p2raw raw(8) 78 | , p3text varchar2(64) 79 | , p3 number 80 | , p3raw raw(8) 81 | , wait_class_id number 82 | , wait_class# number 83 | , wait_class varchar2(64) 84 | , wait_time number 85 | , seconds_in_wait number 86 | , state varchar2(64) 87 | , service_name varchar2(64) 88 | , sql_trace varchar2(64) 89 | , sql_trace_waits varchar2(64) 90 | , sql_trace_binds varchar2(64) 91 | ); 92 | / 93 | 94 | create type moats_ash_ntt as table of moats_ash_ot; 95 | / 96 | 97 | create type moats_stat_ot as object 98 | ( type varchar2(100) 99 | , name varchar2(100) 100 | , value number 101 | ); 102 | / 103 | 104 | create type moats_stat_ntt as table of moats_stat_ot; 105 | / 106 | 107 | 108 | -------------------------------------------------------------------------------- /moats_views.sql: -------------------------------------------------------------------------------- 1 | 2 | create or replace view top 3 | as 4 | select * 5 | from table(moats.top); 6 | --------------------------------------------------------------------------------