RE: Interpreting USED_UREC from V$TRANSACTION

From: Herring Dave - dherri <Dave.Herring_at_acxiom.com>
Date: Fri, 6 Jul 2012 18:44:02 +0000
Message-ID: <BD475CE0B3EE894DA0CAB36CE2F7DEB4CE8096B6_at_CWYIGMBCRP02.Corp.Acxiom.net>



Michael, the MOS script assumes the status of the transaction is "DEAD" while in my case it's "NONE". I guess "DEAD" would be an orphaned trans/process that was killed. Here's what I'm using to monitor, to help explain what I'm looking at. I assume I stole this years ago from various folks and modified it here and there to get the display "just right" for me.

COLUMN sid FORMAT 99999
COLUMN command_or_action FORMAT A100 HEADING 'SQL Command or Action' WRAP COLUMN current_time FORMAT A19 HEADING 'Current Time' COLUMN rollback_mb FORMAT 99,999.99 HEADING 'Undo|MB Used' COLUMN rows_per_sec FORMAT 99,999,999.99 HEADING 'TXN Rows|Per Sec' COLUMN start_time FORMAT a19 HEADING 'TXN Start Time' COLUMN status FORMAT A8 HEADING 'Status' COLUMN used_urec FORMAT 9,999,999,999 HEADING 'Undo Rows|Written' COLUMN username FORMAT A20 HEADING 'Username'

SELECT s.sid

, TO_CHAR(TO_DATE(t.start_time, 'MM/DD/YY HH24:MI:SS'), 'DD-MON-YY HH24:MI:SS') start_time
, TO_CHAR(sysdate, 'DD-MON-YY HH24:MI:SS') current_time
, CASE WHEN (sysdate - TO_DATE(t.start_time, 'MM/DD/YY HH24:MI:SS')) = 0

          THEN t.used_urec
          ELSE t.used_urec / NVL(((sysdate - TO_DATE(t.start_time, 'MM/DD/YY HH24:MI:SS')) * 86400), 1)
       END  rows_per_sec

, SUBSTR(s.username, 1, 15) username
, program
, DECODE(BITAND(t.flag,128), 0, NULL, 'Rollback') status
, t.used_urec
, ROUND(r.rssize / 1024 / 1024, 2) rollback_mb
, DECODE(sq.sql_text, NULL, DECODE(aa.name, NULL, 'UNKNOWN', aa.name), sq.sql_text) command_or_action
FROM v$transaction t
, v$session s
, v$rollstat r
, v$sql sq
, audit_actions aa
WHERE (t.xidusn = r.usn)

   AND (t.addr = s.taddr (+))
   AND ( s.sql_hash_value = sq.hash_value (+)

        AND s.sql_address = sq.address (+))    AND (s.command = aa.action)
 ORDER BY t.start_time, s.sid;

DAVID HERRING
DBA
Acxiom Corporation

EML   dave.herring_at_acxiom.com
TEL    630.944.4762
MBL   630.430.5988 

1501 Opus Pl, Downers Grove, IL 60515, USA WWW.ACXIOM.COM -----Original Message-----
From: Michael Dinh [mailto:mdinh_at_XIFIN.Com] Sent: Friday, July 06, 2012 1:12 PM
To: 'grzegorzof_at_interia.pl'; Herring Dave - dherri Cc: Oracle-L (oracle-l_at_freelists.org) Subject: RE: Interpreting USED_UREC from V$TRANSACTION

Script to Monitor SMON Rollback Progress [ID 1352046.1]

I would be curious to see what the output looks like for 10min interval.          

Michael Dinh
Disparity Breaks Automation (DBA)

Confidence comes not from always being right but from not fearing to be wrong - Peter T Mcintyre Great minds discuss ideas; average minds discuss events; small minds discuss people - Eleanor Roosevelt When any rule or formula becomes a substitute for thought rather than an aid to thinking, it is dangerous and should be discarded -Thomas William Phelps  
-----Original Message-----
From: oracle-l-bounce_at_freelists.org [mailto:oracle-l-bounce_at_freelists.org] On Behalf Of GG Sent: Friday, July 06, 2012 11:02 AM
To: Dave.Herring_at_acxiom.com
Cc: Oracle-L (oracle-l_at_freelists.org) Subject: Re: Interpreting USED_UREC from V$TRANSACTION

W dniu 2012-07-06 19:20, Herring Dave - dherri pisze:

> Folks,
> I'm monitoring a VERY large rollback operation  and could use some help in understanding conflicting values for USED_UREC in V$TRANSACTION.
>
> This is for 11.2.0.3 on RHEL 5.6.  The transaction was  a DROP COLUMN against a 1.3 TB table which I believe ran out of undo after 50+ hrs.  The SQL was generated from a data modeling tool and even after warning about runtimes they wanted the command run exactly as generated.
>
> Now that the DROP COLUMN command has been rolling back for 5 days, I'm getting pretty confused on what V$TRANSACTION is telling me, specifically USED_UREC.  Periodically over the last few days I've been querying this view and the values decreased way below zero and are now back about 800 million.  In all cases each check a little later showed the values were decreasing so I knew it was still rolling back:
>

Hi,
try with this still great script :
http://www.ixora.com.au/scripts/sql/9.0/rolling_back.sql

but If You are still not in last loop this maybe missleading :( .

Regards
GregG

--
http://www.freelists.org/webpage/oracle-l


***************************************************************************
The information contained in this communication is confidential, is
intended only for the use of the recipient named above, and may be legally
privileged.

If the reader of this message is not the intended recipient, you are
hereby notified that any dissemination, distribution or copying of this
communication is strictly prohibited.

If you have received this communication in error, please resend this
communication to the sender and delete the original message or any copy
of it from your computer system.

Thank You.
****************************************************************************
--
http://www.freelists.org/webpage/oracle-l
Received on Fri Jul 06 2012 - 13:44:02 CDT

Original text of this message