RE: What sql is using undo tablespace

  • From: Jonathan Lewis <jonathan@xxxxxxxxxxxxxxxxxx>
  • To: "oracle-l@xxxxxxxxxxxxx" <oracle-l@xxxxxxxxxxxxx>
  • Date: Tue, 13 May 2014 15:42:04 +0000


v$sessstat (joined to v$statname) gives you three statistics at the session 
level (not statement, of course).
data blocks consistent reads - undo records applied
this will usually be similar to
consistent changes

Who's rolling back
rollback changes - undo records applied

A slightly exotic one about finding (upper bound) commit SCNs for transactions 
that committed a "long" time in the past.
transaction tables consistent reads - undo records applied


Regards
Jonathan Lewis
http://jonathanlewis.wordpress.com
@jloracle
________________________________
From: oracle-l-bounce@xxxxxxxxxxxxx [oracle-l-bounce@xxxxxxxxxxxxx] on behalf 
of Adam Musch [ahmusch@xxxxxxxxx]
Sent: 13 May 2014 14:56
To: dba.tyagisumit@xxxxxxxxx
Cc: exriscer@xxxxxxxxx; JDunn@xxxxxxxxx; oracle-l@xxxxxxxxxxxxx
Subject: Re: What sql is using undo tablespace

That shows who generated the undo, which is often useful; what it doesn't show 
is who's referencing the undo to generate read consistent blocks for other 
statements, and I'm not sure that information's tracked anywhere that's 
queryable.


On Tue, May 13, 2014 at 3:46 AM, sumit Tyagi 
<dba.tyagisumit@xxxxxxxxx<mailto:dba.tyagisumit@xxxxxxxxx>> wrote:
undo is just generated by "a query", we do not track undo at a query level
undo is generated by transactions

v$transaction has a column used_ublk that tells you how much undo a given 
transaction has
generated....

to figure out how much undo (blocks or MB) a user session is using as of a 
"point in time" sure you can find :

as soon as they commit, v$transaction empties for them.

so to find information use v$sesstat joined to v$statname, look for name like 
'%undo%', you'll find useful information there - it is cumulative for a session.

select s.sid,
       s.username,
       sum(ss.value) / 1024 / 1024 as undo_size_mb
from  v$sesstat ss
  join v$session s on s.sid = ss.sid
  join v$statname stat on stat.statistic# = ss.statistic#
where stat.name<http://stat.name> = 'undo change vector size'
and s.type <> 'BACKGROUND'
and s.username IS NOT NULL
group by s.sid, s.username;



--
Adam Musch
ahmusch@xxxxxxxxx<mailto:ahmusch@xxxxxxxxx>

Other related posts: