Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 

Oracle table last modified tips

Oracle Database Tips by Burleson Consulting

July 8, 2015


Question:  I know about the last_ddl_time column  in dba_objects, but I am hoping to find some metadata dictionary column to give me the mask DML time for an Oracle table.  In sum, I want to find the last time that a table was updated, using a dictionary SQL script.

Answer: There is no equivalent column in dba_tables because of the high overhead in keeping such a column current.  Tables can have hundreds of modifications per minute and making a last_dml_time column is prohibitively expensive because it would introduce a bottleneck in the Oracle dictionary. 

Instead you can use the Oracle LogMiner utility to find the last date-time when a table was modified.  This uses the dba_tab_modifications view.

Also see these related notes on using flashback_time with export.

Tracking table changes with dbms_logmnr

You can see DML against a table by mining the redo logs, both online and offline, to find SQL or DDL statements. This can be accomplished using the dbms_logmnr package. But first one needs to install the package as follows:

 

SQL> connect sys/mgr as sysdba

SQL> @?\/rdbms/admin/dbmslm.sql

 

Package created.

 

Grant succeeded.

 

Synonym created.

 

Now, for this example, assume that the data root problem or cause occurred fairly recently, as though the phone just rang with a frantic request for help, and expect to find the culprit transaction or transactions still within the online redo logs. So query the data dictionary to find the names of those files.

 

SQL> SELECT distinct member LOGFILENAME FROM V$LOGFILE;

 

LOGFILENAME

-------------------------------------------------------

C:\ORACLE\ORADATA\ORDB1\REDO01.LOG

C:\ORACLE\ORADATA\ORDB1\REDO02.LOG

C:\ORACLE\ORADATA\ORDB1\REDO03.LOG

C:\ORACLE\ORADATA\ORDB1\REDO04.LOG

 

Since it is fine for now to work from just those online redo log files, inform the Oracle log miner utility by registering those redo log files as the ones of interest for mining as shown here:

 

SQL> execute DBMS_LOGMNR.ADD_LOGFILE ('C:\ORACLE\ORADATA\ORDB1\REDO01.LOG');

SQL> execute DBMS_LOGMNR.ADD_LOGFILE ('C:\ORACLE\ORADATA\ORDB1\REDO02.LOG');

SQL> execute DBMS_LOGMNR.ADD_LOGFILE ('C:\ORACLE\ORADATA\ORDB1\REDO03.LOG');

SQL> execute DBMS_LOGMNR.ADD_LOGFILE ('C:\ORACLE\ORADATA\ORDB1\REDO04.LOG');

 

Log miner will require access to a data dictionary lookup reference location so that it can map object IDs to object names. The easiest and recommended source for that information is the current online data dictionary for that database. The other two options involve extracting that lookup information either into the log files or a flat file. Here is the code for using the online data dictionary.

 

execute DBMS_LOGMNR.START_LOGMNR (options => dbms_logmnr.dict_from_online_catalog);

 

PL/SQL procedure successfully completed.

 

Starting a log miner session like this results in the population of a view named v$logmnr_contents. Note how the query and results look pretty much the same as the new Oracle 11g flashback transaction.

 

SQL> select xid, start_scn, operation, table_name, undo_sql from v$logmnr_contents where start_timestamp>=sysdate-1 and username='BERT' and table_owner='BERT';

XID               START_SCN OPERATION    TABLE_NAME

---------------- ---------- ------------ ------------

UNDO_SQL

--------------------------------------------------------------

0200030052030000     475697 DELETE       JUNK

insert into "BERT"."JUNK"("C1","C2") values ('5','6');

 

0200030052030000     475697 DELETE       JUNK

insert into "BERT"."JUNK"("C1","C2") values ('3','4');

 

0200030052030000     475697 INSERT       JUNK

delete from "BERT"."JUNK" where ROWID = 'AAAD94AAAAAAChOAAD';

 

0200030052030000     475697 INSERT       JUNK

delete from "BERT"."JUNK" where ROWID = 'AAAD94AAAAAAChOAAC';

 

0200030052030000     475697 INSERT       JUNK

delete from "BERT"."JUNK" where ROWID = 'AAAD94AAAAAAChOAAB';

 

0200030052030000     475697 INSERT       JUNK

delete from "BERT"."JUNK" where ROWID = 'AAAD94AAAAAAChOAAA';

 

All that is left is to end the log miner session and it is done.

 

SQL> execute DBMS_LOGMNR.END_LOGMNR();;

 

PL/SQL procedure successfully completed.


 
 
Get the Complete
Oracle SQL Tuning Information 

The landmark book "Advanced Oracle SQL Tuning  The Definitive Reference"  is filled with valuable information on Oracle SQL Tuning. This book includes scripts and tools to hypercharge Oracle 11g performance and you can buy it for 30% off directly from the publisher.

 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2016

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.


 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster