Using DBMS_METADATA/DBMS_REDFINITION to move all objects to another TS

From: Rich Jesse <rjoralist2_at_society.servebeer.com>
Date: Thu, 20 Jun 2013 11:26:00 -0500 (CDT)
Message-ID: <b16f14f565c7daed01095d46ba4d5979.squirrel_at_society.servebeer.com>



Howdy,

In 11.2.0.3, we're archiving a good portion of data from Production ERP DB to Production Archive DB. All tables are in one tablespace, all indexes in another, as designed by 3rd party ERP. In order to recover the 100s of GB of disk post-archive, my plan is to:

  1. Create new TS big enough to handle all tables and indexes.
  2. Use DBMS_METADATA to create new tables and indexes in new TS
  3. Use DBMS_REDEFINITION to online move data to new TS
  4. Drop/recreate old TS
  5. Use DBMS_METADATA to create new tables and indexes in original TSs
  6. Use DBMS_REDEFINITION to online move data to original TSs
  7. Drop new TS

The reason I need to use DBMS_METADATA is for the requirement to move the tables and indexes to a new TS. DBMS_REDEFINITION will not do that.

The problem I'm having is how to remap each index name to a new name in DBMS_METADATA. Basically, I'm trying to use this to grab the remapped DDL for each index on a given table:

v_idx_handle := DBMS_METADATA.OPEN('INDEX');

DBMS_METADATA.SET_FILTER(v_idx_handle, 'BASE_OBJECT_SCHEMA', v_schema);
DBMS_METADATA.SET_FILTER(v_idx_handle, 'BASE_OBJECT_NAME', v_source_table);
v_ddl_xform := DBMS_METADATA.ADD_TRANSFORM(v_idx_handle,'MODIFY');
DBMS_METADATA.SET_REMAP_PARAM(v_ddl_xform, 'REMAP_TABLESPACE', v_source_idx_ts, v_dest_ts);
--DBMS_METADATA.SET_REMAP_PARAM(v_ddl_xform, 'REMAP_NAME', ???, ???||'_NEW');
v_ddl_xform := DBMS_METADATA.ADD_TRANSFORM(v_idx_handle,'DDL'); LOOP
        v_ddl := DBMS_METADATA.FETCH_DDL(v_idx_handle); ...

But how does one remap the name in the transform (commented out) when it's not known until it's DDL is fetched? Or am I looking at some regexp in the post-FETCH_DDL?

Thanks!
Rich

--

http://www.freelists.org/webpage/oracle-l Received on Thu Jun 20 2013 - 18:26:00 CEST

Original text of this message