Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 

 
 

Oracle replication: ORA-23318: a DDL failure has occurred

Oracle Database Tips by Donald Burleson

Question:  I received the error "Oracle replication: ORA-23318: a DDL failure has occurred" during dbms_repcat.alter_master_repobject where I change a table definition to add a table column:

BEGIN
DBMS_REPCAT.ALTER_MASTER_REPOBJECT(
   sname => '"SCOTT"',
   oname => '"BONUS"',
   type => 'TABLE',
   ddl_text => 'alter table bonus add (one varchar(10))');
END;
/

Throws error as
BEGIN
*
ERROR at line 1:
ORA-23318: a ddl failure has occurred

How do I correct this ORA-23318 error?

Answer: In your case, you are adding a table column to a replicated table.  Most experienced Oracle DBA's will will manually alter the table and their associated snapshot on the local and remote databases, rather than use the  dbms_repcat.alter_master_repobject procedure.  Oracle recommends using the following procedure for altering replicated tables:

1 - Suspend the required master group of which the table exists:
 
   
exec dbms_repcat.suspend_master_activity('scott')
 
 2. add a new column to the table:
 
 exec dbms_repcat.alter_master_repobject(
   'scott',
   'dept',
   'table',
    - ddl_text=>'alter table scott.dept modify(added_column default ''n''
    - constraint dept_ad_nn not null)
 )';

 
 3. regenerate application support for the table:
 
 exec dbms_repcat.generate_replication_support(
   sname => 'scott', -
   oname =>'dept',
   type => 'table',
   min_communication => true);

 
 4. resume multi-master replication:
 
 exec dbms_repcat.resume_master_activity('scott',true);

I also recommend the book "Oracle Replication" for tips and working replication scripts. 

Diagnosing the ORA-23318 error

The Oracle documentation notes that the ORA-23318 is a generic error with many possible causes:

ORA-23318: a DDL failure has occurred

Cause: User-supplied or system-generated DDL did not execute successfully.

Action: Examine DDL, database state, repcatlog, and all_errors to determine why the failure occurred.

Bugs relating to ORA-23318

  • Bug 1280292 - Fixed in 8.1.7.1
     
  • Bug 1280292 - This bug was introduced in 8.1, which can affect the ALTER TABLE command when it is done via the ALTER_MASTER_REPOBJECT package. This has been resolved in 9i and there are patches for 8i versions.
     
  • Bug 1346937 - Relating to using alter_master_repobject.
     
  • Bug 1881708 -
     
  • Bug 2182554 - When upgrading OID 211 (8.1.7 RDBMS) to OID 902 (902 RDBMS). One of the upgrade tasks is to alter a table column from varchar2(2000) => varchar2(4000).

Oracle notes on the ORA-23318 error

Here are some possible causes for the ORA-23318 error:

  • Invalid Trigger replication - The most common cause of the ORA-23381 error is when replicating triggers, causing the ORA-23318 when the remote trigger does not have the same dependent objects (sequences, tables, packages) as the local trigger. MOSC recommends that replicated triggers use dbms_reputil.from_remote to avoid the re-replication of data.
     
  • Calling alter_master_repobject with default value - Using the alter_master_repobject package and a column is being added an ORA-23318 will be produced if a default value is included in the DDL for the added column. When the column is added with a default, all existing rows will have to have the value inserted, which is DML. Since the group is quiesced, DML is not allowed. If the column is added and then modified to use the default, no DML is required. . . Note 1064130.6 discusses this issue and offers a valid work around that
    utilizes replication views.
     
  • Using unsupported Data Types - Executing dbms_repcat.create_snapshot_repobject can fail with ORA-23318 error when the table has a column of type ORDSYS.Ordimage. Ordimage is an unsupported column type for Advanced Replication. See the Oracle Replication Guide, chapter 'Considerations for Replicated Tables'. Use a BLOB, CLOB or NCLOB as column type.
     
  • Refresh job fails - You can get an ORA-23318 when refreshing a snapshot (or materialized view) if the base table was altered (e.g. new column, changed constraint) without rebuilding the snapshot.

This is just a quick survey of the ORA-23318 error and you should always check MOSC for details.  Of course, the obvious work-around is to manually alter the tables and snapshots.
 
 
Get the Complete
Oracle SQL Tuning Information 

The landmark book "Advanced Oracle SQL Tuning  The Definitive Reference"  is filled with valuable information on Oracle SQL Tuning. This book includes scripts and tools to hypercharge Oracle 11g performance and you can buy it for 30% off directly from the publisher.

 


 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.