Skip to Main Content
  • Questions
  • How do I know the running query is reading UNDO

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Ken.

Asked: June 11, 2020 - 10:55 pm UTC

Last updated: June 15, 2020 - 3:20 am UTC

Version: 11g

Viewed 1000+ times

You Asked

Hi Gurus,

our current production query runs unstable. Normally, it runs 10 minutes, but sometime, it runs over hours. sometimes it throw out "snapshot too old" error. when the error pop up, we know it was reading undo. the system is very old.There are over thousands processes run on daily basis. while troubleshooting the performance issue, I want to know if the slow query was reading UNDO. Is there any dynamic view available for these information?

and Connor said...

Check out the "undo records applied" series of statistics at session level. Here's an example of a query that needs to see the data before it was deleted.


SQL>
SQL> create table t as select * from dba_objects;

Table created.

SQL> create index ix on t ( object_id );

Index created.

SQL>
SQL> variable rc refcursor
SQL> exec open :rc for select /*+ index(t) */ * from t where object_id > 0;

PL/SQL procedure successfully completed.

SQL> delete from t;

82260 rows deleted.

SQL> commit;

Commit complete.

SQL> @mystat
Enter value for statname: undo records applied

NAME                                                              VALUE
------------------------------------------------------------ ----------
transaction tables consistent reads - undo records applied            0
data blocks consistent reads - undo records applied                   0
rollback changes - undo records applied                               0
IM populate undo records applied                                      0
IM repopulate undo records applied                                    0
IM scan CUs undo records applied                                      0

6 rows selected.

SQL> set feedback only
SQL> print rc

82256 rows selected.

SQL> set feedback on
SQL> @mystat
Enter value for statname: undo records applied

NAME                                                              VALUE
------------------------------------------------------------ ----------
transaction tables consistent reads - undo records applied            0
data blocks consistent reads - undo records applied               82256
rollback changes - undo records applied                               0
IM populate undo records applied                                      0
IM repopulate undo records applied                                    0
IM scan CUs undo records applied                                      0

6 rows selected.

SQL>
SQL>
SQL>


but in reality, you might need to only undo a single record in a query ... if that change is from 3 hours ago (because your query is running for 3 hours) then you can still have the same issue.

It is not how *much* undo you have find...but how old it it.

Rating

  (1 rating)

Is this answer out of date? If it is, please let us know via a Comment

Comments

A reader, June 13, 2020 - 2:04 pm UTC

thanks Connor for quick response.

I have question about UNDO reading, Assume I fired a query which need to read 100 blocks (1 .. 100). After reading 10 blocks (1st to 10th), there is DML updated 1st block, in this case, does my query check the 1st block again? if unread block, eg. 20th block was updated/inserted multiple time (let's say 3 times), does oracle only read latest block in UNDO, or oracle will read same block 3 times in UNDO?
Connor McDonald
June 15, 2020 - 3:20 am UTC

Lets say we need to read blocks 1 to 10. Each block has a system change number on it (think of it like a "last changed" timestamp).

I start my query at 9am and lets say each block takes 10mins to read :-)

So i need every block that I read to be in a state as it was at 9am.

at 9am, Read block 1, its last change is 8:46am => perfect, I can use it
at 910am, Read block 2, its last change 9:03am => dang it, I need to roll it back to 9am or before, then I can use it
at 920am, Read block 3, its last change 9:07am => dang it, I need to roll it back to 9am or before, then I can use it

etc etc

So I only need to read each block once, but each block might have a diferent of undo to rewind.

And of course, I'm using time as a metaphor but thats not exactly correct. Block 2 might be last change 9:03 but that might be the last of 10,000 changes between 9am and 903. Whereas block 3 might have 2 changes, the last one being at 907.

So in this case, block 2 will be way more expensive to unravel.

But we don't need to go back and revisit blocks (in this instance)

More to Explore

Administration

Need more information on Administration? Check out the Administrators guide for the Oracle Database