Online Redefinition fails with ORA-23540: Redefinition not defined or initiated
Problem Description
While doing online redefinition on a table dbms_redefinition.copy_table_dependents fails with error ORA-23540 as below.
Cause of the problem
There may be different causes against it. If the schema specified in the dbms_redefinition.copy_table_dependents procedure does not exist already in the database then above error can appears. Suppose it may be the case that you specified schema name as lower case but by default username is created in uppercase.
There may be other reason is that the redefinition process is not yet started or initiated by dbms_redefinition.start_redef_table over the table. In fact dbms_redefinition.start_redef_table function create a materialized view on the table. If the materialized view is not yet created then ORA-23540 come.
Solution of the Problem
Let's see whether materialized view created on the underlying table.
SQL> select master,log_table from dba_mview_logs where log_owner='MUCI' and master='HISTORY';
no rows selected
Check for underlying table under the user.
SQL> desc muci.history;
ERROR:
ORA-04043: object muci.history does not exist
In fact user MUCI is not existed on the system and hence error comes.
The same error also appears if redefinition is not defined on the table. Suppose here schema MUCI_FINAL exist and also table HISTORY_DETAIL as well as interim table HISTORY_ but redefinition is not defined.
Check for tables by,
SQL> select table_name from dba_tables where owner='MUCI_FINAL' and table_name like 'HISTORY%';
TABLE_NAME
------------------------------
HISTORY_DETAIL_
HISTORY_DETAIL
HISTORY_
HISTORY
See materialized view log exists on HISTORY (ran dbms_redefinition.start_redef_table earlier) and hence dbms_redefinition.copy_table_dependents procedure can be run over HISTORY table.
While doing online redefinition on a table dbms_redefinition.copy_table_dependents fails with error ORA-23540 as below.
SQL> set serverout on
SQL> declare
2 error_count pls_integer := 0;
3 BEGIN
4 dbms_redefinition.copy_table_dependents('MUCI', 'HISTORY', 'HISTORY_',1, true, true, true, false,error_count);
5 dbms_output.put_line('errors := ' || to_char(error_count));
6 END;
7 /
declare
*
ERROR at line 1:
ORA-23540: Redefinition not defined or initiated
ORA-06512: at "SYS.DBMS_SYS_ERROR", line 79
ORA-06512: at "SYS.DBMS_REDEFINITION", line 1662
ORA-06512: at line 4
Cause of the problem
There may be different causes against it. If the schema specified in the dbms_redefinition.copy_table_dependents procedure does not exist already in the database then above error can appears. Suppose it may be the case that you specified schema name as lower case but by default username is created in uppercase.
There may be other reason is that the redefinition process is not yet started or initiated by dbms_redefinition.start_redef_table over the table. In fact dbms_redefinition.start_redef_table function create a materialized view on the table. If the materialized view is not yet created then ORA-23540 come.
Solution of the Problem
Let's see whether materialized view created on the underlying table.
SQL> select master,log_table from dba_mview_logs where log_owner='MUCI' and master='HISTORY';
no rows selected
Check for underlying table under the user.
SQL> desc muci.history;
ERROR:
ORA-04043: object muci.history does not exist
In fact user MUCI is not existed on the system and hence error comes.
The same error also appears if redefinition is not defined on the table. Suppose here schema MUCI_FINAL exist and also table HISTORY_DETAIL as well as interim table HISTORY_ but redefinition is not defined.
SQL> declare
2 error_count pls_integer := 0;
3 BEGIN
4 dbms_redefinition.copy_table_dependents('MUCI_FINAL', 'HISTORY_DETAIL', 'HISTORY_',1, true, true, true, false,error_count);
5 dbms_output.put_line('errors := ' || to_char(error_count));
6 END;
7 /
declare
*
ERROR at line 1:
ORA-23540: Redefinition not defined or initiated
ORA-06512: at "SYS.DBMS_SYS_ERROR", line 79
ORA-06512: at "SYS.DBMS_REDEFINITION", line 1662
ORA-06512: at line 4
Check for tables by,
SQL> select table_name from dba_tables where owner='MUCI_FINAL' and table_name like 'HISTORY%';
TABLE_NAME
------------------------------
HISTORY_DETAIL_
HISTORY_DETAIL
HISTORY_
HISTORY
See materialized view log exists on HISTORY (ran dbms_redefinition.start_redef_table earlier) and hence dbms_redefinition.copy_table_dependents procedure can be run over HISTORY table.
SQL> select master,log_table from dba_mview_logs where log_owner='MUCI_FINAL' and master='HISTORY';
MASTER LOG_TABLE
------------------------------ ------------------------------
HISTORY MLOG$_HISTORY
SQL> declare
2 error_count pls_integer := 0;
3 BEGIN
4 dbms_redefinition.copy_table_dependents('MUCI_FINAL', 'HISTORY', 'HISTORY_',1, true, true, true, false,error_count);
5 dbms_output.put_line('errors := ' || to_char(error_count));
6 END;
7 /
errors := 0
PL/SQL procedure successfully completed.
Comments
Post a Comment