Re: Sorting High Water Mark anywhere?

From: Rich Jesse <rjoralist2_at_society.servebeer.com>
Date: Fri, 25 Jan 2013 09:54:53 -0600 (CST)
Message-ID: <fa1eb445cfda7df2ac976648d23c95e2.squirrel_at_society.servebeer.com>



Hey Chris,

> I'd like to be able to determine, say over 24 hours, how much sorting is
being done in memory, and how much is begin done on disk.

I needed to monitor large temp usage, so I threw together this:

SELECT /* RULE */ sysdate "TIME_STAMP", vsu.username, vsu.sql_id, vsu.tablespace, vsu.usage_mb, vst.sql_text, vp.spid FROM
(

        SELECT username, sqladdr, sqlhash, sql_id, tablespace, session_addr, sum(blocks)*8192/1024/1024 "USAGE_MB"

	FROM v$sort_usage
	HAVING SUM(blocks)> 10000
	GROUP BY username, sqladdr, sqlhash, sql_id, tablespace, session_addr ) "VSU",
v$sqltext vst,

v$session vs,
v$process vp
WHERE vsu.sql_id = vst.sql_id
	AND vsu.sqladdr = vst.address
	AND vsu.sqlhash = vst.hash_value
	AND vsu.session_addr = vs.saddr
	AND vs.paddr = vp.addr
	AND vst.piece = 0;

Caveats: blocksize is hardcoded, the HAVING clause only looks for large usage, it doesn't consider CTAS usage (see MOS 67534.1), and the RULE hint was needed for performance in 10.1.

The view needs to be polled at regular intervals, so it's not a true HWM. It's just something to possibly get you started down the manual path of monitoring TEMP.

HTH! GL! Rich

--
http://www.freelists.org/webpage/oracle-l
Received on Fri Jan 25 2013 - 16:54:53 CET

Original text of this message