Find Unused Columns in Oracle Database


Sometimes during development of new systems, you may add new columns to tables and then you don't use it and forget dropping it.

So you want to know which these columns to drop.
Usually unused columns have NULL value, So I created a function to return array of column names in my schema have NULL value.

I created GET_NULL_COLUMNS function returns VARRAY of varchar2
It has only one parameter (IN_TABLE_NAME)
If I pass a value for IN_TABLE_NAME then it will return NULL columns in this table only, otherwise it will return NULL columns in entire schema.



 CREATE OR REPLACE FUNCTION GET_NULL_COLUMNS (  
   IN_TABLE_NAME VARCHAR2 DEFAULT NULL)  
   RETURN SYS.ODCIVARCHAR2LIST  
 IS  
   L_NULL_COLS   SYS.ODCIVARCHAR2LIST := SYS.ODCIVARCHAR2LIST ();  
   LN$ROW_COUNT  NUMBER;  
   LN$NULL_COUNT  NUMBER;  
   LN$INDEX    NUMBER := 1;  
   CURSOR LCUR$COLS (P_TABLE_NAME VARCHAR2)  
   IS  
    SELECT TABLE_NAME, COLUMN_NAME  
     FROM USER_TAB_COLS  
     WHERE DECODE (P_TABLE_NAME, TABLE_NAME, 1, NULL, 1, 0) = 1;  
 BEGIN  
   FOR LREC$COLS IN LCUR$COLS (IN_TABLE_NAME)  
   LOOP  
    EXECUTE IMMEDIATE 'SELECT COUNT(1) FROM ' || LREC$COLS.TABLE_NAME  
      INTO LN$ROW_COUNT;  
    EXECUTE IMMEDIATE  'SELECT COUNT(1) FROM '  
             || LREC$COLS.TABLE_NAME  
             || ' WHERE '  
             || LREC$COLS.COLUMN_NAME  
             || ' IS NULL'  
      INTO LN$NULL_COUNT;  
    IF LN$ROW_COUNT = LN$NULL_COUNT  
    THEN  
      L_NULL_COLS.EXTEND;  
      L_NULL_COLS (LN$INDEX) :=  
       LREC$COLS.TABLE_NAME || '.' || LREC$COLS.COLUMN_NAME;  
      LN$INDEX := LN$INDEX + 1;  
    END IF;  
   END LOOP;  
   RETURN L_NULL_COLS;  
 END;  

Let's now test this function in SCOTT schema
 SELECT COLUMN_VALUE FROM TABLE (GET_NULL_COLUMNS);  

The output of query is


Thanks

Popular posts from this blog

ADF : Get Current Logged User Name

OAF : Get Current Row in Table

ADF : Working with ViewCriteria