├── LICENSE ├── README.txt ├── SessInfo.sql ├── adg.sql ├── ash.sql ├── ash2.sql ├── ash3.sql ├── ash4.sql ├── ash_h.sql ├── ash_report.sql ├── ash_sess.sql ├── ash_top.sql ├── awr_global_report.sql ├── awr_report.sql ├── awr_snapshots.sql ├── awr_sql_report.sql ├── binds.sql ├── ehm.sql ├── ehm_local.sql ├── ehm_micro.sql ├── ehm_micro_local.sql ├── eventmetric.sql ├── explain.sql ├── explain_awr.sql ├── filemetric.sql ├── flash.sql ├── iometric.sql ├── iometric_details.sql ├── jobs_running.sql ├── kill.sql ├── kill_select.sql ├── load.sql ├── locks.sql ├── locks_10g.sql ├── locks_details.sql ├── login.sql ├── longops.sql ├── longops_10g.sql ├── longops_details.sql ├── monitor.sql ├── monitor_details.sql ├── monitor_plan.sql ├── monitor_report_sid.sql ├── monitor_report_sid_active.sql ├── monitor_report_sql_id.sql ├── monitor_report_sql_id_active.sql ├── obj.sql ├── reports └── README.txt ├── sessmetric.sql ├── sql.sql ├── sysmetric.sql ├── sysmetric_details.sql ├── top.sql ├── top_10g.sql └── transactions.sql /LICENSE: -------------------------------------------------------------------------------- 1 | GNU GENERAL PUBLIC LICENSE 2 | Version 2, June 1991 3 | 4 | Copyright (C) 1989, 1991 Free Software Foundation, Inc., 5 | 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA 6 | Everyone is permitted to copy and distribute verbatim copies 7 | of this license document, but changing it is not allowed. 8 | 9 | Preamble 10 | 11 | The licenses for most software are designed to take away your 12 | freedom to share and change it. By contrast, the GNU General Public 13 | License is intended to guarantee your freedom to share and change free 14 | software--to make sure the software is free for all its users. This 15 | General Public License applies to most of the Free Software 16 | Foundation's software and to any other program whose authors commit to 17 | using it. (Some other Free Software Foundation software is covered by 18 | the GNU Lesser General Public License instead.) You can apply it to 19 | your programs, too. 20 | 21 | When we speak of free software, we are referring to freedom, not 22 | price. Our General Public Licenses are designed to make sure that you 23 | have the freedom to distribute copies of free software (and charge for 24 | this service if you wish), that you receive source code or can get it 25 | if you want it, that you can change the software or use pieces of it 26 | in new free programs; and that you know you can do these things. 27 | 28 | To protect your rights, we need to make restrictions that forbid 29 | anyone to deny you these rights or to ask you to surrender the rights. 30 | These restrictions translate to certain responsibilities for you if you 31 | distribute copies of the software, or if you modify it. 32 | 33 | For example, if you distribute copies of such a program, whether 34 | gratis or for a fee, you must give the recipients all the rights that 35 | you have. You must make sure that they, too, receive or can get the 36 | source code. And you must show them these terms so they know their 37 | rights. 38 | 39 | We protect your rights with two steps: (1) copyright the software, and 40 | (2) offer you this license which gives you legal permission to copy, 41 | distribute and/or modify the software. 42 | 43 | Also, for each author's protection and ours, we want to make certain 44 | that everyone understands that there is no warranty for this free 45 | software. If the software is modified by someone else and passed on, we 46 | want its recipients to know that what they have is not the original, so 47 | that any problems introduced by others will not reflect on the original 48 | authors' reputations. 49 | 50 | Finally, any free program is threatened constantly by software 51 | patents. We wish to avoid the danger that redistributors of a free 52 | program will individually obtain patent licenses, in effect making the 53 | program proprietary. To prevent this, we have made it clear that any 54 | patent must be licensed for everyone's free use or not licensed at all. 55 | 56 | The precise terms and conditions for copying, distribution and 57 | modification follow. 58 | 59 | GNU GENERAL PUBLIC LICENSE 60 | TERMS AND CONDITIONS FOR COPYING, DISTRIBUTION AND MODIFICATION 61 | 62 | 0. This License applies to any program or other work which contains 63 | a notice placed by the copyright holder saying it may be distributed 64 | under the terms of this General Public License. The "Program", below, 65 | refers to any such program or work, and a "work based on the Program" 66 | means either the Program or any derivative work under copyright law: 67 | that is to say, a work containing the Program or a portion of it, 68 | either verbatim or with modifications and/or translated into another 69 | language. (Hereinafter, translation is included without limitation in 70 | the term "modification".) Each licensee is addressed as "you". 71 | 72 | Activities other than copying, distribution and modification are not 73 | covered by this License; they are outside its scope. The act of 74 | running the Program is not restricted, and the output from the Program 75 | is covered only if its contents constitute a work based on the 76 | Program (independent of having been made by running the Program). 77 | Whether that is true depends on what the Program does. 78 | 79 | 1. You may copy and distribute verbatim copies of the Program's 80 | source code as you receive it, in any medium, provided that you 81 | conspicuously and appropriately publish on each copy an appropriate 82 | copyright notice and disclaimer of warranty; keep intact all the 83 | notices that refer to this License and to the absence of any warranty; 84 | and give any other recipients of the Program a copy of this License 85 | along with the Program. 86 | 87 | You may charge a fee for the physical act of transferring a copy, and 88 | you may at your option offer warranty protection in exchange for a fee. 89 | 90 | 2. You may modify your copy or copies of the Program or any portion 91 | of it, thus forming a work based on the Program, and copy and 92 | distribute such modifications or work under the terms of Section 1 93 | above, provided that you also meet all of these conditions: 94 | 95 | a) You must cause the modified files to carry prominent notices 96 | stating that you changed the files and the date of any change. 97 | 98 | b) You must cause any work that you distribute or publish, that in 99 | whole or in part contains or is derived from the Program or any 100 | part thereof, to be licensed as a whole at no charge to all third 101 | parties under the terms of this License. 102 | 103 | c) If the modified program normally reads commands interactively 104 | when run, you must cause it, when started running for such 105 | interactive use in the most ordinary way, to print or display an 106 | announcement including an appropriate copyright notice and a 107 | notice that there is no warranty (or else, saying that you provide 108 | a warranty) and that users may redistribute the program under 109 | these conditions, and telling the user how to view a copy of this 110 | License. (Exception: if the Program itself is interactive but 111 | does not normally print such an announcement, your work based on 112 | the Program is not required to print an announcement.) 113 | 114 | These requirements apply to the modified work as a whole. If 115 | identifiable sections of that work are not derived from the Program, 116 | and can be reasonably considered independent and separate works in 117 | themselves, then this License, and its terms, do not apply to those 118 | sections when you distribute them as separate works. But when you 119 | distribute the same sections as part of a whole which is a work based 120 | on the Program, the distribution of the whole must be on the terms of 121 | this License, whose permissions for other licensees extend to the 122 | entire whole, and thus to each and every part regardless of who wrote it. 123 | 124 | Thus, it is not the intent of this section to claim rights or contest 125 | your rights to work written entirely by you; rather, the intent is to 126 | exercise the right to control the distribution of derivative or 127 | collective works based on the Program. 128 | 129 | In addition, mere aggregation of another work not based on the Program 130 | with the Program (or with a work based on the Program) on a volume of 131 | a storage or distribution medium does not bring the other work under 132 | the scope of this License. 133 | 134 | 3. You may copy and distribute the Program (or a work based on it, 135 | under Section 2) in object code or executable form under the terms of 136 | Sections 1 and 2 above provided that you also do one of the following: 137 | 138 | a) Accompany it with the complete corresponding machine-readable 139 | source code, which must be distributed under the terms of Sections 140 | 1 and 2 above on a medium customarily used for software interchange; or, 141 | 142 | b) Accompany it with a written offer, valid for at least three 143 | years, to give any third party, for a charge no more than your 144 | cost of physically performing source distribution, a complete 145 | machine-readable copy of the corresponding source code, to be 146 | distributed under the terms of Sections 1 and 2 above on a medium 147 | customarily used for software interchange; or, 148 | 149 | c) Accompany it with the information you received as to the offer 150 | to distribute corresponding source code. (This alternative is 151 | allowed only for noncommercial distribution and only if you 152 | received the program in object code or executable form with such 153 | an offer, in accord with Subsection b above.) 154 | 155 | The source code for a work means the preferred form of the work for 156 | making modifications to it. For an executable work, complete source 157 | code means all the source code for all modules it contains, plus any 158 | associated interface definition files, plus the scripts used to 159 | control compilation and installation of the executable. However, as a 160 | special exception, the source code distributed need not include 161 | anything that is normally distributed (in either source or binary 162 | form) with the major components (compiler, kernel, and so on) of the 163 | operating system on which the executable runs, unless that component 164 | itself accompanies the executable. 165 | 166 | If distribution of executable or object code is made by offering 167 | access to copy from a designated place, then offering equivalent 168 | access to copy the source code from the same place counts as 169 | distribution of the source code, even though third parties are not 170 | compelled to copy the source along with the object code. 171 | 172 | 4. You may not copy, modify, sublicense, or distribute the Program 173 | except as expressly provided under this License. Any attempt 174 | otherwise to copy, modify, sublicense or distribute the Program is 175 | void, and will automatically terminate your rights under this License. 176 | However, parties who have received copies, or rights, from you under 177 | this License will not have their licenses terminated so long as such 178 | parties remain in full compliance. 179 | 180 | 5. You are not required to accept this License, since you have not 181 | signed it. However, nothing else grants you permission to modify or 182 | distribute the Program or its derivative works. These actions are 183 | prohibited by law if you do not accept this License. Therefore, by 184 | modifying or distributing the Program (or any work based on the 185 | Program), you indicate your acceptance of this License to do so, and 186 | all its terms and conditions for copying, distributing or modifying 187 | the Program or works based on it. 188 | 189 | 6. Each time you redistribute the Program (or any work based on the 190 | Program), the recipient automatically receives a license from the 191 | original licensor to copy, distribute or modify the Program subject to 192 | these terms and conditions. You may not impose any further 193 | restrictions on the recipients' exercise of the rights granted herein. 194 | You are not responsible for enforcing compliance by third parties to 195 | this License. 196 | 197 | 7. If, as a consequence of a court judgment or allegation of patent 198 | infringement or for any other reason (not limited to patent issues), 199 | conditions are imposed on you (whether by court order, agreement or 200 | otherwise) that contradict the conditions of this License, they do not 201 | excuse you from the conditions of this License. If you cannot 202 | distribute so as to satisfy simultaneously your obligations under this 203 | License and any other pertinent obligations, then as a consequence you 204 | may not distribute the Program at all. For example, if a patent 205 | license would not permit royalty-free redistribution of the Program by 206 | all those who receive copies directly or indirectly through you, then 207 | the only way you could satisfy both it and this License would be to 208 | refrain entirely from distribution of the Program. 209 | 210 | If any portion of this section is held invalid or unenforceable under 211 | any particular circumstance, the balance of the section is intended to 212 | apply and the section as a whole is intended to apply in other 213 | circumstances. 214 | 215 | It is not the purpose of this section to induce you to infringe any 216 | patents or other property right claims or to contest validity of any 217 | such claims; this section has the sole purpose of protecting the 218 | integrity of the free software distribution system, which is 219 | implemented by public license practices. Many people have made 220 | generous contributions to the wide range of software distributed 221 | through that system in reliance on consistent application of that 222 | system; it is up to the author/donor to decide if he or she is willing 223 | to distribute software through any other system and a licensee cannot 224 | impose that choice. 225 | 226 | This section is intended to make thoroughly clear what is believed to 227 | be a consequence of the rest of this License. 228 | 229 | 8. If the distribution and/or use of the Program is restricted in 230 | certain countries either by patents or by copyrighted interfaces, the 231 | original copyright holder who places the Program under this License 232 | may add an explicit geographical distribution limitation excluding 233 | those countries, so that distribution is permitted only in or among 234 | countries not thus excluded. In such case, this License incorporates 235 | the limitation as if written in the body of this License. 236 | 237 | 9. The Free Software Foundation may publish revised and/or new versions 238 | of the General Public License from time to time. Such new versions will 239 | be similar in spirit to the present version, but may differ in detail to 240 | address new problems or concerns. 241 | 242 | Each version is given a distinguishing version number. If the Program 243 | specifies a version number of this License which applies to it and "any 244 | later version", you have the option of following the terms and conditions 245 | either of that version or of any later version published by the Free 246 | Software Foundation. If the Program does not specify a version number of 247 | this License, you may choose any version ever published by the Free Software 248 | Foundation. 249 | 250 | 10. If you wish to incorporate parts of the Program into other free 251 | programs whose distribution conditions are different, write to the author 252 | to ask for permission. For software which is copyrighted by the Free 253 | Software Foundation, write to the Free Software Foundation; we sometimes 254 | make exceptions for this. Our decision will be guided by the two goals 255 | of preserving the free status of all derivatives of our free software and 256 | of promoting the sharing and reuse of software generally. 257 | 258 | NO WARRANTY 259 | 260 | 11. BECAUSE THE PROGRAM IS LICENSED FREE OF CHARGE, THERE IS NO WARRANTY 261 | FOR THE PROGRAM, TO THE EXTENT PERMITTED BY APPLICABLE LAW. EXCEPT WHEN 262 | OTHERWISE STATED IN WRITING THE COPYRIGHT HOLDERS AND/OR OTHER PARTIES 263 | PROVIDE THE PROGRAM "AS IS" WITHOUT WARRANTY OF ANY KIND, EITHER EXPRESSED 264 | OR IMPLIED, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF 265 | MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. THE ENTIRE RISK AS 266 | TO THE QUALITY AND PERFORMANCE OF THE PROGRAM IS WITH YOU. SHOULD THE 267 | PROGRAM PROVE DEFECTIVE, YOU ASSUME THE COST OF ALL NECESSARY SERVICING, 268 | REPAIR OR CORRECTION. 269 | 270 | 12. IN NO EVENT UNLESS REQUIRED BY APPLICABLE LAW OR AGREED TO IN WRITING 271 | WILL ANY COPYRIGHT HOLDER, OR ANY OTHER PARTY WHO MAY MODIFY AND/OR 272 | REDISTRIBUTE THE PROGRAM AS PERMITTED ABOVE, BE LIABLE TO YOU FOR DAMAGES, 273 | INCLUDING ANY GENERAL, SPECIAL, INCIDENTAL OR CONSEQUENTIAL DAMAGES ARISING 274 | OUT OF THE USE OR INABILITY TO USE THE PROGRAM (INCLUDING BUT NOT LIMITED 275 | TO LOSS OF DATA OR DATA BEING RENDERED INACCURATE OR LOSSES SUSTAINED BY 276 | YOU OR THIRD PARTIES OR A FAILURE OF THE PROGRAM TO OPERATE WITH ANY OTHER 277 | PROGRAMS), EVEN IF SUCH HOLDER OR OTHER PARTY HAS BEEN ADVISED OF THE 278 | POSSIBILITY OF SUCH DAMAGES. 279 | 280 | END OF TERMS AND CONDITIONS 281 | 282 | How to Apply These Terms to Your New Programs 283 | 284 | If you develop a new program, and you want it to be of the greatest 285 | possible use to the public, the best way to achieve this is to make it 286 | free software which everyone can redistribute and change under these terms. 287 | 288 | To do so, attach the following notices to the program. It is safest 289 | to attach them to the start of each source file to most effectively 290 | convey the exclusion of warranty; and each file should have at least 291 | the "copyright" line and a pointer to where the full notice is found. 292 | 293 | 294 | Copyright (C) 295 | 296 | This program is free software; you can redistribute it and/or modify 297 | it under the terms of the GNU General Public License as published by 298 | the Free Software Foundation; either version 2 of the License, or 299 | (at your option) any later version. 300 | 301 | This program is distributed in the hope that it will be useful, 302 | but WITHOUT ANY WARRANTY; without even the implied warranty of 303 | MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 304 | GNU General Public License for more details. 305 | 306 | You should have received a copy of the GNU General Public License along 307 | with this program; if not, write to the Free Software Foundation, Inc., 308 | 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA. 309 | 310 | Also add information on how to contact you by electronic and paper mail. 311 | 312 | If the program is interactive, make it output a short notice like this 313 | when it starts in an interactive mode: 314 | 315 | Gnomovision version 69, Copyright (C) year name of author 316 | Gnomovision comes with ABSOLUTELY NO WARRANTY; for details type `show w'. 317 | This is free software, and you are welcome to redistribute it 318 | under certain conditions; type `show c' for details. 319 | 320 | The hypothetical commands `show w' and `show c' should show the appropriate 321 | parts of the General Public License. Of course, the commands you use may 322 | be called something other than `show w' and `show c'; they could even be 323 | mouse-clicks or menu items--whatever suits your program. 324 | 325 | You should also get your employer (if you work as a programmer) or your 326 | school, if any, to sign a "copyright disclaimer" for the program, if 327 | necessary. Here is a sample; alter the names: 328 | 329 | Yoyodyne, Inc., hereby disclaims all copyright interest in the program 330 | `Gnomovision' (which makes passes at compilers) written by James Hacker. 331 | 332 | , 1 April 1989 333 | Ty Coon, President of Vice 334 | 335 | This General Public License does not permit incorporating your program into 336 | proprietary programs. If your program is a subroutine library, you may 337 | consider it more useful to permit linking proprietary applications with the 338 | library. If this is what you want to do, use the GNU Lesser General 339 | Public License instead of this License. 340 | -------------------------------------------------------------------------------- /README.txt: -------------------------------------------------------------------------------- 1 | Command-line DBA Scripts for Oracle, mostly aimed at troubleshooting performance 2 | 3 | Author: Luca.Canali@cern.ch 4 | Current version: June 2015 5 | Description of the scripts at: http://externaltable.blogspot.com/2012/09/on-command-line-dba.html 6 | -------------------------------------------------------------------------------- /SessInfo.sql: -------------------------------------------------------------------------------- 1 | /* 2 | sessinfo.sql, find session info from v$sessino and @process 3 | example: @sessinfo sid=392 4 | @sessinfo "s.username='myuser'" 5 | By Luca 2012 6 | */ 7 | 8 | col username for a10 9 | col "Server User@terminal" for a15 10 | col program for a14 11 | col terminal for a15 12 | col inst for 999 13 | col sid for 9999 14 | col serial# for 99999 15 | col seq for 9999999 16 | col module for a15 17 | col taddr for a8 18 | col OS_PID for 99999 19 | col elaps for 999999 20 | col service_name for a14 21 | col tracefile for a40 22 | 23 | 24 | select s.inst_id,s.sid,s.serial#,s.username,s.osuser||'@'||s.terminal "Server User@terminal",s.program,s.taddr,s.sql_id, s.sql_exec_start, 25 | s.status,s.module, s.service_name, s.event, s.last_call_et elaps, s.logon_time, p.spid OS_PID, p.tracefile 26 | from gv$session s, gv$process p 27 | where p.addr=s.paddr and p.inst_id=s.inst_id 28 | and &1; 29 | 30 | 31 | -------------------------------------------------------------------------------- /adg.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- adg.sql - shows the status of the ADG recovery 3 | -- 4 | 5 | select inst_id, max(timestamp) from gv$recovery_progress group by inst_id; 6 | -------------------------------------------------------------------------------- /ash.sql: -------------------------------------------------------------------------------- 1 | -- ash.sql print info on latest active session for the current instance from ash 2 | -- Luca Canali March 2012, latest change April 2014 3 | 4 | col sample_id for 999999999 5 | col sid_ser# for a10 6 | col username for a26 7 | col sql_id for a13 8 | col exec_plan_ln#_obj# for a45 9 | col dT for 9999 10 | col event for a30 11 | col "DB%,CPU%" for a7 12 | col "R,W_IOPS" for a7 13 | col "R,W_MBPS" for a7 14 | col "PGA,TEMP_MB" for a9 15 | 16 | set verify off 17 | 18 | column sample_id new_value target_sample_id 19 | select sample_id, sample_time from v$active_session_history where rownum=1; 20 | 21 | select sample_id,session_id||' '||session_serial# sid_ser#, 22 | (select us.username from dba_users us where us.user_id=a.user_id)|| 23 | case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 24 | sql_id, round((sysdate-sql_exec_start)*24*3600,1) dT, 25 | sql_opname||'-'||sql_plan_operation||'-'||sql_plan_options||','||sql_plan_line_id||','||nullif(current_obj#,-1) exec_plan_ln#_obj#, 26 | decode(session_state,'WAITING',event,'CPU') event, 27 | --blocking_session, wait_time,time_waited 28 | round(100*TM_DELTA_DB_TIME/TM_DELTA_TIME,0)||', '||round(100*TM_DELTA_CPU_TIME/TM_DELTA_TIME,0) "DB%,CPU%", 29 | round (1000000*delta_read_io_requests/delta_time,0)||', '||round(1000000*delta_write_io_requests/delta_time,0) "R,W_IOPS", 30 | round(delta_read_io_bytes/delta_time,1)||', '||round(delta_write_io_bytes/delta_time,1) "R,W_MBPS", 31 | round(pga_allocated/1000000,1)||', '||round(temp_space_allocated/1000000,1) "PGA,TEMP_MB" 32 | --from v$active_session_history a where sample_id=&target_sample_id; this seems more straightforward but perfoms worst than the code here below 33 | from (select * from v$active_session_history where rownum<500) a 34 | where sample_id=&target_sample_id; 35 | -------------------------------------------------------------------------------- /ash2.sql: -------------------------------------------------------------------------------- 1 | -- ash2.sql print info on latest active session for RAC up to 2 nodes from ash 2 | -- Luca March 2012, last modifued April 2014 3 | 4 | col inst_sid_ser# for a12 5 | col username for a26 6 | col sql_id for a13 7 | col exec_plan_ln#_obj# for a45 8 | col dT for 9999 9 | col event for a30 10 | col "DB%,CPU%" for a8 11 | col "R,W_IOPS" for a8 12 | col "R,W_MBPS" for a8 13 | col "PGA,TEMP_MB" for a8 14 | 15 | break on sample_id skip 1 16 | 17 | select inst_id||'_'||session_id||' '||session_serial# inst_sid_ser#, 18 | (select us.username from dba_users us where us.user_id=a.user_id)|| 19 | case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 20 | sql_id, round((sysdate-sql_exec_start)*24*3600,1) dT, 21 | sql_opname||'-'||sql_plan_operation||'-'||sql_plan_options||','||sql_plan_line_id||','||nullif(current_obj#,-1) exec_plan_ln#_obj#, 22 | decode(session_state,'WAITING',event,'CPU') event, 23 | --blocking_session, wait_time,time_waited 24 | round(100*TM_DELTA_DB_TIME/TM_DELTA_TIME,0)||', '||round(100*TM_DELTA_CPU_TIME/TM_DELTA_TIME,0) "DB%,CPU%", 25 | round (1000000*delta_read_io_requests/delta_time,0)||', '||round(1000000*delta_write_io_requests/delta_time,0) "R,W_IOPS", 26 | round(delta_read_io_bytes/delta_time,1)||', '||round(delta_write_io_bytes/delta_time,1) "R,W_MBPS", 27 | round(pga_allocated/1000000,1)||', '||round(temp_space_allocated/1000000,1) "PGA,TEMP_MB" 28 | from (select * from gv$active_session_history where inst_id=1 and rownum<300) a 29 | where sample_id=(select sample_id from gv$active_session_history where inst_id=1 and rownum=1) 30 | UNION ALL 31 | select inst_id||'_'||session_id||' '||session_serial# sid_ser#, 32 | (select us.username from dba_users us where us.user_id=a.user_id)|| 33 | case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 34 | sql_id, round((sysdate-sql_exec_start)*24*3600,1) dT, 35 | sql_opname||'-'||sql_plan_operation||'-'||sql_plan_options||','||sql_plan_line_id||','||nullif(current_obj#,-1) exec_plan_ln#_obj#, 36 | decode(session_state,'WAITING',event,'CPU') event, 37 | --blocking_session, wait_time,time_waited 38 | round(100*TM_DELTA_DB_TIME/TM_DELTA_TIME,0)||', '||round(100*TM_DELTA_CPU_TIME/TM_DELTA_TIME,0) "DB%,CPU%", 39 | round (1000000*delta_read_io_requests/delta_time,0)||', '||round(1000000*delta_write_io_requests/delta_time,0) "R,W_IOPS", 40 | round(delta_read_io_bytes/delta_time,1)||', '||round(delta_write_io_bytes/delta_time,1) "R,W_MBPS", 41 | round(pga_allocated/1000000,1)||', '||round(temp_space_allocated/1000000,1) "PGA,TEMP_MB" 42 | from (select * from gv$active_session_history where inst_id=2 and rownum<300) a 43 | where sample_id=(select sample_id from gv$active_session_history where inst_id=2 and rownum=1) 44 | / 45 | 46 | 47 | 48 | 49 | 50 | -------------------------------------------------------------------------------- /ash3.sql: -------------------------------------------------------------------------------- 1 | -- ash3.sql print info on latest active session for RAC up to 3 nodes from ash 2 | -- Luca March 2012, last modifued April 2014 3 | 4 | col inst_sid_ser# for a12 5 | col username for a26 6 | col sql_id for a13 7 | col exec_plan_ln#_obj# for a45 8 | col dT for 9999 9 | col event for a30 10 | col "DB%,CPU%" for a8 11 | col "R,W_IOPS" for a8 12 | col "R,W_MBPS" for a8 13 | col "PGA,TEMP_MB" for a8 14 | 15 | 16 | break on sample_id skip 1 17 | 18 | select inst_id||'_'||session_id||' '||session_serial# inst_sid_ser#, 19 | (select us.username from dba_users us where us.user_id=a.user_id)|| 20 | case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 21 | sql_id, round((sysdate-sql_exec_start)*24*3600,1) dT, 22 | sql_opname||'-'||sql_plan_operation||'-'||sql_plan_options||','||sql_plan_line_id||','||nullif(current_obj#,-1) exec_plan_ln#_obj#, 23 | decode(session_state,'WAITING',event,'CPU') event, 24 | --blocking_session, wait_time,time_waited 25 | round(100*TM_DELTA_DB_TIME/TM_DELTA_TIME,0)||', '||round(100*TM_DELTA_CPU_TIME/TM_DELTA_TIME,0) "DB%,CPU%", 26 | round (1000000*delta_read_io_requests/delta_time,0)||', '||round(1000000*delta_write_io_requests/delta_time,0) "R,W_IOPS", 27 | round(delta_read_io_bytes/delta_time,1)||', '||round(delta_write_io_bytes/delta_time,1) "R,W_MBPS", 28 | round(pga_allocated/1000000,1)||', '||round(temp_space_allocated/1000000,1) "PGA,TEMP_MB" 29 | from (select * from gv$active_session_history where inst_id=1 and rownum<300) a 30 | where sample_id=(select sample_id from gv$active_session_history where inst_id=1 and rownum=1) 31 | UNION ALL 32 | select inst_id||'_'||session_id||' '||session_serial# sid_ser#, 33 | (select us.username from dba_users us where us.user_id=a.user_id)|| 34 | case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 35 | sql_id, round((sysdate-sql_exec_start)*24*3600,1) dT, 36 | sql_opname||'-'||sql_plan_operation||'-'||sql_plan_options||','||sql_plan_line_id||','||nullif(current_obj#,-1) exec_plan_ln#_obj#, 37 | decode(session_state,'WAITING',event,'CPU') event, 38 | --blocking_session, wait_time,time_waited 39 | round(100*TM_DELTA_DB_TIME/TM_DELTA_TIME,0)||', '||round(100*TM_DELTA_CPU_TIME/TM_DELTA_TIME,0) "DB%,CPU%", 40 | round (1000000*delta_read_io_requests/delta_time,0)||', '||round(1000000*delta_write_io_requests/delta_time,0) "R,W_IOPS", 41 | round(delta_read_io_bytes/delta_time,1)||', '||round(delta_write_io_bytes/delta_time,1) "R,W_MBPS", 42 | round(pga_allocated/1000000,1)||', '||round(temp_space_allocated/1000000,1) "PGA,TEMP_MB" 43 | from (select * from gv$active_session_history where inst_id=2 and rownum<300) a 44 | where sample_id=(select sample_id from gv$active_session_history where inst_id=2 and rownum=1) 45 | UNION ALL 46 | select inst_id||'_'||session_id||' '||session_serial# sid_ser#, 47 | (select us.username from dba_users us where us.user_id=a.user_id)|| 48 | case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 49 | sql_id, round((sysdate-sql_exec_start)*24*3600,1) dT, 50 | sql_opname||'-'||sql_plan_operation||'-'||sql_plan_options||','||sql_plan_line_id||','||nullif(current_obj#,-1) exec_plan_ln#_obj#, 51 | decode(session_state,'WAITING',event,'CPU') event, 52 | --blocking_session, wait_time,time_waited 53 | round(100*TM_DELTA_DB_TIME/TM_DELTA_TIME,0)||', '||round(100*TM_DELTA_CPU_TIME/TM_DELTA_TIME,0) "DB%,CPU%", 54 | round (1000000*delta_read_io_requests/delta_time,0)||', '||round(1000000*delta_write_io_requests/delta_time,0) "R,W_IOPS", 55 | round(delta_read_io_bytes/delta_time,1)||', '||round(delta_write_io_bytes/delta_time,1) "R,W_MBPS", 56 | round(pga_allocated/1000000,1)||', '||round(temp_space_allocated/1000000,1) "PGA,TEMP_MB" 57 | from (select * from gv$active_session_history where inst_id=3 and rownum<300) a 58 | where sample_id=(select sample_id from gv$active_session_history where inst_id=3 and rownum=1) 59 | / 60 | 61 | 62 | 63 | 64 | 65 | -------------------------------------------------------------------------------- /ash4.sql: -------------------------------------------------------------------------------- 1 | -- ash4.sql print info on latest active session for RAC up to 4 nodes from ash 2 | -- Luca March 2012, last modifued April 2014 3 | 4 | col inst_sid_ser# for a12 5 | col username for a26 6 | col sql_id for a13 7 | col exec_plan_ln#_obj# for a45 8 | col dT for 9999 9 | col event for a30 10 | col "DB%,CPU%" for a8 11 | col "R,W_IOPS" for a8 12 | col "R,W_MBPS" for a8 13 | col "PGA,TEMP_MB" for a8 14 | 15 | 16 | break on sample_id skip 1 17 | 18 | select inst_id||'_'||session_id||' '||session_serial# inst_sid_ser#, 19 | (select us.username from dba_users us where us.user_id=a.user_id)|| 20 | case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 21 | sql_id, round((sysdate-sql_exec_start)*24*3600,1) dT, 22 | sql_opname||'-'||sql_plan_operation||'-'||sql_plan_options||','||sql_plan_line_id||','||nullif(current_obj#,-1) exec_plan_ln#_obj#, 23 | decode(session_state,'WAITING',event,'CPU') event, 24 | --blocking_session, wait_time,time_waited 25 | round(100*TM_DELTA_DB_TIME/TM_DELTA_TIME,0)||', '||round(100*TM_DELTA_CPU_TIME/TM_DELTA_TIME,0) "DB%,CPU%", 26 | round (1000000*delta_read_io_requests/delta_time,0)||', '||round(1000000*delta_write_io_requests/delta_time,0) "R,W_IOPS", 27 | round(delta_read_io_bytes/delta_time,1)||', '||round(delta_write_io_bytes/delta_time,1) "R,W_MBPS", 28 | round(pga_allocated/1000000,1)||', '||round(temp_space_allocated/1000000,1) "PGA,TEMP_MB" 29 | from (select * from gv$active_session_history where inst_id=1 and rownum<300) a 30 | where sample_id=(select sample_id from gv$active_session_history where inst_id=1 and rownum=1) 31 | UNION ALL 32 | select inst_id||'_'||session_id||' '||session_serial# sid_ser#, 33 | (select us.username from dba_users us where us.user_id=a.user_id)|| 34 | case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 35 | sql_id, round((sysdate-sql_exec_start)*24*3600,1) dT, 36 | sql_opname||'-'||sql_plan_operation||'-'||sql_plan_options||','||sql_plan_line_id||','||nullif(current_obj#,-1) exec_plan_ln#_obj#, 37 | decode(session_state,'WAITING',event,'CPU') event, 38 | --blocking_session, wait_time,time_waited 39 | round(100*TM_DELTA_DB_TIME/TM_DELTA_TIME,0)||', '||round(100*TM_DELTA_CPU_TIME/TM_DELTA_TIME,0) "DB%,CPU%", 40 | round (1000000*delta_read_io_requests/delta_time,0)||', '||round(1000000*delta_write_io_requests/delta_time,0) "R,W_IOPS", 41 | round(delta_read_io_bytes/delta_time,1)||', '||round(delta_write_io_bytes/delta_time,1) "R,W_MBPS", 42 | round(pga_allocated/1000000,1)||', '||round(temp_space_allocated/1000000,1) "PGA,TEMP_MB" 43 | from (select * from gv$active_session_history where inst_id=2 and rownum<300) a 44 | where sample_id=(select sample_id from gv$active_session_history where inst_id=2 and rownum=1) 45 | UNION ALL 46 | select inst_id||'_'||session_id||' '||session_serial# sid_ser#, 47 | (select us.username from dba_users us where us.user_id=a.user_id)|| 48 | case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 49 | sql_id, round((sysdate-sql_exec_start)*24*3600,1) dT, 50 | sql_opname||'-'||sql_plan_operation||'-'||sql_plan_options||','||sql_plan_line_id||','||nullif(current_obj#,-1) exec_plan_ln#_obj#, 51 | decode(session_state,'WAITING',event,'CPU') event, 52 | --blocking_session, wait_time,time_waited 53 | round(100*TM_DELTA_DB_TIME/TM_DELTA_TIME,0)||', '||round(100*TM_DELTA_CPU_TIME/TM_DELTA_TIME,0) "DB%,CPU%", 54 | round (1000000*delta_read_io_requests/delta_time,0)||', '||round(1000000*delta_write_io_requests/delta_time,0) "R,W_IOPS", 55 | round(delta_read_io_bytes/delta_time,1)||', '||round(delta_write_io_bytes/delta_time,1) "R,W_MBPS", 56 | round(pga_allocated/1000000,1)||', '||round(temp_space_allocated/1000000,1) "PGA,TEMP_MB" 57 | from (select * from gv$active_session_history where inst_id=3 and rownum<300) a 58 | where sample_id=(select sample_id from gv$active_session_history where inst_id=3 and rownum=1) 59 | UNION ALL 60 | select inst_id||'_'||session_id||' '||session_serial# sid_ser#, 61 | (select us.username from dba_users us where us.user_id=a.user_id)|| 62 | case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 63 | sql_id, round((sysdate-sql_exec_start)*24*3600,1) dT, 64 | sql_opname||'-'||sql_plan_operation||'-'||sql_plan_options||','||sql_plan_line_id||','||nullif(current_obj#,-1) exec_plan_ln#_obj#, 65 | decode(session_state,'WAITING',event,'CPU') event, 66 | --blocking_session, wait_time,time_waited 67 | round(100*TM_DELTA_DB_TIME/TM_DELTA_TIME,0)||', '||round(100*TM_DELTA_CPU_TIME/TM_DELTA_TIME,0) "DB%,CPU%", 68 | round (1000000*delta_read_io_requests/delta_time,0)||', '||round(1000000*delta_write_io_requests/delta_time,0) "R,W_IOPS", 69 | round(delta_read_io_bytes/delta_time,1)||', '||round(delta_write_io_bytes/delta_time,1) "R,W_MBPS", 70 | round(pga_allocated/1000000,1)||', '||round(temp_space_allocated/1000000,1) "PGA,TEMP_MB" 71 | from (select * from gv$active_session_history where inst_id=4 and rownum<300) a 72 | where sample_id=(select sample_id from gv$active_session_history where inst_id=4 and rownum=1) 73 | / 74 | 75 | 76 | 77 | 78 | 79 | -------------------------------------------------------------------------------- /ash_h.sql: -------------------------------------------------------------------------------- 1 | -- print history info from from ash for 11.2 2 | -- Luca March 2012 3 | -- 4 | -- usage @ash_h 5 | -- 6 | 7 | col sample_id for 999999999 8 | col sid_ser# for a10 9 | col username for a26 10 | col sql_id for a13 11 | col exec_plan_ln#_obj# for a45 12 | col dT for 9999 13 | col event for a30 14 | col "DB%,CPU%" for a7 15 | col "R,W_IOPS" for a7 16 | col "R,W_MBPS" for a7 17 | col "PGA,TEMP_MB" for a9 18 | 19 | break on sample_id skip 1 20 | 21 | select sample_id,session_id||' '||session_serial# sid_ser#, 22 | (select us.name from sys.user$ us where us.user#=user_id)||case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 23 | sql_id, round((sysdate-sql_exec_start)*24*3600,1) dT, 24 | sql_opname||'-'||sql_plan_operation||'-'||sql_plan_options||','||sql_plan_line_id||','||nullif(current_obj#,-1) exec_plan_ln#_obj#, 25 | decode(session_state,'WAITING',event,'CPU') event, 26 | --blocking_session, wait_time,time_waited 27 | round(100*TM_DELTA_DB_TIME/TM_DELTA_TIME,0)||', '||round(100*TM_DELTA_CPU_TIME/TM_DELTA_TIME,0) "DB%,CPU%", 28 | round (1000000*delta_read_io_requests/delta_time,0)||', '||round(1000000*delta_write_io_requests/delta_time,0) "R,W_IOPS", 29 | round(delta_read_io_bytes/delta_time,1)||', '||round(delta_write_io_bytes/delta_time,1) "R,W_MBPS", 30 | round(pga_allocated/1000000,1)||', '||round(temp_space_allocated/1000000,1) "PGA,TEMP_MB" 31 | from v$active_session_history 32 | where sample_time>systimestamp-numtodsinterval(&1,'second'); 33 | 34 | 35 | 36 | -------------------------------------------------------------------------------- /ash_report.sql: -------------------------------------------------------------------------------- 1 | -- generates and prints ASH report for current instance 2 | -- Luca Apr 2012 3 | -- Usage: @awr_report begin_time end_time 4 | -- example: @ash_report sysdate-1/24 sysdate 5 | 6 | -- can add more parameters: http://docs.oracle.com/cd/E11882_01/appdev.112/e25788/d_workload_repos.htm#autoId10 7 | 8 | 9 | set pages 0 10 | set lines 1500 11 | set verify off 12 | set heading off 13 | set termout off 14 | 15 | host del reports\scratch_ash.html 16 | spool reports\scratch_ash.html 17 | select * from table(DBMS_WORKLOAD_REPOSITORY.Ash_REPORT_HTML((select dbid from v$database),(select instance_number from v$instance),&1,&2)); 18 | spool off 19 | set heading on 20 | set termout on 21 | set pages 1000 22 | 23 | host reports\scratch_ash.html 24 | 25 | -------------------------------------------------------------------------------- /ash_sess.sql: -------------------------------------------------------------------------------- 1 | -- print history info from from ash for 11.2 2 | -- Luca March 2012 3 | -- 4 | -- usage @ash_sess inst_id sid n#_sec 5 | -- 6 | 7 | col sample_id for 999999999 8 | col sid_ser# for a10 9 | col username for a26 10 | col sql_id for a13 11 | col top_level_sql_id for a13 12 | col exec_plan_ln#_obj# for a45 13 | col dT for 9999 14 | col event for a30 15 | col "DB%,CPU%" for a8 16 | col "R,W_IOPS" for a8 17 | col "R,W_MBPS" for a8 18 | col "PGA,TEMP_MB" for a11 19 | 20 | 21 | select session_id||' '||session_serial# sid_ser#, 22 | (select us.name from sys.user$ us where us.user#=user_id)||case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username 23 | from gv$active_session_history 24 | where inst_id=&1 and session_id=&2 25 | and rownum=1; 26 | 27 | break on sample_id skip 1 28 | 29 | select sample_id, 30 | sql_id, top_level_sql_id, 31 | round((sysdate-sql_exec_start)*24*3600,1) dT, 32 | sql_opname||'-'||sql_plan_operation||'-'||sql_plan_options||','||sql_plan_line_id||','||nullif(current_obj#,-1) exec_plan_ln#_obj#, 33 | decode(session_state,'WAITING',event,'CPU') event, 34 | --blocking_session, wait_time,time_waited 35 | round(100*TM_DELTA_DB_TIME/TM_DELTA_TIME,0)||', '||round(100*TM_DELTA_CPU_TIME/TM_DELTA_TIME,0) "DB%,CPU%", 36 | round (1000000*delta_read_io_requests/delta_time,0)||', '||round(1000000*delta_write_io_requests/delta_time,0) "R,W_IOPS", 37 | round(delta_read_io_bytes/delta_time,1)||', '||round(delta_write_io_bytes/delta_time,1) "R,W_MBPS", 38 | round(pga_allocated/1000000,1)||', '||round(temp_space_allocated/1000000,1) "PGA,TEMP_MB" 39 | from gv$active_session_history 40 | where inst_id=&1 and session_id=&2 41 | and sample_time>systimestamp-numtodsinterval(&3,'second') 42 | / 43 | 44 | 45 | 46 | 47 | -------------------------------------------------------------------------------- /ash_top.sql: -------------------------------------------------------------------------------- 1 | -- print aggregations from ash for 11.2 2 | -- Luca March 2012 3 | -- 4 | -- usage @ash_top 5 | -- 6 | 7 | set verify off 8 | 9 | break on sql_id 10 | 11 | with b as ( 12 | select count(distinct sample_id) samples, max(sample_time)-min(sample_time) deltaT_interval, 13 | extract( hour from (max(sample_time)-min(sample_time)) )*60*60+extract( minute from (max(sample_time)-min(sample_time)) )*60+extract( second from (max(sample_time)-min(sample_time)) ) DeltaT 14 | from v$active_session_history 15 | where sample_time>systimestamp-numtodsinterval(&1,'second') 16 | ) 17 | select sql_id,decode(session_state,'WAITING',event,'CPU') event, 18 | round(100*sum(TM_DELTA_DB_TIME/TM_DELTA_TIME)/b.samples) "DB_TIME%", 19 | round(100*sum(TM_DELTA_CPU_TIME/TM_DELTA_TIME)/b.samples) "CPU_TIME%", 20 | round(sum(DELTA_READ_IO_REQUESTS)/b.deltaT) R_IOPs, 21 | round(sum(DELTA_READ_IO_BYTES)/b.deltaT/1000000,1) R_MBPs, 22 | round(sum(DELTA_WRITE_IO_REQUESTS)/b.deltaT) W_IOPs, 23 | round(sum(DELTA_WRITE_IO_BYTES)/b.deltaT/1000000,1) W_MBPs, 24 | round(max(PGA_ALLOCATED)/1000000,1) PGA_MB, round(max(TEMP_SPACE_ALLOCATED)/1000000,1) TEMP_MB 25 | from v$active_session_history,b 26 | where sample_time>systimestamp-numtodsinterval(&1,'second') 27 | group by sql_id,event,b.samples,b.deltaT,session_state 28 | --having round(100*sum(TM_DELTA_DB_TIME/TM_DELTA_TIME)/b.samples) >=1 29 | order by 1,2,3 desc nulls last; 30 | 31 | clear breaks 32 | break on username 33 | 34 | with b as ( 35 | select count(distinct sample_id) samples, max(sample_time)-min(sample_time) deltaT_interval, 36 | extract( hour from (max(sample_time)-min(sample_time)) )*60*60+extract( minute from (max(sample_time)-min(sample_time)) )*60+extract( second from (max(sample_time)-min(sample_time)) ) DeltaT 37 | from v$active_session_history 38 | where sample_time>systimestamp-numtodsinterval(&1,'second') 39 | ) 40 | select (select us.name from sys.user$ us where us.user#=user_id)||case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 41 | sql_id, 42 | round(100*sum(TM_DELTA_DB_TIME/TM_DELTA_TIME)/b.samples) "DB_TIME%", 43 | round(100*sum(TM_DELTA_CPU_TIME/TM_DELTA_TIME)/b.samples) "CPU_TIME%", 44 | round(sum(DELTA_READ_IO_REQUESTS)/b.deltaT) R_IOPs, 45 | round(sum(DELTA_READ_IO_BYTES)/b.deltaT/1000000,1) R_MBPs, 46 | round(sum(DELTA_WRITE_IO_REQUESTS)/b.deltaT) W_IOPs, 47 | round(sum(DELTA_WRITE_IO_BYTES)/b.deltaT/1000000,1) W_MBPs, 48 | round(max(PGA_ALLOCATED)/1000000,1) PGA_MB, round(max(TEMP_SPACE_ALLOCATED)/1000000,1) TEMP_MB 49 | from v$active_session_history,b 50 | where sample_time>systimestamp-numtodsinterval(&1,'second') 51 | group by user_id,program,sql_id,b.samples,b.deltaT 52 | having round(100*sum(TM_DELTA_DB_TIME/TM_DELTA_TIME)/b.samples) >=2 53 | order by 3 desc nulls last; 54 | 55 | clear breaks 56 | break on session_id 57 | 58 | with b as ( 59 | select count(distinct sample_id) samples, max(sample_time)-min(sample_time) deltaT_interval, 60 | extract( hour from (max(sample_time)-min(sample_time)) )*60*60+extract( minute from (max(sample_time)-min(sample_time)) )*60+extract( second from (max(sample_time)-min(sample_time)) ) DeltaT 61 | from v$active_session_history 62 | where sample_time>systimestamp-numtodsinterval(&1,'second') 63 | ) 64 | select session_id, 65 | sql_id, 66 | round(100*sum(TM_DELTA_DB_TIME/TM_DELTA_TIME)/b.samples) "DB_TIME%", 67 | round(100*sum(TM_DELTA_CPU_TIME/TM_DELTA_TIME)/b.samples) "CPU_TIME%", 68 | round(sum(DELTA_READ_IO_REQUESTS)/b.deltaT) R_IOPs, 69 | round(sum(DELTA_READ_IO_BYTES)/b.deltaT/1000000,1) R_MBPs, 70 | round(sum(DELTA_WRITE_IO_REQUESTS)/b.deltaT) W_IOPs, 71 | round(sum(DELTA_WRITE_IO_BYTES)/b.deltaT/1000000,1) W_MBPs, 72 | round(max(PGA_ALLOCATED)/1000000,1) PGA_MB, round(max(TEMP_SPACE_ALLOCATED)/1000000,1) TEMP_MB 73 | from v$active_session_history,b 74 | where sample_time>systimestamp-numtodsinterval(&1,'second') 75 | group by session_id,sql_id,b.samples,b.deltaT 76 | having round(100*sum(TM_DELTA_DB_TIME/TM_DELTA_TIME)/b.samples) >=2 77 | order by 3 desc nulls last; 78 | 79 | clear breaks -------------------------------------------------------------------------------- /awr_global_report.sql: -------------------------------------------------------------------------------- 1 | -- generates and prints AWR global report 2 | -- Luca Apr 2012 3 | -- Usage: @awr_global_report snap_begin snap_end 4 | 5 | set pages 0 6 | set lines 1500 7 | set verify off 8 | set heading off 9 | set termout off 10 | 11 | host del reports\scratch_awr_global.html 12 | spool reports\scratch_awr_global.html 13 | select * from table(DBMS_WORKLOAD_REPOSITORY.AWR_GLOBAL_REPORT_HTML((select dbid from v$database),'',&1,&2)); 14 | spool off 15 | set heading on 16 | set termout on 17 | set pages 1000 18 | 19 | host reports\scratch_awr_global.html 20 | 21 | -------------------------------------------------------------------------------- /awr_report.sql: -------------------------------------------------------------------------------- 1 | -- generates and prints AWR report for current instance 2 | -- Luca Apr 2012 3 | -- Usage: @awr_report snap_begin snap_end 4 | -- use @awr_snapshots or select max(snap_id) from DBA_HIST_SNAPSHOT ; to find latest snapshot 5 | 6 | set pages 0 7 | set lines 1500 8 | set verify off 9 | set heading off 10 | set termout off 11 | 12 | host del reports\scratch_awr.html 13 | spool reports\scratch_awr.html 14 | select * from table(DBMS_WORKLOAD_REPOSITORY.AWR_REPORT_HTML((select dbid from v$database),(select instance_number from v$instance),&1,&2)); 15 | spool off 16 | set heading on 17 | set termout on 18 | set pages 1000 19 | 20 | host reports\scratch_awr.html 21 | 22 | -------------------------------------------------------------------------------- /awr_snapshots.sql: -------------------------------------------------------------------------------- 1 | -- lists latest 24 snapshots 2 | -- Luca Apr 2012 3 | 4 | select * from ( 5 | select snap_id,min(begin_interval_time), min(end_interval_time) from dba_hist_snapshot group by snap_id order by snap_id desc 6 | ) where rownum<=24; 7 | -------------------------------------------------------------------------------- /awr_sql_report.sql: -------------------------------------------------------------------------------- 1 | -- generates and prints awr sql report for current instance 2 | -- Luca Apr 2012 3 | -- Usage: @awr_sql_report snap_begin snap_end sql_id 4 | -- example: @awr_sql_report 3843 3844 "'9dhn1b8d88dpf'" 5 | 6 | set pages 0 7 | set lines 1500 8 | set verify off 9 | set heading off 10 | set termout off 11 | 12 | host del reports\scratch_sql_awr.html 13 | spool reports\scratch_sql_awr.html 14 | select * from table(DBMS_WORKLOAD_REPOSITORY.AWR_SQL_REPORT_HTML((select dbid from v$database),(select instance_number from v$instance),&1,&2,&3)); 15 | spool off 16 | set heading on 17 | set termout on 18 | set pages 1000 19 | 20 | host reports\scratch_sql_awr.html 21 | 22 | -------------------------------------------------------------------------------- /binds.sql: -------------------------------------------------------------------------------- 1 | -- bind values captured on DB 2 | -- for more need to do oradebug dump errorstack 3 3 | -- Luca Mar 2012 updated for oracle 11g 4 | 5 | 6 | select * from gV$SQL_BIND_CAPTURE where sql_id='&1'; 7 | 8 | select BINDS_XML from gv$sql_monitor where sql_id='&1'; 9 | -------------------------------------------------------------------------------- /ehm.sql: -------------------------------------------------------------------------------- 1 | -- Title: event histogram metric, an Oracle monitoring script RAC version (data source are gv$ views) 2 | -- This script collects and displays latency histograms for Oracle wait events 3 | -- It works by computing deltas between two snapshots of gv$event_histogram and gv$system_event 4 | -- Privileges needed: execute on sys.DBMS_LOCK and select on gv$event_histogram and gv$system_event 5 | -- 6 | -- Author: Luca.Canali@cern.ch 7 | -- Version 1.1, June 2015 8 | -- Version 1.0, April 2012 9 | -- 10 | -- Usage: @ehm 11 | -- Tips: for random I/O studies measure "db file sequential read". For commit time latency: "log file sync" 12 | -- Examples: 13 | -- @ehm 10 "db file sequential read" 14 | -- @ehm 10 "log file sync" 15 | -- 16 | 17 | set serverout on 18 | set verify off 19 | 20 | -- set parameters default when not provided, this sqlplus trick technique is described in orafaq 21 | COLUMN p1 NEW_VALUE 1 22 | COLUMN p2 NEW_VALUE 2 23 | set termout off 24 | SELECT null p1, null p2 FROM dual WHERE 1=2; 25 | -- NOTE: the default values for and parameters are hard coded here 26 | SELECT nvl('&1','5') p1, nvl('&2','db file sequential read') p2 from dual; 27 | set termout on 28 | 29 | prompt 30 | prompt Latency histograms for Oracle wait events, RAC version. 31 | prompt Usage: @ehm 32 | prompt Please wait for &1 sec (DeltaT = &1 sec) for snapshot N.2 and script output. 33 | 34 | DECLARE 35 | v_sleep_time number; 36 | v_event_name varchar2(50) := '&2'; 37 | v_delta_waits number; 38 | v_delta_waits_per_sec number; 39 | v_delta_time_waited_estimate number; 40 | v_delta_time_waited_micro number; 41 | v_avg_wait_time_milli number; 42 | v_latencybin varchar2(100); 43 | 44 | CURSOR c1 IS 45 | SELECT event, wait_time_milli, sum(wait_count) wait_count, max(last_update_time) last_update_time 46 | FROM gv$event_histogram 47 | WHERE event = v_event_name 48 | GROUP BY event, wait_time_milli 49 | ORDER BY event, wait_time_milli; 50 | 51 | CURSOR c2 IS 52 | SELECT event, sum(time_waited_micro) time_waited_micro, sum(total_waits) total_waits 53 | FROM gv$system_event 54 | WHERE event = v_event_name 55 | GROUP BY event 56 | ORDER BY event; 57 | 58 | TYPE EventHisto IS TABLE OF c1%ROWTYPE; 59 | TYPE SysEvent IS TABLE OF c2%ROWTYPE; 60 | 61 | t0_histval EventHisto; -- nested table of records for t0 snapshot 62 | t1_histval EventHisto; -- nested table of records for t1 snapshot 63 | t0_eventval SysEvent; -- nested table of records for t0 snapshot 64 | t1_eventval SysEvent; -- nested table of records for t1 snapshot 65 | 66 | BEGIN 67 | -- input validation 68 | BEGIN 69 | v_sleep_time := TO_NUMBER('&1'); 70 | IF (v_sleep_time <= 0) THEN 71 | raise value_error; 72 | END IF; 73 | EXCEPTION 74 | WHEN value_error THEN 75 | RAISE_APPLICATION_ERROR(-20001,'Wait time must be numeric and >0. Example use wait time = 10'); 76 | END; 77 | 78 | -- collect t0 data 79 | OPEN c1; 80 | OPEN c2; 81 | FETCH c1 BULK COLLECT INTO t0_histval; 82 | FETCH c2 BULK COLLECT INTO t0_eventval; 83 | CLOSE c1; 84 | CLOSE c2; 85 | 86 | IF t0_eventval.COUNT <=0 THEN 87 | RAISE_APPLICATION_ERROR(-20001,'Not enough data. Probably wrong event name. Tip, try event = "db file sequential read".'); 88 | END IF; 89 | 90 | IF t0_eventval.COUNT >= 100 THEN 91 | RAISE_APPLICATION_ERROR(-20002,'Too many values, soft limit set to 100'); 92 | END IF; 93 | 94 | -- put wait time here note user needs exec privilege on dbms_lock 95 | sys.DBMS_LOCK.SLEEP (v_sleep_time); 96 | 97 | -- collect t1 data 98 | OPEN c1; 99 | OPEN c2; 100 | FETCH c1 BULK COLLECT INTO t1_histval; 101 | FETCH c2 BULK COLLECT INTO t1_eventval; 102 | CLOSE c1; 103 | CLOSE c2; 104 | 105 | -- check and report error if number of points is different between the two snapshots 106 | -- (rare, but can happen if a new histogram bin has been created) 107 | IF t0_histval.COUNT <> t1_histval.COUNT THEN 108 | RAISE_APPLICATION_ERROR(-20003,'Number of histogram bins changed during collection. Cannot handle it.'); 109 | END IF; 110 | 111 | -- print out results 112 | -- compute delta values and print. 113 | -- format with rpad to keep column width constant 114 | 115 | -- Latency histogram from gv$event_histogram 116 | DBMS_OUTPUT.PUT_LINE(chr(13)); 117 | DBMS_OUTPUT.PUT_LINE('Latency histogram for event "&2" from GV$EVENT_HISTOGRAM:'); 118 | DBMS_OUTPUT.PUT_LINE(chr(13)); 119 | DBMS_OUTPUT.PUT_LINE ('Latency Bucket Num Waits/DeltaT Wait Time/DeltaT Event Name Last Update Time'); 120 | DBMS_OUTPUT.PUT_LINE ('(millisec) (Hz) (millisec/sec) '); 121 | DBMS_OUTPUT.PUT_LINE ('---------------- ---------------- ---------------- ------------------------- -----------------------------------'); 122 | 123 | FOR i IN t1_histval.FIRST .. t1_histval.LAST LOOP 124 | v_delta_waits := t1_histval(i).wait_count - t0_histval(i).wait_count; 125 | v_delta_waits_per_sec := round(v_delta_waits / v_sleep_time,1); 126 | v_delta_time_waited_estimate := round(0.75 * t1_histval(i).wait_time_milli * v_delta_waits_per_sec,1); -- estimated value 127 | IF (t1_histval(i).wait_time_milli <> 1) THEN 128 | v_latencybin := to_char(t1_histval(i).wait_time_milli/2) ||' -> ' || to_char(t1_histval(i).wait_time_milli); 129 | ELSE 130 | v_latencybin := '0 -> 1'; 131 | END IF; 132 | DBMS_OUTPUT.PUT_LINE ( 133 | rpad(v_latencybin,16,' ')||' '|| 134 | lpad(to_char(v_delta_waits_per_sec),16,' ')||' '|| 135 | lpad(to_char(v_delta_time_waited_estimate),16,' ')||' '|| 136 | rpad(t1_histval(i).event,24,' ') ||' '|| 137 | t1_histval(i).last_update_time 138 | ); 139 | END LOOP; 140 | 141 | -- This is the summary from gv$system_event 142 | DBMS_OUTPUT.PUT_LINE(chr(13)); 143 | DBMS_OUTPUT.PUT_LINE('Average values from GV$SYSTEM_EVENT:'); 144 | DBMS_OUTPUT.PUT_LINE(chr(13)); 145 | DBMS_OUTPUT.PUT_LINE ('Mean Wait Time Num Waits/DeltaT Wait Time/DeltaT Event Name '); 146 | DBMS_OUTPUT.PUT_LINE ('(millisec) (Hz) (millisec/sec) '); 147 | DBMS_OUTPUT.PUT_LINE ('---------------- ---------------- ---------------- -------------------------'); 148 | 149 | FOR i IN t1_eventval.FIRST .. t1_eventval.LAST LOOP 150 | v_delta_time_waited_micro := t1_eventval(i).time_waited_micro - t0_eventval(i).time_waited_micro; 151 | v_delta_waits := t1_eventval(i).total_waits - t0_eventval(i).total_waits; 152 | v_delta_waits_per_sec := round(v_delta_waits / v_sleep_time, 1); 153 | IF v_delta_waits <> 0 then 154 | v_avg_wait_time_milli := round(v_delta_time_waited_micro/v_delta_waits/1000,1); 155 | ELSE 156 | v_avg_wait_time_milli := 0; 157 | END IF; 158 | DBMS_OUTPUT.PUT_LINE( 159 | rpad(to_char(v_avg_wait_time_milli),16,' ')||' '|| 160 | lpad(to_char(v_delta_waits_per_sec),16,' ')||' '|| 161 | lpad(to_char(round(v_delta_time_waited_micro/v_sleep_time/1000,1)),16,' ')||' '|| 162 | rpad(t1_histval(i).event,24,' ') 163 | ); 164 | END LOOP; 165 | DBMS_OUTPUT.PUT_LINE(chr(13)); 166 | 167 | END; 168 | / 169 | -------------------------------------------------------------------------------- /ehm_local.sql: -------------------------------------------------------------------------------- 1 | -- Title: event histogram metric local, an Oracle monitoring script 2 | -- local instance version (data source are v$ views) 3 | -- This script collects and displays latency histograms for Oracle wait events 4 | -- It works by computing deltas between two snapshots of v$event_histogram and v$system_event 5 | -- Privileges needed: execute on sys.DBMS_LOCK and select on v$event_histogram and v$system_event 6 | -- 7 | -- Author: Luca.Canali@cern.ch 8 | -- Version 1.1, June 2015 9 | -- Version 1.0, April 2012 10 | -- 11 | -- Usage: @ehm_local 12 | -- Tips: for random I/O studies measure "db file sequential read". For commit time latency: "log file sync" 13 | -- Examples: 14 | -- @ehm 10 "db file sequential read" 15 | -- @ehm 10 "log file sync" 16 | -- 17 | 18 | set serverout on 19 | set verify off 20 | 21 | -- set parameters default when not provided, this sqlplus trick technique is described in orafaq 22 | COLUMN p1 NEW_VALUE 1 23 | COLUMN p2 NEW_VALUE 2 24 | set termout off 25 | SELECT null p1, null p2 FROM dual WHERE 1=2; 26 | -- NOTE the default values for and parameters are hard coded here 27 | SELECT nvl('&1','5') p1, nvl('&2','db file sequential read') p2 from dual; 28 | set termout on 29 | 30 | prompt 31 | prompt Latency histograms for Oracle wait events on local instance. 32 | prompt Usage: @ehm_local 33 | prompt Please wait for &1 sec (DeltaT = &1 sec) for snapshot N.2 and script output. 34 | 35 | DECLARE 36 | v_sleep_time number; 37 | v_event_name varchar2(50) := '&2'; 38 | v_delta_waits number; 39 | v_delta_waits_per_sec number; 40 | v_delta_time_waited_estimate number; 41 | v_delta_time_waited_micro number; 42 | v_avg_wait_time_milli number; 43 | v_latencybin varchar2(100); 44 | 45 | CURSOR c1 IS 46 | SELECT event, wait_time_milli, sum(wait_count) wait_count, max(last_update_time) last_update_time 47 | FROM v$event_histogram 48 | WHERE event = v_event_name 49 | GROUP BY event, wait_time_milli 50 | ORDER BY event, wait_time_milli; 51 | 52 | CURSOR c2 IS 53 | SELECT event, sum(time_waited_micro) time_waited_micro, sum(total_waits) total_waits 54 | FROM v$system_event 55 | WHERE event = v_event_name 56 | GROUP BY event 57 | ORDER BY event; 58 | 59 | TYPE EventHisto IS TABLE OF c1%ROWTYPE; 60 | TYPE SysEvent IS TABLE OF c2%ROWTYPE; 61 | 62 | t0_histval EventHisto; -- nested table of records for t0 snapshot 63 | t1_histval EventHisto; -- nested table of records for t1 snapshot 64 | t0_eventval SysEvent; -- nested table of records for t0 snapshot 65 | t1_eventval SysEvent; -- nested table of records for t1 snapshot 66 | 67 | BEGIN 68 | -- input validation 69 | BEGIN 70 | v_sleep_time := TO_NUMBER('&1'); 71 | IF (v_sleep_time <= 0) THEN 72 | raise value_error; 73 | END IF; 74 | EXCEPTION 75 | WHEN value_error THEN 76 | RAISE_APPLICATION_ERROR(-20001,'Wait time must be numeric and >0. Example use wait time = 10'); 77 | END; 78 | 79 | -- collect t0 data 80 | OPEN c1; 81 | OPEN c2; 82 | FETCH c1 BULK COLLECT INTO t0_histval; 83 | FETCH c2 BULK COLLECT INTO t0_eventval; 84 | CLOSE c1; 85 | CLOSE c2; 86 | 87 | IF t0_eventval.COUNT <=0 THEN 88 | RAISE_APPLICATION_ERROR(-20001,'Not enough data. Probably wrong event name. Tip, try event = "db file sequential read".'); 89 | END IF; 90 | 91 | IF t0_eventval.COUNT >= 100 THEN 92 | RAISE_APPLICATION_ERROR(-20002,'Too many values, soft limit set to 100'); 93 | END IF; 94 | 95 | -- put wait time here note user needs exec privilege on dbms_lock 96 | sys.DBMS_LOCK.SLEEP (v_sleep_time); 97 | 98 | -- collect t1 data 99 | OPEN c1; 100 | OPEN c2; 101 | FETCH c1 BULK COLLECT INTO t1_histval; 102 | FETCH c2 BULK COLLECT INTO t1_eventval; 103 | CLOSE c1; 104 | CLOSE c2; 105 | 106 | -- check and report error if number of points is different between the two snapshots 107 | -- (rare, but can happen if a new histogram bin has been created) 108 | IF t0_histval.COUNT <> t1_histval.COUNT THEN 109 | RAISE_APPLICATION_ERROR(-20003,'Number of histogram bins changed during collection. Cannot handle it.'); 110 | END IF; 111 | 112 | -- print out results 113 | -- compute delta values and print. 114 | -- format with rpad to keep column width constant 115 | 116 | -- Latency histogram from v$event_histogram 117 | DBMS_OUTPUT.PUT_LINE(chr(13)); 118 | DBMS_OUTPUT.PUT_LINE('Latency histogram for event "&2" from V$EVENT_HISTOGRAM:'); 119 | DBMS_OUTPUT.PUT_LINE(chr(13)); 120 | DBMS_OUTPUT.PUT_LINE ('Latency Bucket Num Waits/DeltaT Wait Time/DeltaT Event Name Last Update Time'); 121 | DBMS_OUTPUT.PUT_LINE ('(millisec) (Hz) (millisec/sec) '); 122 | DBMS_OUTPUT.PUT_LINE ('---------------- ---------------- ---------------- ------------------------- -----------------------------------'); 123 | 124 | FOR i IN t1_histval.FIRST .. t1_histval.LAST LOOP 125 | v_delta_waits := t1_histval(i).wait_count - t0_histval(i).wait_count; 126 | v_delta_waits_per_sec := round(v_delta_waits / v_sleep_time,1); 127 | v_delta_time_waited_estimate := round(0.75 * t1_histval(i).wait_time_milli * v_delta_waits_per_sec,1); -- estimated value 128 | IF (t1_histval(i).wait_time_milli <> 1) THEN 129 | v_latencybin := to_char(t1_histval(i).wait_time_milli/2) ||' -> ' || to_char(t1_histval(i).wait_time_milli); 130 | ELSE 131 | v_latencybin := '0 -> 1'; 132 | END IF; 133 | DBMS_OUTPUT.PUT_LINE ( 134 | rpad(v_latencybin,16,' ')||' '|| 135 | lpad(to_char(v_delta_waits_per_sec),16,' ')||' '|| 136 | lpad(to_char(v_delta_time_waited_estimate),16,' ')||' '|| 137 | rpad(t1_histval(i).event,24,' ') ||' '|| 138 | t1_histval(i).last_update_time 139 | ); 140 | END LOOP; 141 | 142 | -- This is the summary from v$system_event 143 | DBMS_OUTPUT.PUT_LINE(chr(13)); 144 | DBMS_OUTPUT.PUT_LINE('Average values from V$SYSTEM_EVENT:'); 145 | DBMS_OUTPUT.PUT_LINE(chr(13)); 146 | DBMS_OUTPUT.PUT_LINE ('Mean Wait Time Num Waits/DeltaT Wait Time/DeltaT Event Name '); 147 | DBMS_OUTPUT.PUT_LINE ('(millisec) (Hz) (millisec/sec) '); 148 | DBMS_OUTPUT.PUT_LINE ('---------------- ---------------- ---------------- -------------------------'); 149 | 150 | FOR i IN t1_eventval.FIRST .. t1_eventval.LAST LOOP 151 | v_delta_time_waited_micro := t1_eventval(i).time_waited_micro - t0_eventval(i).time_waited_micro; 152 | v_delta_waits := t1_eventval(i).total_waits - t0_eventval(i).total_waits; 153 | v_delta_waits_per_sec := round(v_delta_waits / v_sleep_time, 1); 154 | IF v_delta_waits <> 0 then 155 | v_avg_wait_time_milli := round(v_delta_time_waited_micro/v_delta_waits/1000,1); 156 | ELSE 157 | v_avg_wait_time_milli := 0; 158 | END IF; 159 | DBMS_OUTPUT.PUT_LINE( 160 | rpad(to_char(v_avg_wait_time_milli),16,' ')||' '|| 161 | lpad(to_char(v_delta_waits_per_sec),16,' ')||' '|| 162 | lpad(to_char(round(v_delta_time_waited_micro/v_sleep_time/1000,1)),16,' ')||' '|| 163 | rpad(t1_histval(i).event,24,' ') 164 | ); 165 | END LOOP; 166 | DBMS_OUTPUT.PUT_LINE(chr(13)); 167 | 168 | END; 169 | / 170 | -------------------------------------------------------------------------------- /ehm_micro.sql: -------------------------------------------------------------------------------- 1 | -- Title: event histogram metric micro, an Oracle monitoring script RAC version (data source are gv$ views). 2 | -- Requires 12.1.0.2 or higher (use ehm.sql if on previous versions). 3 | -- This script collects and displays latency histograms for Oracle wait events 4 | -- It works by computing deltas between two snapshots of gv$event_histogram_micro and gv$system_event 5 | -- Privileges needed: execute on sys.DBMS_LOCK and select on gv$event_histogram_micro and gv$system_event 6 | -- 7 | -- Author: Luca.Canali@cern.ch 8 | -- Version 1.1, June 2015 9 | -- Based on ehm.sql version 1.0, April 2012 10 | -- 11 | -- Usage: @ehm_micro 12 | -- Tips: for random I/O studies measure "db file sequential read". For commit time latency: "log file sync" 13 | -- Examples: 14 | -- @ehm_micro 10 "db file sequential read" 15 | -- @ehm_micro 10 "log file sync" 16 | -- 17 | 18 | set serverout on 19 | set verify off 20 | 21 | -- set parameters default when not provided, this sqlplus trick technique is described in orafaq 22 | COLUMN p1 NEW_VALUE 1 23 | COLUMN p2 NEW_VALUE 2 24 | set termout off 25 | SELECT null p1, null p2 FROM dual WHERE 1=2; 26 | -- NOTE: the default values for and parameters are hard coded here 27 | SELECT nvl('&1','5') p1, nvl('&2','db file sequential read') p2 from dual; 28 | set termout on 29 | 30 | prompt 31 | prompt Latency histograms for Oracle wait events, RAC 12c version. 32 | prompt Usage: @ehm_micro 33 | prompt Please wait for &1 sec (DeltaT = &1 sec) for snapshot N.2 and script output. 34 | 35 | DECLARE 36 | v_sleep_time number; 37 | v_event_name varchar2(50) := '&2'; 38 | v_delta_waits number; 39 | v_delta_waits_per_sec number; 40 | v_delta_time_waited_estimate number; 41 | v_delta_time_waited_micro number; 42 | v_avg_wait_time_micro number; 43 | v_latencybin varchar2(100); 44 | 45 | CURSOR c1 IS 46 | SELECT event, wait_time_micro, sum(wait_count) wait_count, max(last_update_time) last_update_time 47 | FROM gv$event_histogram_micro 48 | WHERE event = v_event_name 49 | GROUP BY event, wait_time_micro 50 | ORDER BY event, wait_time_micro; 51 | 52 | CURSOR c2 IS 53 | SELECT event, sum(time_waited_micro) time_waited_micro, sum(total_waits) total_waits 54 | FROM gv$system_event 55 | WHERE event = v_event_name 56 | GROUP BY event 57 | ORDER BY event; 58 | 59 | 60 | TYPE EventHisto IS TABLE OF c1%ROWTYPE; 61 | TYPE SysEvent IS TABLE OF c2%ROWTYPE; 62 | 63 | t0_histval EventHisto; -- nested table of records for t0 snapshot 64 | t1_histval EventHisto; -- nested table of records for t1 snapshot 65 | t0_eventval SysEvent; -- nested table of records for t0 snapshot 66 | t1_eventval SysEvent; -- nested table of records for t1 snapshot 67 | 68 | BEGIN 69 | -- input validation 70 | BEGIN 71 | v_sleep_time := TO_NUMBER('&1'); 72 | IF (v_sleep_time <= 0) THEN 73 | raise value_error; 74 | END IF; 75 | EXCEPTION 76 | WHEN value_error THEN 77 | RAISE_APPLICATION_ERROR(-20001,'Wait time must be numeric and >0. Example use wait time = 10'); 78 | END; 79 | 80 | -- collect t0 data 81 | OPEN c1; 82 | OPEN c2; 83 | FETCH c1 BULK COLLECT INTO t0_histval; 84 | FETCH c2 BULK COLLECT INTO t0_eventval; 85 | CLOSE c1; 86 | CLOSE c2; 87 | 88 | IF t0_eventval.COUNT <=0 THEN 89 | RAISE_APPLICATION_ERROR(-20001,'Not enough data. Probably wrong event name. Tip, try event = "db file sequential read".'); 90 | END IF; 91 | 92 | IF t0_eventval.COUNT >= 100 THEN 93 | RAISE_APPLICATION_ERROR(-20002,'Too many values, soft limit set to 100'); 94 | END IF; 95 | 96 | -- put wait time here note user needs exec privilege on dbms_lock 97 | sys.DBMS_LOCK.SLEEP (v_sleep_time); 98 | 99 | -- collect t1 data 100 | OPEN c1; 101 | OPEN c2; 102 | FETCH c1 BULK COLLECT INTO t1_histval; 103 | FETCH c2 BULK COLLECT INTO t1_eventval; 104 | CLOSE c1; 105 | CLOSE c2; 106 | 107 | -- check and report error if number of points is different between the two snapshots 108 | -- (rare, but can happen if a new histogram bin has been created) 109 | IF t0_histval.COUNT <> t1_histval.COUNT THEN 110 | RAISE_APPLICATION_ERROR(-20003,'Number of histogram bins changed during collection. Cannot handle it.'); 111 | END IF; 112 | 113 | -- print out results 114 | -- compute delta values and print. 115 | -- format with rpad to keep column width constant 116 | 117 | -- Latency histogram from gv$event_histogram_micro 118 | DBMS_OUTPUT.PUT_LINE(chr(13)); 119 | DBMS_OUTPUT.PUT_LINE('Latency histogram for event "&2" from GV$EVENT_HISTOGRAM_MICRO:'); 120 | DBMS_OUTPUT.PUT_LINE(chr(13)); 121 | DBMS_OUTPUT.PUT_LINE ('Latency Bucket Num Waits/DeltaT Wait Time/DeltaT Event Name Last Update Time'); 122 | DBMS_OUTPUT.PUT_LINE ('(microsec) (Hz) (microsec/sec) '); 123 | DBMS_OUTPUT.PUT_LINE ('------------------- ---------------- ------------------ ------------------------- -----------------------------------'); 124 | 125 | FOR i IN t1_histval.FIRST .. t1_histval.LAST LOOP 126 | v_delta_waits := t1_histval(i).wait_count - t0_histval(i).wait_count; 127 | v_delta_waits_per_sec := round(v_delta_waits / v_sleep_time,1); 128 | v_delta_time_waited_estimate := round(0.75 * t1_histval(i).wait_time_micro * v_delta_waits_per_sec,1); -- estimated value 129 | IF (t1_histval(i).wait_time_micro <> 1) THEN 130 | v_latencybin := to_char(t1_histval(i).wait_time_micro/2) ||' -> ' || to_char(t1_histval(i).wait_time_micro); 131 | ELSE 132 | v_latencybin := '0 -> 1'; 133 | END IF; 134 | DBMS_OUTPUT.PUT_LINE ( 135 | rpad(v_latencybin,19,' ')||' '|| 136 | lpad(to_char(v_delta_waits_per_sec),16,' ')||' '|| 137 | lpad(to_char(v_delta_time_waited_estimate),18,' ')||' '|| 138 | rpad(t1_histval(i).event,24,' ') ||' '|| 139 | t1_histval(i).last_update_time 140 | ); 141 | END LOOP; 142 | 143 | -- This is the summary from gv$system_event 144 | DBMS_OUTPUT.PUT_LINE(chr(13)); 145 | DBMS_OUTPUT.PUT_LINE('Average values from GV$SYSTEM_EVENT:'); 146 | DBMS_OUTPUT.PUT_LINE(chr(13)); 147 | DBMS_OUTPUT.PUT_LINE ('Mean Wait Time Num Waits/DeltaT Wait Time/DeltaT Event Name '); 148 | DBMS_OUTPUT.PUT_LINE ('(microsec) (Hz) (microsec/sec) '); 149 | DBMS_OUTPUT.PUT_LINE ('------------------- ---------------- ------------------ -------------------------'); 150 | 151 | FOR i IN t1_eventval.FIRST .. t1_eventval.LAST LOOP 152 | v_delta_time_waited_micro := t1_eventval(i).time_waited_micro - t0_eventval(i).time_waited_micro; 153 | v_delta_waits := t1_eventval(i).total_waits - t0_eventval(i).total_waits; 154 | v_delta_waits_per_sec := round(v_delta_waits / v_sleep_time, 1); 155 | IF v_delta_waits <> 0 then 156 | v_avg_wait_time_micro := round(v_delta_time_waited_micro/v_delta_waits,1); 157 | ELSE 158 | v_avg_wait_time_micro := 0; 159 | END IF; 160 | DBMS_OUTPUT.PUT_LINE( 161 | rpad(to_char(v_avg_wait_time_micro),19,' ')||' '|| 162 | lpad(to_char(v_delta_waits_per_sec),16,' ')||' '|| 163 | lpad(to_char(round(v_delta_time_waited_micro/v_sleep_time,1)),18,' ')||' '|| 164 | rpad(t1_histval(i).event,24,' ') 165 | ); 166 | END LOOP; 167 | DBMS_OUTPUT.PUT_LINE(chr(13)); 168 | 169 | END; 170 | / 171 | -------------------------------------------------------------------------------- /ehm_micro_local.sql: -------------------------------------------------------------------------------- 1 | -- Title: event histogram metric micro, an Oracle monitoring script 2 | -- local instance version (data source are v$ views) 3 | -- Requires 12.1.0.2 or higher (use ehm_local.sql if on previous Oracle versions). 4 | -- This script collects and displays latency histograms for Oracle wait events 5 | -- It works by computing deltas between two snapshots of v$event_histogram_micro and v$system_event 6 | -- Privileges needed: execute on sys.DBMS_LOCK and select on v$event_histogram_micro and v$system_event 7 | -- 8 | -- Author: Luca.Canali@cern.ch 9 | -- Version 1.1, June 2015 10 | -- Based on ehm.sql version 1.0, April 2012 11 | -- 12 | -- Usage: @ehm_micro_local 13 | -- Tips: for random I/O studies measure "db file sequential read". For commit time latency: "log file sync" 14 | -- Examples: 15 | -- @ehm_micro_local 10 "db file sequential read" 16 | -- @ehm_micro_local 10 "log file sync" 17 | -- 18 | 19 | set serverout on 20 | set verify off 21 | 22 | -- set parameters default when not provided, this sqlplus trick technique is described in orafaq 23 | COLUMN p1 NEW_VALUE 1 24 | COLUMN p2 NEW_VALUE 2 25 | set termout off 26 | SELECT null p1, null p2 FROM dual WHERE 1=2; 27 | -- NOTE: the default values for and parameters are hard coded here 28 | SELECT nvl('&1','5') p1, nvl('&2','db file sequential read') p2 from dual; 29 | set termout on 30 | 31 | prompt 32 | prompt Latency histograms for Oracle wait events, RAC 12c version. 33 | prompt Usage: @ehm_micro_local 34 | prompt Please wait for &1 sec (DeltaT = &1 sec) for snapshot N.2 and script output. 35 | 36 | DECLARE 37 | v_sleep_time number; 38 | v_event_name varchar2(50) := '&2'; 39 | v_delta_waits number; 40 | v_delta_waits_per_sec number; 41 | v_delta_time_waited_estimate number; 42 | v_delta_time_waited_micro number; 43 | v_avg_wait_time_micro number; 44 | v_latencybin varchar2(100); 45 | 46 | CURSOR c1 IS 47 | SELECT event, wait_time_micro, sum(wait_count) wait_count, max(last_update_time) last_update_time 48 | FROM v$event_histogram_micro 49 | WHERE event = v_event_name 50 | GROUP BY event, wait_time_micro 51 | ORDER BY event, wait_time_micro; 52 | 53 | CURSOR c2 IS 54 | SELECT event, sum(time_waited_micro) time_waited_micro, sum(total_waits) total_waits 55 | FROM v$system_event 56 | WHERE event = v_event_name 57 | GROUP BY event 58 | ORDER BY event; 59 | 60 | 61 | TYPE EventHisto IS TABLE OF c1%ROWTYPE; 62 | TYPE SysEvent IS TABLE OF c2%ROWTYPE; 63 | 64 | t0_histval EventHisto; -- nested table of records for t0 snapshot 65 | t1_histval EventHisto; -- nested table of records for t1 snapshot 66 | t0_eventval SysEvent; -- nested table of records for t0 snapshot 67 | t1_eventval SysEvent; -- nested table of records for t1 snapshot 68 | 69 | BEGIN 70 | -- input validation 71 | BEGIN 72 | v_sleep_time := TO_NUMBER('&1'); 73 | IF (v_sleep_time <= 0) THEN 74 | raise value_error; 75 | END IF; 76 | EXCEPTION 77 | WHEN value_error THEN 78 | RAISE_APPLICATION_ERROR(-20001,'Wait time must be numeric and >0. Example use wait time = 10'); 79 | END; 80 | 81 | -- collect t0 data 82 | OPEN c1; 83 | OPEN c2; 84 | FETCH c1 BULK COLLECT INTO t0_histval; 85 | FETCH c2 BULK COLLECT INTO t0_eventval; 86 | CLOSE c1; 87 | CLOSE c2; 88 | 89 | IF t0_eventval.COUNT <=0 THEN 90 | RAISE_APPLICATION_ERROR(-20001,'Not enough data. Probably wrong event name. Tip, try event = "db file sequential read".'); 91 | END IF; 92 | 93 | IF t0_eventval.COUNT >= 100 THEN 94 | RAISE_APPLICATION_ERROR(-20002,'Too many values, soft limit set to 100'); 95 | END IF; 96 | 97 | -- put wait time here note user needs exec privilege on dbms_lock 98 | sys.DBMS_LOCK.SLEEP (v_sleep_time); 99 | 100 | -- collect t1 data 101 | OPEN c1; 102 | OPEN c2; 103 | FETCH c1 BULK COLLECT INTO t1_histval; 104 | FETCH c2 BULK COLLECT INTO t1_eventval; 105 | CLOSE c1; 106 | CLOSE c2; 107 | 108 | -- check and report error if number of points is different between the two snapshots 109 | -- (rare, but can happen if a new histogram bin has been created) 110 | IF t0_histval.COUNT <> t1_histval.COUNT THEN 111 | RAISE_APPLICATION_ERROR(-20003,'Number of histogram bins changed during collection. Cannot handle it.'); 112 | END IF; 113 | 114 | -- print out results 115 | -- compute delta values and print. 116 | -- format with rpad to keep column width constant 117 | 118 | -- Latency histogram from v$event_histogram_micro 119 | DBMS_OUTPUT.PUT_LINE(chr(13)); 120 | DBMS_OUTPUT.PUT_LINE('Latency histogram for event "&2" from V$EVENT_HISTOGRAM_MICRO:'); 121 | DBMS_OUTPUT.PUT_LINE(chr(13)); 122 | DBMS_OUTPUT.PUT_LINE ('Latency Bucket Num Waits/DeltaT Wait Time/DeltaT Event Name Last Update Time'); 123 | DBMS_OUTPUT.PUT_LINE ('(microsec) (Hz) (microsec/sec) '); 124 | DBMS_OUTPUT.PUT_LINE ('------------------- ---------------- ------------------ ------------------------- -----------------------------------'); 125 | 126 | FOR i IN t1_histval.FIRST .. t1_histval.LAST LOOP 127 | v_delta_waits := t1_histval(i).wait_count - t0_histval(i).wait_count; 128 | v_delta_waits_per_sec := round(v_delta_waits / v_sleep_time,1); 129 | v_delta_time_waited_estimate := round(0.75 * t1_histval(i).wait_time_micro * v_delta_waits_per_sec,1); -- estimated value 130 | IF (t1_histval(i).wait_time_micro <> 1) THEN 131 | v_latencybin := to_char(t1_histval(i).wait_time_micro/2) ||' -> ' || to_char(t1_histval(i).wait_time_micro); 132 | ELSE 133 | v_latencybin := '0 -> 1'; 134 | END IF; 135 | DBMS_OUTPUT.PUT_LINE ( 136 | rpad(v_latencybin,19,' ')||' '|| 137 | lpad(to_char(v_delta_waits_per_sec),16,' ')||' '|| 138 | lpad(to_char(v_delta_time_waited_estimate),18,' ')||' '|| 139 | rpad(t1_histval(i).event,24,' ') ||' '|| 140 | t1_histval(i).last_update_time 141 | ); 142 | END LOOP; 143 | 144 | -- This is the summary from v$system_event 145 | DBMS_OUTPUT.PUT_LINE(chr(13)); 146 | DBMS_OUTPUT.PUT_LINE('Average values from V$SYSTEM_EVENT:'); 147 | DBMS_OUTPUT.PUT_LINE(chr(13)); 148 | DBMS_OUTPUT.PUT_LINE ('Mean Wait Time Num Waits/DeltaT Wait Time/DeltaT Event Name '); 149 | DBMS_OUTPUT.PUT_LINE ('(microsec) (Hz) (microsec/sec) '); 150 | DBMS_OUTPUT.PUT_LINE ('------------------- ---------------- ------------------ -------------------------'); 151 | 152 | FOR i IN t1_eventval.FIRST .. t1_eventval.LAST LOOP 153 | v_delta_time_waited_micro := t1_eventval(i).time_waited_micro - t0_eventval(i).time_waited_micro; 154 | v_delta_waits := t1_eventval(i).total_waits - t0_eventval(i).total_waits; 155 | v_delta_waits_per_sec := round(v_delta_waits / v_sleep_time, 1); 156 | IF v_delta_waits <> 0 then 157 | v_avg_wait_time_micro := round(v_delta_time_waited_micro/v_delta_waits,1); 158 | ELSE 159 | v_avg_wait_time_micro := 0; 160 | END IF; 161 | DBMS_OUTPUT.PUT_LINE( 162 | rpad(to_char(v_avg_wait_time_micro),19,' ')||' '|| 163 | lpad(to_char(v_delta_waits_per_sec),16,' ')||' '|| 164 | lpad(to_char(round(v_delta_time_waited_micro/v_sleep_time,1)),18,' ')||' '|| 165 | rpad(t1_histval(i).event,24,' ') 166 | ); 167 | END LOOP; 168 | DBMS_OUTPUT.PUT_LINE(chr(13)); 169 | 170 | END; 171 | / 172 | -------------------------------------------------------------------------------- /eventmetric.sql: -------------------------------------------------------------------------------- 1 | /* 2 | eventmetric.sql - sqlplus script - displays significant event metrics 3 | By Luca Jan 2011, 11g version Apr2012 4 | */ 5 | 6 | col "Time /Delta" for a14 7 | col name for a40 8 | col INST_ID for 999 9 | set linesize 140 10 | set pagesize 1000 11 | 12 | set wrap off 13 | 14 | select "Time /Delta",inst_id,name, 15 | T_per_wait_fg*10 "Avg_FG_wait_ms", round(T_waited_fg/100,1) "Waited_FG_sec", W_count_fg "W_count_FG", 16 | round(T_waited/100,1) "Waited_tot_sec", W_count "W_count_tot" 17 | from ( 18 | select to_char(min(begin_time),'hh24:mi:ss')||' /'||round(avg(intsize_csec/100),0)||'s' "Time /Delta", 19 | em.inst_id,en.name, 20 | sum(em.time_waited_fg) T_waited_fg, sum(em.time_waited) T_waited,sum(wait_count) W_count, sum(wait_count_fg) W_count_fg, 21 | sum(decode(em.wait_count, 0,0,round(em.time_waited/em.wait_count,2))) T_per_wait, 22 | sum(decode(em.wait_count_fg, 0,0,round(em.time_waited_fg/em.wait_count_fg,2))) T_per_wait_fg 23 | from gv$eventmetric em, v$event_name en 24 | where em.event#=en.event# 25 | and en.wait_class <>'Idle' 26 | group by em.inst_id,en.name,em.event_id 27 | order by T_waited_fg desc 28 | ) 29 | where rownum<=20; 30 | 31 | 32 | set wrap on 33 | -------------------------------------------------------------------------------- /explain.sql: -------------------------------------------------------------------------------- 1 | -- explain.sql 2 | -- prints execution plan for a give sql_id 3 | -- detailed execution plan, taken from memory/library cache 4 | -- Usage @explain 5 | -- by Luca 6 | 7 | --select * from table(dbms_xplan.display_cursor('&1')); 8 | --select * from table(dbms_xplan.display_cursor('&1',0,'ALLSTATS LAST')); 9 | --select * from table(dbms_xplan.display_cursor('&1',0,'TYPICAL OUTLINE')); 10 | --for explain plan use: 11 | --select * from table(dbms_xplan.display('PLAN_TABLE',null,'ADVANCED OUTLINE ALLSTATS LAST +PEEKED_BINDS',null)); 12 | select * from table(dbms_xplan.display_cursor('&1',null,'ADVANCED OUTLINE ALLSTATS LAST +PEEKED_BINDS')); 13 | -------------------------------------------------------------------------------- /explain_awr.sql: -------------------------------------------------------------------------------- 1 | -- explain.sql 2 | -- prints execution plan for a give sql_id 3 | -- detailed execution plan, taken from AWR 4 | -- Usage @explain 5 | -- by Luca 6 | 7 | --select * from table(dbms_xplan.display_cursor('&1')); 8 | --select * from table(dbms_xplan.display_cursor('&1',0,'ALLSTATS LAST')); 9 | --select * from table(dbms_xplan.display_cursor('&1',0,'TYPICAL OUTLINE')); 10 | --select * from table(dbms_xplan.display_cursor('&1',null,'ADVANCED OUTLINE ALLSTATS LAST +PEEKED_BINDS')); 11 | select * from table(dbms_xplan.display_awr('&1',null,null,'ADVANCED OUTLINE ALLSTATS LAST +PEEKED_BINDS')); -------------------------------------------------------------------------------- /filemetric.sql: -------------------------------------------------------------------------------- 1 | /* 2 | filematric.sql - displays files with significant IO activity 3 | Luca Feb-2008 4 | */ 5 | 6 | col name for a60 7 | col sec for 999 8 | col file# for 99999 9 | 10 | select sum(physical_block_writes) Phys_BLK_W, sum(physical_block_reads) Phys_BLK_R, round(avg(average_read_time)*10,1) AVG_read_ms, 11 | file_id file#, (select tablespace_name from dba_data_files ddf where ddf.file_id=fh.file_id) TBS_Name, 12 | to_char(max(begin_time),'hh24:mi') time, round(max(intsize_csec)/100,0) sec 13 | from gv$filemetric_history fh 14 | where begin_time >sysdate-1/24/3 15 | group by inst_id,file_id 16 | having sum(physical_block_writes) + sum(physical_block_writes) > 100 17 | order by 1 desc; 18 | -------------------------------------------------------------------------------- /flash.sql: -------------------------------------------------------------------------------- 1 | select * from v$flash_recovery_area_usage; 2 | -------------------------------------------------------------------------------- /iometric.sql: -------------------------------------------------------------------------------- 1 | -- iometric values in 11g 2 | -- Luca Jan 2012 3 | 4 | select min(begin_time) b_time, min(end_time) e_time, function_name, 5 | round(sum(small_read_iops+large_read_iops)) read_TOT_iops, round(sum(small_write_iops+large_write_iops)) write_TOT_iops, round(sum(large_read_mbps+small_read_mbps)) read_TOT_mbps, round(sum(large_write_mbps+small_write_mbps)) write_TOT_mbps 6 | from GV$IOFUNCMETRIC 7 | group by rollup(function_name) 8 | having round(sum(small_read_iops+large_read_iops)) + round(sum(large_read_mbps+small_read_mbps)) + round(sum(small_write_iops+large_write_iops)) + round(sum(large_write_mbps+small_write_mbps)) >0 9 | order by function_name; 10 | -------------------------------------------------------------------------------- /iometric_details.sql: -------------------------------------------------------------------------------- 1 | -- query to iofuncmetric view in 11g 2 | -- Luca Jan 2012 3 | 4 | 5 | select inst_id,begin_time,function_name, 6 | round(small_read_iops) RD_IOPS_sm, round(large_read_iops) RD_IOPS_lg, 7 | round(small_read_mbps) RD_MBPS_sm, round(large_read_mbps) RD_MBPS_lg, 8 | round(small_write_iops) WT_IOPS_sm, round(large_write_iops) WT_IOPS_lg, 9 | round(small_write_mbps) WT_MBPS_sm, round(large_write_mbps) WT_MBPS_lg 10 | from GV$IOFUNCMETRIC 11 | --where function_name in ('Buffer Cache Reads','LGWR','DBWR','Direct Reads','Direct Writes','RMAN') 12 | --where round(small_read_iops+large_read_iops+small_write_iops+large_write_iops) >0 13 | order by function_name,inst_id; 14 | 15 | select min(begin_time) b_time, min(end_time) e_time, round(sum(small_read_iops+large_read_iops)) read_TOT_iops, round(sum(large_read_mbps+small_read_mbps)) read_TOT_mbps, round(sum(small_write_iops+large_write_iops)) write_TOT_iops, round(sum(large_write_mbps+small_write_mbps)) write_TOT_mbps from GV$IOFUNCMETRIC; 16 | 17 | -------------------------------------------------------------------------------- /jobs_running.sql: -------------------------------------------------------------------------------- 1 | -- Display nfo on running jobs 2 | -- Luca Sep 2011 3 | 4 | 5 | col elapsed_time for a20 6 | col cpu_used for a20 7 | col inst_sid for a7 8 | 9 | --dbms_schedule_jobs 10 | select running_instance||'_'||session_id inst_sid,owner,job_name,elapsed_time,cpu_used from dba_SCHEDULER_RUNNING_JOBS; 11 | 12 | 13 | --old fashioned jobs 14 | select * from dba_jobs_running; -------------------------------------------------------------------------------- /kill.sql: -------------------------------------------------------------------------------- 1 | -- kill a given oracle session 2 | -- usage @kill 3 | 4 | alter system kill session '&1,&2' immediate; 5 | -------------------------------------------------------------------------------- /kill_select.sql: -------------------------------------------------------------------------------- 1 | REM creates selects statements for session kill 2 | REM Luca, Feb 2008 3 | 4 | col SQL for a80 5 | 6 | select 'alter system kill session '''||sid||','||serial#||''' immediate;' SQL 7 | from v$session where &1; 8 | -------------------------------------------------------------------------------- /load.sql: -------------------------------------------------------------------------------- 1 | REM prints server load as in linux 'w' 2 | REM Luca, Jan 2007 3 | 4 | col host_name for a20 5 | 6 | select ins.instance_name,ins.host_name,round(os.value,2) load 7 | from gv$osstat os, gv$instance ins 8 | where os.inst_id=ins.inst_id and os.stat_name='LOAD' 9 | order by 3 desc; 10 | -------------------------------------------------------------------------------- /locks.sql: -------------------------------------------------------------------------------- 1 | -- locks.sql locks and enqueue blocks for 11g 2 | -- Luca Jan 2012 3 | 4 | 5 | set feedback off 6 | col oracle_username for a15 7 | col owner for a15 8 | col object_name for a15 9 | col inst_sid_s# for a13 10 | col username for a14 11 | col obj_lck for a18 12 | col blk_info for a14 13 | col f_blk_info for a14 14 | col event for a30 15 | col s_wt for 9999 16 | col chain_signature for a65 17 | col Wsecs for 999 18 | 19 | /* 20 | 21 | prompt DML locks from current instance (dba_dml_locks) 22 | 23 | select session_id sid, owner,name,mode_held,mode_requested from dba_dml_locks; 24 | 25 | prompt 26 | prompt sessions with lockwait from gv$session 27 | 28 | select inst_id||' '||sid||','||serial# inst_sid_s#, username, row_wait_obj#||','||row_wait_block#||','||row_wait_row# obj_lck, 29 | blocking_session_Status||' '||blocking_instance||','||blocking_session blk_info, 30 | final_blocking_session_Status||' '||final_blocking_instance||','||final_blocking_session f_blk_info, 31 | event, seconds_in_wait s_wt 32 | from gv$session 33 | where lockwait is not null 34 | order by inst_id; 35 | 36 | prompt 37 | prompt waitchains (all events) 38 | 39 | select instance||' '||sid||','||sess_serial# inst_sid_s#, chain_signature,num_waiters wrs#,in_wait_secs Wsecs,row_wait_obj#||','||row_wait_block# obj_lck, 40 | blocker_is_valid||' '||blocker_instance||','||blocker_sid blk_info 41 | from v$wait_chains 42 | where in_wait='TRUE' and blocker_is_valid='TRUE' 43 | order by instance,chain_signature; 44 | 45 | */ 46 | 47 | prompt 48 | prompt final blockers from gv$session_blockers 49 | 50 | 51 | select * from GV$SESSION_BLOCKERS; 52 | 53 | 54 | prompt 55 | prompt final blockers from gv$session (all events) 56 | 57 | select final_blocking_instance f_blk_inst, final_blocking_session f_blk_sess, event, sql_id, row_wait_obj#||','||row_wait_block# obj_lck, count(*) num_blocked, round(max(wait_time_micro)/1000000,2) max_wait_sec 58 | from gv$session 59 | where final_blocking_session_Status='VALID' 60 | group by final_blocking_instance, final_blocking_session, event, sql_id, row_wait_obj#||','||row_wait_block# 61 | order by 1; 62 | 63 | 64 | /* 65 | 66 | prompt global blocked locks 67 | 68 | select * from GV$GLOBAL_BLOCKED_LOCKS ; 69 | 70 | prompt TX locks 71 | 72 | select * from gv$transaction_enqueue; 73 | 74 | prompt waiting sessions 75 | 76 | select inst_id,sid,process,username,row_wait_obj#,LOCKWAIT,blocking_instance blk_inst, blocking_session blk_sid 77 | from gv$session 78 | where lockwait is not null; 79 | 80 | prompt blocking sessions 81 | 82 | select sid,username,row_wait_obj#,row_wait_block#,row_wait_row#,blocking_session from gv$session a where row_wait_obj#<>0 and blocking_Session is not null order by 2,1; 83 | 84 | prompt blockers from gv$Lock 85 | 86 | select inst_id,sid,type,ctime LOCK_TIME,id1,id2 87 | from gv$lock 88 | where block =1; 89 | 90 | 91 | */ 92 | 93 | set feedback on 94 | -------------------------------------------------------------------------------- /locks_10g.sql: -------------------------------------------------------------------------------- 1 | /* 2 | lock.sql locks and enqueue blocks for 10g 3 | By Luca Canali 2006 4 | */ 5 | 6 | set feedback off 7 | col oracle_username for a15 8 | col owner for a15 9 | col object_name for a15 10 | 11 | 12 | prompt DML locks from current instance 13 | 14 | select session_id sid, owner,name,mode_held,mode_requested from dba_dml_locks; 15 | 16 | prompt blockers from gv$Lock 17 | 18 | select inst_id,sid,type,ctime LOCK_TIME,id1,id2 19 | from gv$lock 20 | where block =1; 21 | 22 | 23 | /* 24 | 25 | prompt global blocked locks 26 | 27 | select * from GV$GLOBAL_BLOCKED_LOCKS ; 28 | 29 | prompt TX locks 30 | 31 | select * from gv$transaction_enqueue; 32 | 33 | prompt waiting sessions 34 | 35 | select inst_id,sid,process,username,row_wait_obj#,LOCKWAIT,blocking_instance blk_inst, blocking_session blk_sid 36 | from gv$session 37 | where lockwait is not null; 38 | 39 | prompt blocking sessions 40 | 41 | select sid,username,row_wait_obj#,row_wait_block#,row_wait_row#,blocking_session from gv$session a where row_wait_obj#<>0 and blocking_Session is not null order by 2,1; 42 | 43 | */ 44 | 45 | --in 11g can use select .. from v$wait_chains 46 | 47 | set feedback on 48 | -------------------------------------------------------------------------------- /locks_details.sql: -------------------------------------------------------------------------------- 1 | -- locks.sql locks and enqueue blocks for 11g 2 | -- Luca Jan 2012 3 | 4 | 5 | set feedback off 6 | col oracle_username for a15 7 | col owner for a15 8 | col object_name for a15 9 | col inst_sid_s# for a13 10 | col username for a14 11 | col obj_lck for a18 12 | col blk_info for a14 13 | col f_blk_info for a14 14 | col event for a30 15 | col s_wt for 9999 16 | col chain_signature for a65 17 | col Wsecs for 999 18 | 19 | prompt DML locks from current instance (dba_dml_locks) 20 | 21 | select session_id sid, owner,name,mode_held,mode_requested from dba_dml_locks; 22 | 23 | prompt 24 | prompt sessions with lockwait from gv$session 25 | 26 | select inst_id||' '||sid||','||serial# inst_sid_s#, username, row_wait_obj#||','||row_wait_block#||','||row_wait_row# obj_lck, 27 | blocking_session_Status||' '||blocking_instance||','||blocking_session blk_info, 28 | final_blocking_session_Status||' '||final_blocking_instance||','||final_blocking_session f_blk_info, 29 | event, seconds_in_wait s_wt 30 | from gv$session 31 | where lockwait is not null 32 | order by inst_id; 33 | 34 | prompt 35 | prompt waitchains (all events) 36 | 37 | select instance||' '||sid||','||sess_serial# inst_sid_s#, chain_signature,num_waiters wrs#,in_wait_secs Wsecs,row_wait_obj#||','||row_wait_block# obj_lck, 38 | blocker_is_valid||' '||blocker_instance||','||blocker_sid blk_info 39 | from v$wait_chains 40 | where in_wait='TRUE' and blocker_is_valid='TRUE' 41 | order by instance,chain_signature; 42 | 43 | prompt 44 | prompt final blockers from gv$session (all events) 45 | 46 | select final_blocking_instance f_blk_inst, final_blocking_session f_blk_sess, event, sql_id, row_wait_obj#||','||row_wait_block# obj_lck, count(*) num_blocked, max(wait_time_micro) max_wait_musec 47 | from gv$session 48 | where final_blocking_session_Status='VALID' 49 | group by final_blocking_instance, final_blocking_session, event, sql_id, row_wait_obj#||','||row_wait_block# 50 | order by 1; 51 | 52 | 53 | /* 54 | 55 | prompt global blocked locks 56 | 57 | select * from GV$GLOBAL_BLOCKED_LOCKS ; 58 | 59 | prompt TX locks 60 | 61 | select * from gv$transaction_enqueue; 62 | 63 | prompt waiting sessions 64 | 65 | select inst_id,sid,process,username,row_wait_obj#,LOCKWAIT,blocking_instance blk_inst, blocking_session blk_sid 66 | from gv$session 67 | where lockwait is not null; 68 | 69 | prompt blocking sessions 70 | 71 | select sid,username,row_wait_obj#,row_wait_block#,row_wait_row#,blocking_session from gv$session a where row_wait_obj#<>0 and blocking_Session is not null order by 2,1; 72 | 73 | prompt blockers from gv$Lock 74 | 75 | select inst_id,sid,type,ctime LOCK_TIME,id1,id2 76 | from gv$lock 77 | where block =1; 78 | 79 | 80 | */ 81 | 82 | set feedback on 83 | -------------------------------------------------------------------------------- /login.sql: -------------------------------------------------------------------------------- 1 | -- sqlplus startup scripts, sets up prompt, etc 2 | -- Luca 2005, last updated from 11g Mar 2012 3 | 4 | set termout off 5 | set long 5000 6 | 7 | set pagesize 9999 8 | set linesize 180 9 | set longchunksize 180 10 | set arraysize 100 11 | 12 | set num 10 13 | 14 | define gname=idle 15 | column global_name new_value gname 16 | --select lower(user) || '@' || sys_context('USERENV','INSTANCE_NAME') global_name from dual; 17 | select lower(sys_context('USERENV','DATABASE_ROLE'))||':'||lower(user) || '@' || sys_context('USERENV','INSTANCE_NAME') global_name from dual; 18 | select lower(sys_context('USERENV','DATABASE_ROLE'))||':'||lower(user) || '@' || sys_context('USERENV','DB_UNIQUE_NAME') || '-' ||sys_context('USERENV','INSTANCE_NAME') global_name from dual; 19 | 20 | 21 | set sqlprompt '&gname> ' 22 | 23 | host title sqlplus connected to &gname 24 | alter session set nls_date_format='dd-mm-yy hh24:mi'; 25 | 26 | set tab off 27 | set termout on 28 | 29 | -------------------------------------------------------------------------------- /longops.sql: -------------------------------------------------------------------------------- 1 | -- Session longops 2 | -- By L. Canali 3 | -- Oct 04, updated for 11g Mar 2012 4 | 5 | col remaining for 999999 6 | col elapsed for 999999 7 | col hash for 9999999999 8 | col inst_sid_ser for a13 9 | col username for a20 10 | col message for a80 11 | col exec_plan for a25 12 | 13 | 14 | select inst_id||'_'||sid||' '||serial# inst_sid_ser,username,time_remaining remaining,elapsed_seconds elapsed, sql_id, 15 | sql_plan_operation||'-'||sql_plan_options||', '||sql_plan_line_id exec_plan, 16 | message 17 | from gv$session_longops 18 | where time_remaining>0; 19 | -------------------------------------------------------------------------------- /longops_10g.sql: -------------------------------------------------------------------------------- 1 | -- Session longops 2 | -- By Luca Canali 3 | -- Oct 04 4 | 5 | col remaining for 999999 6 | col elapsed for 999999 7 | col hash for 9999999999 8 | col sid for 9999 9 | col username for a10 10 | col opname for a15 11 | col message for a45 12 | 13 | 14 | select inst_id,sid,username,time_remaining remaining, elapsed_seconds elapsed, sql_id, opname,message 15 | from gv$session_longops 16 | where time_remaining>0; 17 | -------------------------------------------------------------------------------- /longops_details.sql: -------------------------------------------------------------------------------- 1 | -- Session longops 2 | -- By L. Canali 3 | -- Oct 04 4 | 5 | col remaining for 999999 6 | col elapsed for 999999 7 | col hash for 9999999999 8 | col inst_sid_ser for a13 9 | col username for a25 10 | col message for a100 11 | col exec_plan for a25 12 | 13 | 14 | prompt longops last day with daration > 60 sec 15 | 16 | select inst_id||'_'||sid||' '||serial# inst_sid_ser,username,start_time,elapsed_seconds elapsed, sql_id, 17 | message 18 | from gv$session_longops 19 | where time_remaining=0 20 | and elapsed_seconds>60 21 | and start_time >sysdate-1 order by start_time desc; 22 | -------------------------------------------------------------------------------- /monitor.sql: -------------------------------------------------------------------------------- 1 | -- read from sql_monitor 2 | -- Luca March 2012 3 | 4 | @@monitor_details status='EXECUTING' 5 | 6 | -------------------------------------------------------------------------------- /monitor_details.sql: -------------------------------------------------------------------------------- 1 | -- read from sql_monitor 2 | -- Luca March 2012 3 | 4 | -- used by monitor.sql script 5 | -- usage @monitor_details "" 6 | 7 | col key for 9999999999999 8 | col inst_sid_ser for a13 9 | col username for a24 10 | col mod_action for a32 11 | col R_MB for 9999999 12 | col W_MB for 9999 13 | col px for 99 14 | 15 | select key, inst_id||'_'||sid||' '||session_serial# inst_sid_ser, 16 | username||case when regexp_substr(program,' \(.+') <> ' (TNS V1-V3)' then regexp_substr(program,' \(.+') end username, 17 | regexp_substr(module,'.+@.+cern')||' '||ACTION mod_action, 18 | sql_id, round(elapsed_time/1000000,1) elaps_s, round(cpu_time/1000000,1) cpu_s, 19 | round(user_io_wait_time/1000000,1) iowait_s,round((cluster_wait_time+application_wait_time+plsql_exec_time+java_exec_time)/1000000,1) other_s, 20 | physical_read_requests R_IOPS,round(physical_read_bytes/1000000,1) R_MB,round(physical_write_bytes/1000000,1) W_MB, PX_SERVERS_ALLOCATED PX 21 | from gv$sql_monitor where &1 22 | order by SQL_EXEC_START desc; 23 | 24 | -------------------------------------------------------------------------------- /monitor_plan.sql: -------------------------------------------------------------------------------- 1 | -- select from v$sql_monitor_plan by key 2 | -- Luca, March 2012 3 | 4 | -- Usage: @monitor_plan 5 | 6 | set verify off 7 | col operation for a70 8 | col part for a12 9 | 10 | select status,sql_exec_start,last_refresh_time,sid,process_name,sql_id,sql_plan_hash_value,sql_child_address 11 | from gv$sql_plan_monitor where key=&1 and rownum=1; 12 | 13 | 14 | select lpad(' ',plan_depth)||plan_operation||' '||plan_options||nullif(' - '||plan_object_owner||'.'||plan_object_name||' ('||plan_object_type||')',' - . ()') operation, 15 | plan_cost p_cost,plan_cardinality p_card,output_rows outp_rows,starts,physical_read_requests R_iops, 16 | round(physical_read_bytes/1000000,1) R_MB,round(physical_write_bytes/1000000,1) W_MB, 17 | round(workarea_mem/1000000,1) pga_MB,round(workarea_tempseg/1000000,1) temp_mb, 18 | nullif(plan_partition_start||'-'||plan_partition_stop,'-') part 19 | from gv$sql_plan_monitor where key=&1 20 | order by plan_line_id; -------------------------------------------------------------------------------- /monitor_report_sid.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Generates and prints sql_monitor report for a given SID 3 | -- Luca Jan 2014 4 | -- Usage: @monitor_report_sid SID 5 | 6 | set long 1000000000 7 | set longc 2000 8 | set pages 0 9 | set lines 1500 10 | set verify off 11 | set heading off 12 | set termout off 13 | 14 | host del reports\scratch_report_sql_monitor.html 15 | spool reports\scratch_report_sql_monitor.html 16 | SELECT DBMS_SQLTUNE.REPORT_SQL_MONITOR(SESSION_ID=>&1, report_level=>'ALL', type => 'HTML') as report FROM dual; 17 | spool off 18 | set heading on 19 | set termout on 20 | set pages 1000 21 | 22 | host reports\scratch_report_sql_monitor.html 23 | 24 | 25 | -------------------------------------------------------------------------------- /monitor_report_sid_active.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Generates and prints sql_monitor report for a given SID 3 | -- Luca Jan 2014 4 | -- Usage: @monitor_report_sid_active SID 5 | 6 | set long 1000000000 7 | set longc 2000 8 | set pages 0 9 | set lines 1500 10 | set verify off 11 | set heading off 12 | set termout off 13 | 14 | host del reports\scratch_report_sql_monitor.html 15 | spool reports\scratch_report_sql_monitor.html 16 | SELECT DBMS_SQLTUNE.REPORT_SQL_MONITOR(SESSION_ID=>&1, report_level=>'ALL', type => 'ACTIVE') as report FROM dual; 17 | spool off 18 | set heading on 19 | set termout on 20 | set pages 1000 21 | 22 | host reports\scratch_report_sql_monitor.html 23 | 24 | 25 | -------------------------------------------------------------------------------- /monitor_report_sql_id.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Generates and prints sql_monitor report for a given sql_id 3 | -- Luca Jan 2014 4 | -- Usage: @monitor_report sql_id 5 | 6 | set long 1000000000 7 | set longc 2000 8 | set pages 0 9 | set lines 1500 10 | set verify off 11 | set heading off 12 | set termout off 13 | 14 | host del reports\scratch_report_sql_monitor.html 15 | spool reports\scratch_report_sql_monitor.html 16 | SELECT DBMS_SQLTUNE.REPORT_SQL_MONITOR(SQL_ID=>'&1', report_level=>'ALL', type => 'HTML') as report FROM dual; 17 | spool off 18 | set heading on 19 | set termout on 20 | set pages 1000 21 | 22 | host reports\scratch_report_sql_monitor.html 23 | 24 | 25 | -------------------------------------------------------------------------------- /monitor_report_sql_id_active.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Generates and prints sql_monitor report for a given sql_id 3 | -- Luca Jan 2014 4 | -- Usage: @monitor_report sql_id 5 | 6 | set long 1000000000 7 | set longc 2000 8 | set pages 0 9 | set lines 1500 10 | set verify off 11 | set heading off 12 | set termout off 13 | 14 | host del reports\scratch_report_sql_monitor.html 15 | spool reports\scratch_report_sql_monitor.html 16 | SELECT DBMS_SQLTUNE.REPORT_SQL_MONITOR(SQL_ID=>'&1', report_level=>'ALL', type => 'ACTIVE') as report FROM dual; 17 | spool off 18 | set heading on 19 | set termout on 20 | set pages 1000 21 | 22 | host reports\scratch_report_sql_monitor.html 23 | 24 | 25 | -------------------------------------------------------------------------------- /obj.sql: -------------------------------------------------------------------------------- 1 | -- object details from data_object_id 2 | -- Luca Feb 2011 3 | 4 | -- note for advanced troubleshooting 5 | -- RBS segments use obj_id = 4294950912 + SEG_ID (as seen in dba_rollback_segs) 6 | -- fixed objects had object ID in SYS.X$KQFTA (which are also numbers above 4294950912 ) 7 | 8 | 9 | col owner for a10 10 | col object_name for a20 11 | col subobject_name for a20 12 | col object_type for a10 13 | 14 | select owner,object_name,SUBOBJECT_NAME,object_type,object_id,data_object_id,created,last_ddl_time from dba_objects where data_object_id=&1 or object_id=&1; 15 | 16 | -------------------------------------------------------------------------------- /reports/README.txt: -------------------------------------------------------------------------------- 1 | This directory is intentionally empty. 2 | It is used to store the output of ash_report and awr_report among other scripts -------------------------------------------------------------------------------- /sessmetric.sql: -------------------------------------------------------------------------------- 1 | /* 2 | sesmetric.sql 3 | displays resource utilization per session 4 | By Luca Canali 2005 5 | */ 6 | 7 | 8 | select * from ( 9 | select inst_id, session_id sid, to_char(begin_time,'hh24:mi:ss') begTime, round(intsize_csec/100,0) D_sec, cpu, 10 | physical_reads PhyReads, logical_reads LogicalReads, pga_memory, hard_parses, soft_parses 11 | from gv$sessmetric 12 | order by cpu+physical_reads desc 13 | ) 14 | where rownum<20 15 | / 16 | -------------------------------------------------------------------------------- /sql.sql: -------------------------------------------------------------------------------- 1 | /* sql.sql script to display sql instructions for a give sql_id 2 | By Luca Canali 2005 3 | */ 4 | 5 | set verify off 6 | set long 4000 7 | col sql_fulltext for a400 8 | 9 | --select inst_id,sql_text from gv$sqltext where sql_id='&1' order by inst_id,piece; 10 | select inst_id,sql_fulltext from gv$sqlstats where sql_id='&1' order by inst_id; 11 | -------------------------------------------------------------------------------- /sysmetric.sql: -------------------------------------------------------------------------------- 1 | /* 2 | sysmetric.sql - sqlplus script - displays significant system metrics 3 | By Luca Nov 2007 4 | */ 5 | 6 | col "Time+Delta" for a14 7 | col metric for a56 8 | col "Total" for a10 9 | 10 | set linesize 140 11 | set pagesize 1000 12 | 13 | set wrap off 14 | REM truncates the metric field to max length 15 | 16 | select "Time+Delta", "Metric", 17 | case when "Total" >10000000 then '* '||round("Total"/1024/1024,0)||' M' 18 | when "Total" between 10000 and 10000000 then '+ '||round("Total"/1024,0)||' K' 19 | when "Total" between 10 and 1024 then ' '||to_char(round("Total",0)) 20 | else ' '||to_char("Total") 21 | end "Total" 22 | from ( 23 | select to_char(min(begin_time),'hh24:mi:ss')||' /'||round(avg(intsize_csec/100),0)||'s' "Time+Delta", 24 | metric_name||' - '||metric_unit "Metric", 25 | nvl(sum(value_inst1),0)+nvl(sum(value_inst2),0)+nvl(sum(value_inst3),0)+nvl(sum(value_inst4),0)+ 26 | nvl(sum(value_inst5),0)+nvl(sum(value_inst6),0)+nvl(sum(value_inst7),0)+nvl(sum(value_inst8),0) "Total", 27 | sum(value_inst1) inst1, sum(value_inst2) inst2, sum(value_inst3) inst3, sum(value_inst4) inst4, 28 | sum(value_inst5) inst5, sum(value_inst6) inst6, sum(value_inst7) inst7, sum(value_inst8) inst8 29 | from 30 | ( select begin_time,intsize_csec,metric_name,metric_unit,metric_id,group_id, 31 | case inst_id when 1 then round(value,1) end value_inst1, 32 | case inst_id when 2 then round(value,1) end value_inst2, 33 | case inst_id when 3 then round(value,1) end value_inst3, 34 | case inst_id when 4 then round(value,1) end value_inst4, 35 | case inst_id when 5 then round(value,1) end value_inst5, 36 | case inst_id when 6 then round(value,1) end value_inst6, 37 | case inst_id when 7 then round(value,1) end value_inst7, 38 | case inst_id when 8 then round(value,1) end value_inst8 39 | from gv$sysmetric 40 | where metric_name in ('Host CPU Utilization (%)','Current OS Load', 'Physical Write Total IO Requests Per Sec', 41 | 'Physical Write Total Bytes Per Sec', 'Physical Write IO Requests Per Sec', 'Physical Write Bytes Per Sec', 42 | 'I/O Requests per Second', 'I/O Megabytes per Second', 43 | 'Physical Read Total Bytes Per Sec', 'Physical Read Total IO Requests Per Sec', 'Physical Read IO Requests Per Sec', 44 | 'CPU Usage Per Sec','Network Traffic Volume Per Sec','Logons Per Sec','Redo Generated Per Sec','Redo Writes Per Sec', 45 | 'User Transaction Per Sec','Average Active Sessions','Average Synchronous Single-Block Read Latency', 46 | 'Logical Reads Per Sec','DB Block Changes Per Sec') 47 | ) 48 | group by metric_id,group_id,metric_name,metric_unit 49 | order by metric_name 50 | ); 51 | 52 | set wrap on 53 | 54 | @@iometric 55 | -------------------------------------------------------------------------------- /sysmetric_details.sql: -------------------------------------------------------------------------------- 1 | /* 2 | sysmetric_details.sql - sqlplus script - displays significant system metrics detailed per RAC instance 3 | By Luca Nov 2007 4 | */ 5 | 6 | col "Time+Delta" for a14 7 | col "Metric" for a40 8 | col "Total" for a10 9 | col metric_name for a25 10 | 11 | set linesize 140 12 | set pagesize 1000 13 | 14 | set wrap off 15 | REM truncates the metric field to max length 16 | 17 | select to_char(min(begin_time),'hh24:mi:ss')||' /'||round(avg(intsize_csec/100),0)||'s' "Time+Delta", 18 | metric_name||' - '||metric_unit "Metric", 19 | sum(value_inst1) inst1, sum(value_inst2) inst2, sum(value_inst3) inst3, sum(value_inst4) inst4, 20 | sum(value_inst5) inst5, sum(value_inst6) inst6 21 | from 22 | ( select begin_time,intsize_csec,metric_name,metric_unit,metric_id,group_id, 23 | case inst_id when 1 then round(value,1) end value_inst1, 24 | case inst_id when 2 then round(value,1) end value_inst2, 25 | case inst_id when 3 then round(value,1) end value_inst3, 26 | case inst_id when 4 then round(value,1) end value_inst4, 27 | case inst_id when 5 then round(value,1) end value_inst5, 28 | case inst_id when 6 then round(value,1) end value_inst6 29 | from gv$sysmetric 30 | where metric_name in ('Host CPU Utilization (%)','Current OS Load', 'Physical Write Total IO Requests Per Sec', 31 | 'Physical Write Total Bytes Per Sec', 'Physical Write IO Requests Per Sec', 'Physical Write Bytes Per Sec', 32 | 'I/O Requests per Second', 'I/O Megabytes per Second', 33 | 'Physical Read Total Bytes Per Sec', 'Physical Read Total IO Requests Per Sec', 'Physical Read IO Requests Per Sec', 34 | 'CPU Usage Per Sec','Network Traffic Volume Per Sec','Logons Per Sec','Redo Generated Per Sec', 35 | 'User Transaction Per Sec','Average Active Sessions','Average Synchronous Single-Block Read Latency', 36 | 'Logical Reads Per Sec','DB Block Changes Per Sec') 37 | ) 38 | group by metric_id,group_id,metric_name,metric_unit 39 | order by metric_name; 40 | 41 | set wrap on -------------------------------------------------------------------------------- /top.sql: -------------------------------------------------------------------------------- 1 | -- Top.sql: prints details of active sessions 2 | -- Usage: @top, run a few times on to see dynamics of active sessions 3 | -- Luca Canali 2002, last updated and customized for 11g, Apr 2012 4 | 5 | set lines 180 6 | col inst_sid_ser for a13 7 | col username for a23 8 | col serv_mod_action for a48 9 | col tr for a2 10 | col event for a32 11 | col sql_id for a13 12 | col sql_dT for 999999 13 | col call_dT for 9999999 14 | col W_dT for 9999 15 | col obj# for 99999999 16 | 17 | 18 | select inst_id||'_'||sid||' '||serial# inst_sid_ser, 19 | username||case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username, 20 | sql_id sql_id, 21 | round((sysdate-sql_exec_start)*24*3600,1) sql_dT, 22 | last_call_et call_dT, 23 | case state when 'WAITING' then round(wait_time_micro/1000000,2) else round(time_since_last_wait_micro/1000000,2) end W_dT, 24 | decode(state,'WAITING',event,'CPU') event, 25 | service_name||' '||substr(module,1,20)||' '||ACTION serv_mod_action, 26 | nullif(row_wait_obj#,-1) obj#,decode(taddr,null,null,'NN') tr 27 | from gv$session 28 | where ((state='WAITING' and wait_class<>'Idle') or (state<>'WAITING' and status='ACTIVE')) 29 | --and audsid != to_number(sys_context('USERENV','SESSIONID')) -- this is clean but does not work on ADG so replaced by following line 30 | and (machine,port) <> (select machine,port from v$session where sid=sys_context('USERENV','SID')) --workaround for ADG 31 | order by inst_id,sql_id 32 | / 33 | 34 | 35 | -------------------------------------------------------------------------------- /top_10g.sql: -------------------------------------------------------------------------------- 1 | -- Top.sql: prints details of active sessions 2 | -- Usage: @top, run a few times on to see dynamics of active sessions 3 | -- Luca Canali 2002, last updated and customized for 10g Feb 2011 4 | 5 | col username for a21 6 | col service for a19 7 | col "User@Term" for a10 8 | col program for a22 9 | col inst_sid_serial# for a12 10 | col seq for a5 11 | col module for a15 12 | col tr for a2 13 | col event for a25 14 | col sql_id for a13 15 | col elaps for 9999999 16 | col w_tim for 9999 17 | col state for a7 18 | set linesize 150 19 | set pagesize 1000 20 | col "Event details" for a37 21 | col obj# for 99999999 22 | col module for a16 23 | 24 | set lines 180 25 | 26 | select inst_id||'_'||sid||' '||serial# inst_sid_serial#,nvl(username,'PRG: '||program) username, service_name service, substr(module,0,15) module, decode(taddr,null,null,'NN') tr, 27 | sql_id, decode(state,'WAITING',null,state||':')||event event, row_wait_obj# obj#, 28 | p1text||'='||p1||'; '||p2text||'='||p2||'; '||p3text||'='||p3 "Event details", 29 | case state when 'WAITING' then seconds_in_wait else wait_time end w_tim, last_call_et elaps 30 | from gv$session 31 | where status='ACTIVE' 32 | and not (username is null and wait_class='Idle') 33 | and not (username in ('SYS','DBSNMP') and wait_class='Idle') 34 | and audsid !=sys_context('USERENV','SESSIONID') 35 | order by inst_id 36 | / -------------------------------------------------------------------------------- /transactions.sql: -------------------------------------------------------------------------------- 1 | -- lists transactions open and in crash recovery 2 | -- Luca Feb2011 3 | 4 | select inst_id,addr,start_time,used_ublk,xid from gv$transaction; 5 | 6 | select inst_id,state,undoblocksdone,undoblockstotal,xid from gv$fast_start_transactions; 7 | 8 | SELECT sess.sid, sess.status, sess.username, machine, sql_id, prev_sql_id, trans.USED_UBLK, trans.start_date 9 | from gv$session sess, gv$transaction trans 10 | WHERE sess.taddr=trans.addr and sess.inst_id=trans.inst_id; 11 | --------------------------------------------------------------------------------