Find latest change in table having no date/time column

you can achieve this using 3 different methods:

    Using USER_/DBA_TAB_MODIFICATIONS dictionary view. — Whenever you perform any DML on a table/object, this view gets populated but not right after you finish (Commit) your change. To let oracle populate this table you will have to run “EXEC DBMS_STATS.FLUSH_DATABASE_MONITORING_INFO;”. Once this is run, you can check the view to see how many inserts/deletes/updates has been performed on the table. It will have timestamp also but the timestamp will refer to the latest change. Using timestamp and flashback query, you can find the changes as below:

SQL:SCOTT@tp11g>col empno for 9999
SQL:SCOTT@tp11g>col mgr like empno
SQL:SCOTT@tp11g>col sal like empno
SQL:SCOTT@tp11g>select * from emp;

EMPNO ENAME      JOB         MGR HIREDATE    SAL       COMM     DEPTNO
===== ========== ========= ===== ========= ===== ========== ==========
7369 SMITH      CLERK      7902 17-DEC-80   800                    20
1112 test       qa         7934 10-NOV-13  1000        100         10
7499 ALLEN      SALESMAN   7698 20-FEB-81  1600        300         30
7521 WARD       SALESMAN   7698 22-FEB-81  1250        500         30
7566 JONES      MANAGER    7839 02-APR-81  2975                    20
7654 MARTIN     SALESMAN   7698 28-SEP-81  1250       1400         30
7698 BLAKE      MANAGER    7839 01-MAY-81  2850                    30
7782 CLARK      MANAGER    7839 09-JUN-81  2450                    10
7788 SCOTT      ANALYST    7566 19-APR-87  3000                    20
7839 KING       PRESIDENT       17-NOV-81  5000                    10
7844 TURNER     SALESMAN   7698 08-SEP-81  1500          0         30
7876 ADAMS      CLERK      7788 23-MAY-87  1100                    20
7900 JAMES      CLERK      7698 03-DEC-81   950                    30
7902 FORD       ANALYST    7566 03-DEC-81  3000                    20
7934 MILLER     CLERK      7782 23-JAN-82  1300                    10

15 rows selected.

SQL:SCOTT@tp11g>delete from emp where empno=1212;

1 row deleted.

SQL:SCOTT@tp11g>commit;

Commit complete.

SQL:SCOTT@tp11g>select table_name,inserts,updates,deletes,timestamp from user_tab_modifications;

TABLE_NAME    INSERTS    UPDATES    DELETES TIMESTAMP
========== ========== ========== ========== =========
EMP                 2          0          0 11-SEP-13

SQL:SCOTT@tp11g>exec dbms_stats.flush_database_monitoring_info;

PL/SQL procedure successfully completed.

SQL:SCOTT@tp11g>select table_name,inserts,updates,deletes,timestamp from user_tab_modifications;

TABLE_NAME    INSERTS    UPDATES    DELETES TIMESTAMP
========== ========== ========== ========== =========
EMP                 2          0          1 11-SEP-13

SQL:SCOTT@tp11g>SELECT * FROM EMP AS OF timestamp systimestamp -interval '2' minute
2 minus
3 SELECT * FROM EMP;

EMPNO ENAME      JOB         MGR HIREDATE    SAL       COMM     DEPTNO
===== ========== ========= ===== ========= ===== ========== ==========

1212 Onkar     DBA      7839 11-SEP-13  5487                    10

SQL:SCOTT@tp11g>

NOTE: For inserts and updates, you need to swap the order of select statements means select after MINUS will be first and select before minus will become second query and you can find the changes. Obviously you have to look for the interval.

2. Second method is by using a pseudocolumn called ORA_ROWSCN but this is not full proof as this is SCN with respect to the block and not the row which means if you are changing a row in a block which has more than one row in it then you will get changed rownumber for the entire block and for specific records. More you can read here:

http://laurentschneider.com/…/08/select-last-rows.html

http://psoug.org/reference/pseudocols.html

3. Third method is using FLASHBACK query provided you have undo data available.

Since Oracle does not keep track of DML changes, you need to enable auditing on the table or use trigger to record any change in the data set but it should not be done for all the tables you have as it will increase overload on the system. Use this approach only for selected table and that too for selected period of time and not forever.

More on Flashback Technology in other post

About these ads

About Onkar Nath T

I am an Oracle & Teradata enthusiast and an AIOUG Board Member. My certifications include: Oracle 9i and 11g Certified Professional, Teradata V2R5 Certified Professional, Oracle 11g Implementation Specialist, GoldenGate 10 Implementation Specialist, Teradata V2R5 Implementation Specialist, VMware Certified Associate - Data Center Virtualization
This entry was posted in Oracle. Bookmark the permalink.

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s