MacLochlainns Weblog

Michael McLaughlin's Technical Blog

Site Admin

Finding Direct Indexes

without comments

If you’re not using Toad DBA Suite, it’s sometimes hard to find solutions. Somebody wanted to know how to find indexes that aren’t indirect. Indirect indexes are those created for a primary key because a primary key column or set of columns are both not null and uniquely constrained. Likewise, you create a unique index when you can create a unique constraint. You can’t drop a unique index for a primary key without dropping the primary key or unique constraint that indirectly created it.

The following query returns indexes with one or more columns that are created by a CREATE INDEX statement on a target table. It excludes unique indexes created by a primary key constraint, and it returns the relative position of columns in an index:

COLUMN sequence_name   FORMAT A22 HEADING "Sequence Name"
COLUMN column_position FORMAT 999 HEADING "Column|Position"
COLUMN column_name     FORMAT A22 HEADING "Column|Name"
SELECT   uin.index_name
,        uic.column_position
,        uic.column_name
FROM     user_indexes uin INNER JOIN user_ind_columns uic
ON       uin.index_name = uic.index_name
AND      uin.table_name = uic.table_name
WHERE    uin.table_name = UPPER('&&table_name')
AND NOT  uin.index_name IN (SELECT constraint_name
                            FROM   user_constraints
                            WHERE  table_name = UPPER('&&table_name'))
ORDER BY uin.index_name
,        uic.column_position;

It can be rewritten into a function, which can then drop indexes based on a table name:

CREATE OR REPLACE FUNCTION drop_indexes_on
( pv_table_name  VARCHAR2 ) RETURN NUMBER IS 
 
  /* A return value. */
  lv_return  NUMBER := 0;
 
  /* A query to return only directly created indexes. */
  CURSOR find_indexes_on
  ( cv_table_name  VARCHAR2 ) IS
    SELECT   DISTINCT ui.index_name
    FROM     user_indexes ui INNER JOIN user_ind_columns uic
    ON       ui.index_name = uic.index_name
    AND      ui.table_name = uic.table_name
    WHERE    ui.table_name = UPPER(cv_table_name)
    AND NOT  ui.index_name IN (SELECT constraint_name
                               FROM   user_constraints
                               WHERE  table_name = UPPER(cv_table_name));
 
  /* Declare function autonomous. */
  PRAGMA AUTONOMOUS_TRANSACTION;
 
BEGIN
 
  /* Drop the indexes on a table. */
  FOR i IN find_indexes_on(pv_table_name) LOOP
    EXECUTE IMMEDIATE 'DROP INDEX '||i.index_name;
    lv_return := 1;
  END LOOP;
 
  RETURN lv_return;
END drop_indexes_on;
/

You can call the drop_on_indexes_on function like this:

SELECT   drop_indexes_on(UPPER('address_lab'))
FROM     dual;

Hope this helps those who need to work with dropping indexes.

Written by maclochlainn

November 23rd, 2014 at 8:42 pm