I’ve updated some of my ASH scripts to use these 4 arguments in a standard way:
- What ASH columns to display (and aggregate by)
- Which ASH rows to use for the report (filter)
- Time range start
- Time range end
So this means whenever I run ashtop (or dashtop) for example, I need to type in all 4 parameters. The example below would show top SQL_IDs only for user SOE sessions from last hour of ASH samples:
SQL> @ashtop sql_id username='SOE' sysdate-1/24 sysdate Total Seconds AAS %This SQL_ID FIRST_SEEN LAST_SEEN DIST_SQLEXEC_SEEN --------- ------- ------- ------------- ------------------- ------------------- ----------------- 2271 .6 21% | 56pwkjspvmg3h 2015-03-29 13:13:16 2015-03-29 13:43:34 145 2045 .6 19% | gkxxkghxubh1a 2015-03-29 13:13:16 2015-03-29 13:43:14 149 1224 .3 11% | 29qp10usqkqh0 2015-03-29 13:13:25 2015-03-29 13:43:32 132 959 .3 9% | c13sma6rkr27c 2015-03-29 13:13:19 2015-03-29 13:43:34 958 758 .2 7% | 2015-03-29 13:13:16 2015-03-29 13:43:31 1
When I want more control and specify a fixed time range, I can just use the ANSI TIMESTAMP (or TO_DATE) syntax:
SQL> @ashtop sql_id username='SOE' "TIMESTAMP'2015-03-29 13:00:00'" "TIMESTAMP'2015-03-29 13:15:00'" Total Seconds AAS %This SQL_ID FIRST_SEEN LAST_SEEN DIST_SQLEXEC_SEEN --------- ------- ------- ------------- ------------------- ------------------- ----------------- 153 .2 22% | 56pwkjspvmg3h 2015-03-29 13:13:29 2015-03-29 13:14:59 9 132 .1 19% | gkxxkghxubh1a 2015-03-29 13:13:29 2015-03-29 13:14:59 8 95 .1 14% | 29qp10usqkqh0 2015-03-29 13:13:29 2015-03-29 13:14:52 7 69 .1 10% | c13sma6rkr27c 2015-03-29 13:13:31 2015-03-29 13:14:58 69 41 .0 6% | 2015-03-29 13:13:34 2015-03-29 13:14:59 1
Note that the arguments 3 & 4 above are in double quotes as there’s a space within the timestamp value. Without the double-quotes, sqlplus would think the script has total 6 arguments due to the spaces.
I don’t like to type too much though (every character counts!) so I was happy to see that the following sqlplus hack works. I just defined pairs of arguments as sqlplus DEFINE variables as seen below (also in init.sql now):
-- geeky shorcuts for producing date ranges for various ASH scripts define min="sysdate-1/24/60 sysdate" define minute="sysdate-1/24/60 sysdate" define 5min="sysdate-1/24/12 sysdate" define hour="sysdate-1/24 sysdate" define 2hours="sysdate-1/12 sysdate" define 24hours="sysdate-1 sysdate" define day="sysdate-1 sysdate" define today="TRUNC(sysdate) sysdate"
And now I can type just 3 arguments instead of 4 when I run some of my scripts and want some predefined behavior like seeing last 5 minutes’ activity:
SQL> @ashtop sql_id username='SOE' &5min Total Seconds AAS %This SQL_ID FIRST_SEEN LAST_SEEN DIST_SQLEXEC_SEEN --------- ------- ------- ------------- ------------------- ------------------- ----------------- 368 1.2 23% | gkxxkghxubh1a 2015-03-29 13:39:34 2015-03-29 13:44:33 37 241 .8 15% | 56pwkjspvmg3h 2015-03-29 13:40:05 2015-03-29 13:44:33 25 185 .6 12% | 29qp10usqkqh0 2015-03-29 13:39:40 2015-03-29 13:44:33 24 129 .4 8% | c13sma6rkr27c 2015-03-29 13:39:35 2015-03-29 13:44:32 129 107 .4 7% | 2015-03-29 13:39:34 2015-03-29 13:44:33 1
That’s it, I hope this hack helps :-)
By the way – if you’re a command line & sqlplus fan, check out the SQLCL command line “new sqlplus” tool from the SQL Developer team! (you can download it from the SQL Dev early adopter page for now).