Values populated in DBA_TAB_MODIFICATIONS

 Goal :

The goal is to explain why the view DBA_TAB_MODIFICATIONS  does sometimes have no values

even when the parameter STATISTICS_LEVEL  is set to TYPICAL and  the specific schema has been analyzed successful using the package DBMS_STATS.GATHER_SCHEMA_STATS.

In addition all the tables in that schema shows MONITORING=YES in the view dba_tables.


Fix:

The updates to the table *_tab_modifications are related to the volumne of updates for a table.

There is a need of approximatly 10% of datavolumn changes. Just only on single update of the row for example might not lead to fill the *_tab_modifications.


Example :

SQL>  create table test ( num  varchar2(32));

Table created.


Lets insert 100 rows to table test:


SQL>  begin

  2  for i in 1..100 loop

  3  insert into sys.test values (i);

  4  end loop;

  5  commit;

end;  6

  7  /

PL/SQL procedure successfully completed.


SQL> select count(*) from test;

  COUNT(*)

----------

       100


Gather stats for this table:


SQL> EXEC DBMS_STATS.GATHER_TABLE_STATS('SYS','TEST');

PL/SQL procedure successfully completed.


SQL>  SELECT OWNER,TABLE_NAME,STALE_STATS,NUM_ROWS,BLOCKS,EMPTY_BLOCKS FROM DBA_TAB_STATISTICS where OWNER ='SYS' AND TABLE_NAME='TEST';

OWNER                          TABLE_NAME                     STA   NUM_ROWS

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

    BLOCKS EMPTY_BLOCKS

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

SYS                            TEST                           NO         100

         1            0


SQL>  select * from dba_tab_modifications where TABLE_OWNER='SYS' AND TABLE_NAME='TEST';


no rows selected


Now lets manually flush the modifications from SGA:


Note: The procedure DBMS_STATS.FLUSH_DATABASE_MONITORING_INFO flushes in-memory monitoring information for all tables in the dictionary.

Corresponding entries in the *_TAB_MODIFICATIONS, *_TAB_STATISTICS and *_IND_STATISTICS

views are updated immediately, without waiting for the Oracle database to flush them periodically (per default every 3 hours). This procedure is useful when you need up-to-date information in those views.


SQL> exec dbms_stats.flush_database_monitoring_info;

PL/SQL procedure successfully completed.


SQL>  SELECT OWNER,TABLE_NAME,STALE_STATS,NUM_ROWS,BLOCKS,EMPTY_BLOCKS FROM DBA_TAB_STATISTICS where OWNER ='SYS' AND TABLE_NAME='TEST';

OWNER                          TABLE_NAME                     STA   NUM_ROWS

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

    BLOCKS EMPTY_BLOCKS

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

SYS                            TEST                           NO         100

         1            0


Now lets insert 1000 more values and check if it put entry in dba_tab_modifications:


SQL> begin

 for i in 1..1000 loop

  insert into sys.test values (i);

 end loop;

  commit;

 end;

  /

  2    3    4    5    6    7

PL/SQL procedure successfully completed.


SQL> select count(*) from test;

  COUNT(*)

----------

      1100


SQL>  SELECT OWNER,TABLE_NAME,STALE_STATS,NUM_ROWS,BLOCKS,EMPTY_BLOCKS FROM DBA_TAB_STATISTICS where OWNER ='SYS' AND TABLE_NAME='TEST';

OWNER                          TABLE_NAME                     STA   NUM_ROWS

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

    BLOCKS EMPTY_BLOCKS

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

SYS                            TEST                           NO         100

         1            0

no rows selected


SQL>  select * from dba_tab_modifications where TABLE_OWNER='SYS' AND TABLE_NAME='TEST';

no rows selected


SQL>  SELECT OWNER,TABLE_NAME,STALE_STATS,NUM_ROWS,BLOCKS,EMPTY_BLOCKS FROM DBA_TAB_STATISTICS where OWNER ='SYS' AND TABLE_NAME='TEST';

OWNER                          TABLE_NAME                     STA   NUM_ROWS

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

    BLOCKS EMPTY_BLOCKS

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

SYS                            TEST                           NO         100

         1            0


SQL> exec dbms_stats.flush_database_monitoring_info;

PL/SQL procedure successfully completed.


SQL> SELECT OWNER,TABLE_NAME,STALE_STATS,NUM_ROWS,BLOCKS,EMPTY_BLOCKS FROM DBA_TAB_STATISTICS where OWNER ='SYS' AND TABLE_NAME='TEST';

OWNER                          TABLE_NAME                     STA   NUM_ROWS

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

    BLOCKS EMPTY_BLOCKS

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

SYS                            TEST                           YES        100

         1            0


SQL>  select * from dba_tab_modifications where TABLE_OWNER='SYS' AND TABLE_NAME='TEST';

TABLE_OWNER                    TABLE_NAME

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

PARTITION_NAME                 SUBPARTITION_NAME                 INSERTS

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

   UPDATES    DELETES TIMESTAMP TRU DROP_SEGMENTS

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

SYS                            TEST

                                                                    1000

         0          0 19-JUN-12 NO              0


Comments

Popular posts from this blog

How to Solve - "WAIT FOR EMON PROCESS NTFNS"

Query Regression - "OR" Transformation Oracle 19c

ORA - 12537: TNS: connection closed