Tuesday, March 21, 2017

An easier way to call dbms_xplan.display_cursor

Similar to xplan.sql, but calls dbms_xplan.display_cursor instead of Explain Plan. (I added the 'x' for 'extended', rather unimaginatively.)
How often have you wanted to get the extended plan using dbms_xplan.display_cursor and had to type out the whole thing laboriously? And then after doing that, realised you had forgotten to set serveroutput off, so SQL*Plus callsdbms_output.get_lines right after your query, ruining your test? And you don't really want all the query results scrolling up the screen either, so ideally you would set termout off as well - except that only works from a script, and not from the interactive prompt.
xplanx.sql saves your current settings, makes the settings it needs to, executes the contents of the current SQL buffer (i.e. the most recent SQL statement to be run, edited, fetched etc), invokes dbms_xplan.display_cursor and then places the statement back in the buffer so you can carry on working on it, as far as possible leaving everything the way it was.
  1. -- xplanx.sql
  2. -- William Robertson - www.williamrobertson.net
  3. -- Transparent "dbms_xplan.display_cursor" utility for SQL*Plus.
  4. --
  5. -- Usage:
  6. -- @xplanx
  7. -- Executes the contents of the current SQL buffer (i.e. the most recent SQL statement to be run, edited, fetched etc,
  8. -- invokes dbms_xplan.display_cursor() and then places the statement back in the buffer, as far as possible leaving everything
  9. -- the way it was, including any serveroutput setting (which it disables before executing the statement).
  10.  
  11. set term off
  12. store set sqlplus_settings.tmp replace
  13.  
  14. -- Capture the current SQL buffer as a script:
  15. save xplan.buf repl
  16.  
  17. -- Adjust terminal window size to match linesize below
  18. define terminal_width = 200
  19. set linesize &terminal_width
  20. set pagesize 999 trimspool on heading off pause off feed off verify off timing off autotrace off flagger off tab off trimout on serverout off arraysize 200
  21.  
  22. ttitle off
  23.  
  24. -- To do: detect the current setting before altering, then restore this at the end:
  25. alter session set statistics_level = 'ALL';
  26.  
  27. timing start "Query execution time"
  28. -- Execute the SQL buffer that was captured earlier:
  29. @xplan.buf
  30.  
  31. col plan_table_output clear
  32. col plan_table_output format a&terminal_width
  33. set term on
  34.  
  35. select p.plan_table_output
  36. from table(dbms_xplan.display_cursor(null,null,'ALLSTATS LAST +OUTLINE +NOTE')) p;
  37.  
  38. timing stop
  39.  
  40. @sqlplus_settings.tmp replace
  41. -- Note "del" command assumes Windows. Change to "rm" for Unix/Linux/Mac:
  42. host del sqlplus_settings.tmp
  43. undef terminal_width
  44. get xplan.buf nolist
  45. set term on
  46.  

No comments:

Post a Comment