Using Static Data Dictionary Views


All that we do on the database is recorded inside the static data dictionary tables. Data dictionary tables are not directly accessible, and we query them through data dictionary views. It takes time to know the details of each view but in the end it gives you the freedom to keep under the control the following:

  • schema objects
  • schema objects VALID status
  • the amount of the consumed resources by the schema objects
  • the dependencies between schema objects
  • the granted privileges on schema objects

Many data dictionary tables have three corresponding views:

  • ALL_ view
  • DBA_ view
  • USER_ view

An ALL_ view displays all the information accessible to the current user, which includes information from the current user’s schema, information from objects in other schemas, if the access to those objects is granted through privileges or roles to the current user.

A DBA_ view displays all information in the entire database. DBA_ views are accessible only by administrators.
They can be accessed by less privileged users if they are granted the SELECT ANY TABLE privilege.
This privilege is assigned to the DBA role when the system is initially installed.

A USER_ view displays all the information from the schema of the current user. No special privileges are required to query these views.

The columns of the ALL_, DBA_, and USER_ views corresponding to a single data dictionary table are nearly identical.

Each user should query the view DICTIONARY to know what views are available to him.

In my current Oracle Database 11g2, the DBA can access 2551 views:

sys@XE> select count(*) from dictionary;

  COUNT(*)
----------
      2551

If I create a new schema ANA

sys@XE> create user ana identified by swdev
  2  default tablespace USERS
  3  temporary tablespace TEMP;

User created.

sys@XE> alter user ana identified by swdev account unlock;

User altered.

sys@XE> grant connect, resource to ana;

Grant succeeded.

and if I connect to the database as the user ANA/SWDEV, I can access 804 views.

ana@XE> select count(*) from dictionary;

  COUNT(*)
----------
       804

ana@XE> desc dictionary
 Name              Null?    Type
 ----------------- -------- ----------------
 TABLE_NAME                 VARCHAR2(30)
 COMMENTS                   VARCHAR2(4000)

Only 689 views have a comment.

ana@XE> select count(comments) from dictionary;

COUNT(COMMENTS)
---------------
            689

How many of ALL_ , DBA_, and USER_ views can I access?

ana@XE> select count(*) from dictionary where table_name like 'ALL%';

  COUNT(*)
----------
       339

ana@XE> select count(*) from dictionary where table_name like 'DBA%';

  COUNT(*)
----------
         0

ana@XE> select count(*) from dictionary where table_name like 'USER%';

  COUNT(*)
----------
       361

I can not access DBA_ views, but I can access 339 ALL_ views and 361 USER_ views.

What USER_TAB_ views can I access?


ana@XE> select * 
from dictionary 
where table_name like 'USER_TAB%' 
and comments is not null
and rownum  < 6
order by 1;

TABLE_NAME
------------------------------
COMMENTS
------------------------------
USER_TABLES
Description of the user's own relational tables

USER_TABLESPACES
Description of accessible tablespaces

USER_TAB_COLS
Columns of user's tables, views and clusters

USER_TAB_COLUMNS
Columns of user's tables, views and clusters

USER_TAB_COL_STATISTICS
Columns of user's tables, views and clusters



The list of USER_ views that I usually query during the day is presented in the table of the post published on July, 21 2015.
If you want to know more about static dictionary views, the Oracle Database Reference Guide is listed under the reference [ref13].

WHY and HOW do I use static data dictionary views?

I want to know what schema objects are already in my schema.

ana@XE> select object_name
  2      , object_type
  3      , created
  4      , status
  5      , temporary
  6      , namespace
  7      from user_objects;

no rows selected

As I have been a new user to the database, there is no schema objects in my schema ANA.

I can copy create statements from the existing schema and add some objects to my schema.

ana@XE> select object_type, count(*) total
  2  from user_objects
  3  group by object_type
  4  order by 1;

OBJECT_TYPE              TOTAL
-------------------      ----------
FUNCTION                     1
LOB                          2
SEQUENCE                     1
TABLE                        1
TRIGGER                      1

I created 1 function, 2 LOB objects, 1 sequence, 1 table, and 1 trigger.

What are their names?


ana@XE> select object_name
  2      , object_type
  3      , created
  4      , status
  5      , temporary
  6      , namespace
  7      from user_objects;

OBJECT_NAME
--------------------------------------------------------
OBJECT_TYPE              CREATED   STATUS    T  NAMESPACE
-------------------      -----     ------    -  ----------
FUNCT_GET_DDL
FUNCTION                 23-JUL-15   VALID   N          1

TWEETS
TABLE                    23-JUL-15   VALID   N          1

SYS_LOB0000020438C00003$$
LOB                      23-JUL-15   VALID   N          8

SYS_LOB0000020438C00002$$
LOB                      23-JUL-15   VALID   N          8

TWEETS_SEQ
SEQUENCE                 23-JUL-15   VALID   N          1

TWEETS_TR_INSERT
TRIGGER                  23-JUL-15   VALID   N          3


6 rows selected.

From here, I can easily query USER_ views and learn more about existing schema objects.

ana@XE> select * from user_tables;

TABLE_NAME                     TABLESPACE_NAME                CLUSTER_NAME
------------------------------ ------------------------------ ------------------------------
IOT_NAME                       STATUS     PCT_FREE   PCT_USED  INI_TRANS  MAX_TRANS INITIAL_EXTENT
------------------------------ -------- ---------- ---------- ---------- ---------- --------------
NEXT_EXTENT MIN_EXTENTS MAX_EXTENTS PCT_INCREASE  FREELISTS FREELIST_GROUPS LOG B   NUM_ROWS
----------- ----------- ----------- ------------ ---------- --------------- --- - ----------
    BLOCKS EMPTY_BLOCKS  AVG_SPACE  CHAIN_CNT AVG_ROW_LEN AVG_SPACE_FREELIST_BLOCKS
---------- ------------ ---------- ---------- ----------- -------------------------
NUM_FREELIST_BLOCKS DEGREE
------------------- ----------------------------------------
INSTANCES                                CACHE                TABLE_LO SAMPLE_SIZE LAST_ANAL PAR
---------------------------------------- -------------------- -------- ----------- --------- ---
IOT_TYPE     T S NES BUFFER_ FLASH_C CELL_FL ROW_MOVE GLO USE DURATION        SKIP_COR MON
------------ - - --- ------- ------- ------- -------- --- --- --------------- -------- ---
CLUSTER_OWNER                  DEPENDEN COMPRESS COMPRESS_FOR DRO REA SEG RESULT_
------------------------------ -------- -------- ------------ --- --- --- -------
TWEETS                         USERS
                               VALID            10                     1        255          65536
    1048576           1  2147483645                                         YES N

                             1
         1                                   N                ENABLED                        NO
             N N NO  DEFAULT DEFAULT DEFAULT DISABLED NO  NO                  DISABLED YES
                               DISABLED DISABLED              NO  NO  YES DEFAULT

The table Tweets is created in the tablespace USERS, it does not belong to any cluster, and it is VALID.


ana@XE> select table_name, comments from user_tab_comments;

TABLE_NAME                    
COMMENTS
------------------------------------------------------
TWEETS                         
Tweets table contains tweets and their attached photos

ana@XE> select * from user_col_comments;

TABLE_NAME                     COLUMN_NAME
------------------------------ -----------------
COMMENTS
------------------------------------------------
TWEETS                         ID
The ID is the identification number of the tweet.

TWEETS                         TEXT
The content of the tweet.

TWEETS                         PHOTO
The photo attached to the tweet.

Tweets table has 3 columns, ID, TEXT, and PHOTO.


ana@XE> select table_name, column_name, substr(data_type, 1, 8) data_type from user_tab_cols;

TABLE_NAME        COLUMN_NAME     DATA_TYPE
----------        -----------     -------------
TWEETS            ID              NUMBER
TWEETS            TEXT            CLOB
TWEETS            PHOTO           BLOB


Tweets table columns are of CLOB and BLOB data types.


ana@XE> select * from user_sequences;

SEQUENCE_NAME MIN  MAX        INC C O CACHE_SIZE LAST_NUMBER
------------  ---- ---------- --- - - ---------- ----------- 
TWEETS_SEQ    1    1.0000E+28   1 N N          0          1

ana@XE> select * from user_triggers;

TRIGGER_NAME                   TRIGGER_TYPE
------------------------------ ----------------
TRIGGERING_EVENT
----------------------------------------------------------------------------------------------------
TABLE_OWNER                    BASE_OBJECT_TYPE TABLE_NAME
------------------------------ ---------------- ------------------------------
COLUMN_NAME
----------------------------------------------------------------------------------------------------
REFERENCING_NAMES
----------------------------------------------------------------------------------------------------
WHEN_CLAUSE
----------------------------------------------------------------------------------------------------
STATUS
--------
DESCRIPTION
----------------------------------------------------------------------------------------------------
ACTION_TYPE TRIGGER_BODY                                                                     CROSSED
----------- -------------------------------------------------------------------------------- -------
BEF BEF AFT AFT INS FIR APP
--- --- --- --- --- --- ---
TWEETS_TR_INSERT               BEFORE EACH ROW
INSERT
ANA                            TABLE            TWEETS

REFERENCING NEW AS NEW OLD AS OLD

ENABLED
"ANA"."TWEETS_TR_INSERT"
BEFORE INSERT ON tweets
FOR EACH ROW
PL/SQL      BEGIN                                                                            NO
            SELECT tweets_seq.nextval INTO :new.ID FROM DUAL;
            END;
NO  NO  NO  NO  NO  YES NO

The trigger TWEETS_TR_INSERT will fire on insert on the table TWEETS for each row, it is valid, and its body is listed in the column TRIGGER_BODY.


ana@XE> select * from user_procedures;

OBJECT_NAME
----------------------------------------------------------------------------------------------------
PROCEDURE_NAME                  OBJECT_ID SUBPROGRAM_ID OVERLOAD
------------------------------ ---------- ------------- ----------------------------------------
OBJECT_TYPE         AGG PIP IMPLTYPEOWNER                  IMPLTYPENAME                   PAR INT
------------------- --- --- ------------------------------ ------------------------------ --- ---
DET AUTHID
--- ------------
FUNCT_GET_DDL
                                    20434             1
FUNCTION            NO  NO                                                                NO  NO
NO  CURRENT_USER

TWEETS_TR_INSERT
                                    20444             1
TRIGGER             NO  NO                                                                NO  NO
NO  DEFINER

My schema contains two PL/SQL subprograms, one function FUNCT_GET_DDL, and one trigger TWEETS_TR_INSERT.

Below, the source code of both PL/SQL subprograms is listed.

ana@XE> select text from all_source where owner = 'ANA';

TEXT
----------------------------------------------------------------------------------------------------
FUNCTION       "FUNCT_GET_DDL"
  (  p_in_type VARCHAR2
   , p_in_schema VARCHAR2
   , p_in_name VARCHAR2 )
RETURN CLOB
AUTHID CURRENT_USER
IS

-- Define local variables.

  l_h NUMBER; --handle returned by OPEN
  l_th NUMBER; -- handle returned by ADD_TRANSFORM
  l_doc CLOB; --returned sql ddl statement

BEGIN

-- Specify the object type.

  l_h := DBMS_METADATA.OPEN(p_in_type);

-- Use filters to specify the particular object desired.

  DBMS_METADATA.SET_FILTER(l_h,'SCHEMA',p_in_schema);
  DBMS_METADATA.SET_FILTER(l_h,'NAME',p_in_name);

-- Request that the metadata be transformed into creation DDL.

  l_th := DBMS_METADATA.ADD_TRANSFORM(l_h,'DDL');

-- Fetch the object.

  l_doc := DBMS_METADATA.FETCH_CLOB(l_h);

-- Release resources.

  DBMS_METADATA.CLOSE(l_h);

-- Return the result

  RETURN l_doc;

EXCEPTION
WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE(SQLERRM);
END;


TRIGGER "ANA"."TWEETS_TR_INSERT"
BEFORE INSERT ON tweets
FOR EACH ROW
BEGIN
SELECT tweets_seq.nextval INTO :new.ID FROM DUAL;
END;

51 rows selected.

There are other useful USER_ views about table columns. From the USER_UPDATABLE_COLUMNS we can see what columns we can UPDATE.


ana@XE> select * from user_updatable_columns;

OWNER     TABLE_NAME      COLUMN_NAME    UPD INS  DEL
--------- -----------     -----------    --- ---  ---
ANA       TWEETS          ID             YES YES  YES
ANA       TWEETS          TEXT           YES YES  YES
ANA       TWEETS          PHOTO          YES YES  YES

The view USER_TRIGGER_COLS tells us that the trigger TWEETS_TR_INSERT inserts new value to the column TWEETS.ID.

ana@XE> select * from user_trigger_cols;

TRIGGER_OWNER                  TRIGGER_NAME                   TABLE_OWNER
------------------------------ ------------------------------ ------------------------------
TABLE_NAME
------------------------------
COLUMN_NAME
----------------------------------------------------------------------------------------------------
COL COLUMN_USAGE
--- -----------------
ANA                            TWEETS_TR_INSERT               ANA
TWEETS
ID
NO  NEW OUT

If we wanted to know what resources our table consumes, there are two useful views, USER_TABLESPACES and USER_SEGMENTS.

ana@XE> select * from user_tablespaces;

TABLESPACE_NAME                BLOCK_SIZE INITIAL_EXTENT NEXT_EXTENT MIN_EXTENTS MAX_EXTENTS
------------------------------ ---------- -------------- ----------- ----------- -----------
  MAX_SIZE PCT_INCREASE MIN_EXTLEN STATUS    CONTENTS  LOGGING   FOR EXTENT_MAN ALLOCATIO SEGMEN
---------- ------------ ---------- --------- --------- --------- --- ---------- --------- ------
DEF_TAB_ RETENTION   BIG PREDICA ENC COMPRESS_FOR
-------- ----------- --- ------- --- ------------
SYSTEM                               8192          65536                       1  2147483645
2147483645                   65536 ONLINE    PERMANENT LOGGING   NO  LOCAL      SYSTEM    MANUAL
DISABLED NOT APPLY   NO  HOST    NO

SYSAUX                               8192          65536                       1  2147483645
2147483645                   65536 ONLINE    PERMANENT LOGGING   NO  LOCAL      SYSTEM    AUTO
DISABLED NOT APPLY   NO  HOST    NO

UNDOTBS1                             8192          65536                       1  2147483645
2147483645                   65536 ONLINE    UNDO      LOGGING   NO  LOCAL      SYSTEM    MANUAL
DISABLED NOGUARANTEE NO  HOST    NO

TEMP                                 8192        1048576     1048576           1
2147483645            0    1048576 ONLINE    TEMPORARY NOLOGGING NO  LOCAL      UNIFORM   MANUAL
DISABLED NOT APPLY   NO  HOST    NO

USERS                                8192          65536                       1  2147483645
2147483645                   65536 ONLINE    PERMANENT LOGGING   NO  LOCAL      SYSTEM    AUTO
DISABLED NOT APPLY   NO  HOST    NO


ana@XE> select * from user_segments;

SEGMENT_NAME
---------------------------------------------------------------------------------
PARTITION_NAME                 SEGMENT_TYPE       SEGMENT_SU TABLESPACE_NAME
------------------------------ ------------------ ---------- ------------------------------
     BYTES     BLOCKS    EXTENTS INITIAL_EXTENT NEXT_EXTENT MIN_EXTENTS MAX_EXTENTS   MAX_SIZE
---------- ---------- ---------- -------------- ----------- ----------- ----------- ----------
RETENTI MINRETENTION PCT_INCREASE  FREELISTS FREELIST_GROUPS BUFFER_ FLASH_C CELL_FL
------- ------------ ------------ ---------- --------------- ------- ------- -------
TWEETS
                               TABLE              ASSM       USERS
     65536          8          1          65536     1048576           1  2147483645 2147483645
                                                             DEFAULT DEFAULT DEFAULT

SYS_IL0000020438C00002$$
                               LOBINDEX           ASSM       USERS
     65536          8          1          65536     1048576           1  2147483645 2147483645
                                                             DEFAULT DEFAULT DEFAULT

SYS_IL0000020438C00003$$
                               LOBINDEX           ASSM       USERS
     65536          8          1          65536     1048576           1  2147483645 2147483645
                                                             DEFAULT DEFAULT DEFAULT

SYS_LOB0000020438C00002$$
                               LOBSEGMENT         ASSM       USERS
     65536          8          1          65536     1048576           1  2147483645 2147483645
                                                             DEFAULT DEFAULT DEFAULT

SYS_LOB0000020438C00003$$
                               LOBSEGMENT         ASSM       USERS
     65536          8          1          65536     1048576           1  2147483645 2147483645
                                                             DEFAULT DEFAULT DEFAULT

From the view USER_SEGMENTS, we can see that our table TWEETS is inside the segment TWEETS, and the segment belongs to the tablespace USERS.
The SQL statement CREATE TABLE TWEETS created two LOBSEGMENT segments, one for the column TEXT, and the other for the column PHOTO, and also it created two LOBINDEX segments, one for the column TEXT, and the other for the column PHOTO.

If we need more information about each column of the table TWEETS, we will query the view USER_TAB_COLS or USER_TAB_COLUMNS.


ana@XE> select * from user_tab_columns where COLUMN_NAME = 'TEXT';

TABLE_NAME                     COLUMN_NAME
------------------------------ ------------------------------
DATA_TYPE
----------------------------------------------------------------------------------------------------
DAT
---
DATA_TYPE_OWNER
----------------------------------------------------------------------------------------------------
DATA_LENGTH DATA_PRECISION DATA_SCALE N  COLUMN_ID DEFAULT_LENGTH
----------- -------------- ---------- - ---------- --------------
DATA_DEFAULT                                                                     NUM_DISTINCT
-------------------------------------------------------------------------------- ------------
LOW_VALUE
----------------------------------------------------------------
HIGH_VALUE                                                          DENSITY  NUM_NULLS NUM_BUCKETS
---------------------------------------------------------------- ---------- ---------- -----------
LAST_ANAL SAMPLE_SIZE CHARACTER_SET_NAME                           CHAR_COL_DECL_LENGTH GLO USE
--------- ----------- -------------------------------------------- -------------------- --- ---
AVG_COL_LEN CHAR_LENGTH C V80 DAT HISTOGRAM
----------- ----------- - --- --- ---------------
TWEETS                         TEXT
CLOB
       4000                           Y          2
                      CHAR_CS                                                      4000 NO  NO
                      0   NO  YES NONE

ana@XE> select * from user_tab_columns where COLUMN_NAME = 'PHOTO';

TABLE_NAME                     COLUMN_NAME
------------------------------ ------------------------------
DATA_TYPE
----------------------------------------------------------------------------------------------------
DAT
---
DATA_TYPE_OWNER
----------------------------------------------------------------------------------------------------
DATA_LENGTH DATA_PRECISION DATA_SCALE N  COLUMN_ID DEFAULT_LENGTH
----------- -------------- ---------- - ---------- --------------
DATA_DEFAULT                                                                     NUM_DISTINCT
-------------------------------------------------------------------------------- ------------
LOW_VALUE
----------------------------------------------------------------
HIGH_VALUE                                                          DENSITY  NUM_NULLS NUM_BUCKETS
---------------------------------------------------------------- ---------- ---------- -----------
LAST_ANAL SAMPLE_SIZE CHARACTER_SET_NAME                           CHAR_COL_DECL_LENGTH GLO USE
--------- ----------- -------------------------------------------- -------------------- --- ---
AVG_COL_LEN CHAR_LENGTH C V80 DAT HISTOGRAM
----------- ----------- - --- --- ---------------
TWEETS                         PHOTO
BLOB
       4000                           Y          3
                                                                                        NO  NO
                      0   NO  YES NONE

The CREATE TABLE TWEETS statement also created indexes for both LOB columns.

ana@XE> select * from user_indexes;

INDEX_NAME                     INDEX_TYPE                  TABLE_OWNER
------------------------------ --------------------------- ------------------------------
TABLE_NAME                     TABLE_TYPE  UNIQUENES COMPRESS PREFIX_LENGTH
------------------------------ ----------- --------- -------- -------------
TABLESPACE_NAME                 INI_TRANS  MAX_TRANS INITIAL_EXTENT NEXT_EXTENT MIN_EXTENTS
------------------------------ ---------- ---------- -------------- ----------- -----------
MAX_EXTENTS PCT_INCREASE PCT_THRESHOLD INCLUDE_COLUMN  FREELISTS FREELIST_GROUPS   PCT_FREE LOG
----------- ------------ ------------- -------------- ---------- --------------- ---------- ---
    BLEVEL LEAF_BLOCKS DISTINCT_KEYS AVG_LEAF_BLOCKS_PER_KEY AVG_DATA_BLOCKS_PER_KEY
---------- ----------- ------------- ----------------------- -----------------------
CLUSTERING_FACTOR STATUS     NUM_ROWS SAMPLE_SIZE LAST_ANAL DEGREE
----------------- -------- ---------- ----------- --------- ----------------------------------------
INSTANCES                                PAR T G S BUFFER_ FLASH_C CELL_FL USE DURATION
---------------------------------------- --- - - - ------- ------- ------- --- ---------------
PCT_DIRECT_ACCESS ITYP_OWNER                     ITYP_NAME
----------------- ------------------------------ ------------------------------
PARAMETERS
----------------------------------------------------------------------------------------------------
GLO DOMIDX_STATU DOMIDX FUNCIDX_ JOI IOT DRO VISIBILIT DOMIDX_MANAGEM SEG
--- ------------ ------ -------- --- --- --- --------- -------------- ---
SYS_IL0000020438C00002$$       LOB                         ANA
TWEETS                         TABLE       UNIQUE    DISABLED
USERS                                   2        255          65536     1048576           1
 2147483645                                                                              10 YES

                  VALID                                     0
0                                        NO  N Y N DEFAULT DEFAULT DEFAULT NO


NO                               NO  NO  NO  VISIBLE                  YES

SYS_IL0000020438C00003$$       LOB                         ANA
TWEETS                         TABLE       UNIQUE    DISABLED
USERS                                   2        255          65536     1048576           1
 2147483645                                                                              10 YES

                  VALID                                     0
0                                        NO  N Y N DEFAULT DEFAULT DEFAULT NO


NO                               NO  NO  NO  VISIBLE                  YES


The view USER_LOBS shows all details about table TWEETS LOB columns TEXT and PHOTO.

ana@XE> select * from user_lobs;

TABLE_NAME
------------------------------
COLUMN_NAME
----------------------------------------------------------------------------------------------------
SEGMENT_NAME                   TABLESPACE_NAME                INDEX_NAME
------------------------------ ------------------------------ ------------------------------
     CHUNK PCTVERSION  RETENTION  FREEPOOLS CACHE      LOGGING ENCR COMPRE DEDUPLICATION   IN_
---------- ---------- ---------- ---------- ---------- ------- ---- ------ --------------- ---
FORMAT          PAR SEC SEG RETENTI RETENTION_VALUE
--------------- --- --- --- ------- ---------------
TWEETS
TEXT
SYS_LOB0000020438C00002$$      USERS                          SYS_IL0000020438C00002$$
      8192                   900            NO         YES     NONE NONE   NONE            YES
ENDIAN NEUTRAL  NO  NO  YES YES

TWEETS
PHOTO
SYS_LOB0000020438C00003$$      USERS                          SYS_IL0000020438C00003$$
      8192                   900            NO         YES     NONE NONE   NONE            YES
NOT APPLICABLE  NO  NO  YES YES

If we query USER_LOBS for the specific information about LOBs, such as

  • if it is a BASICFILE or SECUREFILE
  • whether or not the LOB is encrypted
    • for SecureFiles: YES or NO
    • for BasicFiles: NONE – Not applicable
  • the level of compression used for the LOB
    • for SecureFiles: LOW, MEDIUM, HIGH, NO
    • for BasicFiles: NONE – Not applicable
  • kind of deduplication used for this LOB
    • for SecureFiles: LOB – Deduplicate, NO – Keep duplicates
    • for BasicFiles: NONE – Not applicable

we will do it with the following statement:


ana@XE> select table_name
  2  , column_name
  3  , segment_name
  4  , tablespace_name
  5  , index_name
  6  , cache
  7  , logging
  8 , securefile
  9  , compression
 10  , deduplication
 11  , encrypt
 12  from user_lobs;
TABLE_NAME
------------------------------
COLUMN_NAME
----------------------------------------------------------------------------------------------------
SEGMENT_NAME                   TABLESPACE_NAME                INDEX_NAME
------------------------------ ------------------------------ ------------------------------
CACHE      LOGGING SEC COMPRE DEDUPLICATION   ENCR
---------- ------- --- ------ --------------- ----
TWEETS
TEXT
SYS_LOB0000020438C00002$$      USERS                          SYS_IL0000020438C00002$$
NO         YES     NO  NONE   NONE            NONE

TWEETS
PHOTO
SYS_LOB0000020438C00003$$      USERS                          SYS_IL0000020438C00003$$
NO         YES     NO  NONE   NONE            NONE


Both LOBs, TEXT and PHOTO, are BASICFILEs, they are not compressed, deduplicated or encrypted.

And finally, we should know what schema objects are dependent on.

The function FUNCT_GET_DDL depends on the packages STANDARD, DBMS_METADATA, DBMS_OUTPUT, SYS_STUB_FOR_PURITY_ANALYSIS, and DBMS_LOB.

The trigger TWEETS_TR_INSERT depends on the package STANDARD, the tables DUAL and TWEETS, and the sequence TWEETS_SEQ.

ana@XE> select * from user_dependencies;

NAME                           TYPE               REFERENCED_OWNER
------------------------------ ------------------ ------------------------------
REFERENCED_NAME                                                  REFERENCED_TYPE
---------------------------------------------------------------- ------------------
REFERENCED_LINK_NAME
----------------------------------------------------------------------------------------------------
  SCHEMAID DEPE
---------- ----
FUNCT_GET_DDL                  FUNCTION           SYS
STANDARD                                                         PACKAGE
        49 HARD

FUNCT_GET_DDL                  FUNCTION           PUBLIC
DBMS_METADATA                                                    SYNONYM
        49 HARD

FUNCT_GET_DDL                  FUNCTION           PUBLIC
DBMS_OUTPUT                                                      SYNONYM
        49 HARD

FUNCT_GET_DDL                  FUNCTION           SYS
SYS_STUB_FOR_PURITY_ANALYSIS                                     PACKAGE
        49 HARD

FUNCT_GET_DDL                  FUNCTION           SYS
DBMS_LOB                                                         PACKAGE
        49 HARD

TWEETS_TR_INSERT               TRIGGER            SYS
STANDARD                                                         PACKAGE
        49 HARD

TWEETS_TR_INSERT               TRIGGER            PUBLIC
DUAL                                                             SYNONYM
        49 HARD

TWEETS_TR_INSERT               TRIGGER            ANA
TWEETS                                                           TABLE
        49 HARD

TWEETS_TR_INSERT               TRIGGER            ANA
TWEETS_SEQ                                                       SEQUENCE
        49 HARD

9 rows selected.

SUMMARY

The Oracle Database is a complex system that contains many information inside itself.

The static data dictionary views collect all actions on the schema objects and it is necessary to know them better as that knowledge increases a developer productivity in everyday work.

REFERENCE

[ref13]Oracle® Database Reference 11g Release 2 (11.2) E25513-04

I hope this will be useful for anyone who would like to learn more about Oracle Database.

Thank you for visiting my blog!

Have a nice day!

P.S. Keep climbing Mount Olympus ( I mean keep learning and make things happen ) !

Leave a Reply

Please log in using one of these methods to post your comment:

WordPress.com Logo

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

Facebook photo

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

Connecting to %s