Oracle® Streams Replication Administrator's Guide 10g Release 1 (10.1) Part Number B10728-01 |
|
|
View PDF |
This chapter contains information about identifying and resolving common problems in a Streams replication environment.
This chapter contains these topics:
See Also:
Oracle Streams Concepts and Administration for more information about troubleshooting Streams environments |
An apply server is a component of an apply process. Apply servers apply DML and DDL changes to database objects at a destination database. An apply process may use one or more apply servers, and the parallelism
apply process parameter specifies the number of apply servers that may concurrently apply transactions. For example, if parallelism
is set to 5
, then an apply process uses a total of five apply servers.
An apply server encounters contention when the apply server must wait for a resource that is being used by another session. Contention may result from logical dependencies. For example, when an apply server tries to apply a change to a row that a user has locked, then the apply server must wait for the user. Contention also may result from physical dependencies. For example, interested transaction list (ITL) contention results when two transactions that are being applied, which may not be logically dependent, are trying to lock the same block on disk. In this case, one apply server locks rows in the block, and the other apply server must wait for access to the block, even though the second apply server is trying to lock different rows. See "Is the Apply Process Waiting for a Dependent Transaction?" for detailed information about ITL contention.
When an apply server encounters contention that does not involve another apply server in the same apply process, it waits until the contention clears. When an apply server encounters contention that involves another apply server in the same apply process, one of the two apply servers is rolled back. An apply process that is using multiple apply servers may be applying multiple transactions at the same time. The apply process tracks the state of the apply server that is applying the transaction with the lowest commit SCN. If there is a dependency between two transactions, then an apply process always applies the transaction with the lowest commit SCN first. The transaction with the higher commit SCN waits for the other transaction to commit. Therefore, if the apply server with the lowest commit SCN transaction is encountering contention, then the contention results from something other than a dependent transaction. In this case, you can monitor the apply server with the lowest commit SCN transaction to determine the cause of the contention.
The following four wait states are possible for an apply server:
log
file
sync
event, where redo information must be flushed because of a commit or rollback. In these cases, nothing is written to the log initially because such waits are common and are usually transient. If the apply server is waiting for the same event after a certain interval of time, then the apply server writes a message to the alert log and apply process trace file. For example, an apply server a001
may write a message similar to the following:
A001: warning -- apply server 1, sid 26 waiting for event: A001: [log file sync] ...
This output is written to the alert log at intervals until the problem is rectified.
a001
may write a message similar to the following:
A001: warning -- apply server 1, sid 10 waiting on user sid 36 for event: A001: [enq: TM - contention] name|mode=544d0003, object #=a078, table/partition=0
This output is written to the alert log at intervals until the problem is rectified.
For example, if apply server 1 of apply process a001
is blocked by apply server 2 of the same apply process (a001
), then the apply process writes the following messages to the log files:
A001: apply server 1 blocked on server 2 A001: [enq: TX - row lock contention] name|mode=54580006, usn<<16 | slot=1000e, sequence=1853 A001: apply server 2 rolled back
You can determine the total number of times an apply server was rolled back since the apply process last started by querying the TOTAL_ROLLBACKS
column in the V$STREAMS_APPLY_COORDINATOR
dynamic performance view.
See Also:
|
If you set the parallelism
parameter for an apply process to a value greater than 1
, and you set the commit_serialization
parameter of the apply process to full
, then the apply process may detect interested transaction list (ITL) contention if there is a transaction that is dependent on another transaction with a higher SCN. ITL contention occurs if the session that created the transaction waited for an ITL slot in a block. This happens when the session wants to lock a row in the block, but one or more other sessions have rows locked in the same block, and there is no free ITL slot in the block.
ITL contention also is possible if the session is waiting due to a shared bitmap index fragment. Bitmap indexes index key values and a range of rowids. Each entry in a bitmap index can cover many rows in the actual table. If two sessions want to update rows covered by the same bitmap index fragment, then the second session waits for the first transaction to either COMMIT
or ROLLBACK
.
When an apply process detects such a dependency, it resolves the ITL contention automatically and records information about it in the alert log and apply process trace file for the database. ITL contention may negatively affect the performance of an apply process because there may not be any progress while it is detecting the deadlock.
To avoid the problem in the future, perform one of the following actions:
INITRANS
setting for the table using the ALTER
TABLE
statement.commit_serialization
parameter to none
for the apply process.parallelism
apply process parameter to 1
for the apply process.
See Also:
|
If an apply process is not performing well, then the reason may be that one or more apply servers used by the apply process are taking an inordinate amount of time to apply certain transactions. The following query displays information about the transactions being applied by each apply server used by an apply process named strm01_apply
:
COLUMN SERVER_ID HEADING 'Apply Server ID' FORMAT 99999999 COLUMN STATE HEADING 'Apply Server State' FORMAT A20 COLUMN APPLIED_MESSAGE_NUMBER HEADING 'Applied Message|Number' FORMAT 99999999 COLUMN MESSAGE_SEQUENCE HEADING 'Message Sequence|Number' FORMAT 99999999 SELECT SERVER_ID, STATE, APPLIED_MESSAGE_NUMBER, MESSAGE_SEQUENCE FROM V$STREAMS_APPLY_SERVER WHERE APPLY_NAME = 'STRM01_APPLY' ORDER BY SERVER_ID;
If you run this query repeatedly, then over time the apply server state, applied message number, and message sequence number should continue to change for each apply server as it applies transactions. If these values do not change for one or more apply servers, then the apply server may not be performing well. In this case, you should make sure that, for each table to which the apply process applies changes, every key column has an index.
If you have many such tables, then you may need to determine the specific table and DML or DDL operation that is causing an apply server to perform poorly. To do so, run the following query when an apply server is taking an inordinately long time to apply a transaction. In this example, assume that the name of the apply process is strm01_apply
and that apply server number two is performing poorly:
COLUMN OPERATION HEADING 'Operation' FORMAT A20 COLUMN OPTIONS HEADING 'Options' FORMAT A20 COLUMN OBJECT_OWNER HEADING 'Object|Owner' FORMAT A10 COLUMN OBJECT_NAME HEADING 'Object|Name' FORMAT A10 COLUMN COST HEADING 'Cost' FORMAT 99999999 SELECT p.OPERATION, p.OPTIONS, p.OBJECT_OWNER, p.OBJECT_NAME, p.COST FROM V$SQL_PLAN p, V$SESSION s, V$STREAMS_APPLY_SERVER a WHERE a.APPLY_NAME = 'STRM01_APPLY' AND a.SERVER_ID = 2 AND s.SID = a.SID AND p.HASH_VALUE = s.SQL_HASH_VALUE;
This query returns the operation being performed currently by the specified apply server. The query also returns the owner and name of the table on which the operation is being performed and the cost of the operation. Make sure each key column in this table has an index. If the results show FULL
for the COST
column, then the operation is causing full table scans, and indexing the table's key columns may solve the problem.
In addition, you can run the following query to determine the specific DML or DDL SQL statement that is causing an apply server to perform poorly, assuming that the name of the apply process is strm01_apply
and that apply server number two is performing poorly:
SELECT t.SQL_TEXT FROM V$SESSION s, V$SQLTEXT t, V$STREAMS_APPLY_SERVER a WHERE a.APPLY_NAME = 'STRM01_APPLY' AND a.SERVER_ID = 2 AND s.SID = a.SID AND s.SQL_ADDRESS = t.ADDRESS AND s.SQL_HASH_VALUE = t.HASH_VALUE ORDER BY PIECE;
This query returns the SQL statement being run currently by the specified apply server. The statement includes the name of the table to which the transaction is being applied. Make sure each key column in this table has an index.
If the SQL statement returned by the previous query is less than one thousand characters long, then you may run the following simplified query instead:
SELECT t.SQL_TEXT FROM V$SESSION s, V$SQLAREA t, V$STREAMS_APPLY_SERVER a WHERE a.APPLY_NAME = 'STRM01_APPLY' AND a.SERVER_ID = 2 AND s.SID = a.SID AND s.SQL_ADDRESS = t.ADDRESS AND s.SQL_HASH_VALUE = t.HASH_VALUE;
See Also:
Oracle Database Performance Tuning Guide and Oracle Database Reference for more information about the |
When an apply process cannot apply an event, it moves the event and all of the other events in the same transaction into the error queue. You should check the for apply errors periodically to see if there are any transactions that could not be applied. You can check for apply errors by querying the DBA_APPLY_ERROR
data dictionary view.
See Also:
Oracle Streams Concepts and Administration for more information about checking for apply errors and about managing apply errors |
You may encounter the following types of apply process errors for LCR events:
The errors marked with an asterisk (*) in the previous list often result from a problem with an apply handler or a rule-based transformation.
This error occurs when the user designated as the apply user does not have the necessary privileges to perform SQL operations on the replicated objects. The apply user privileges must be granted by an explicit grant of each privilege. Granting these privileges through a role is not sufficient for the Streams apply user.
Specifically, the following privileges are required:
INSERT
, UPDATE
, DELETE
, and SELECT
privileges must be granted.ALTER
TABLE
privilege must be granted.CREATE
ANY
TABLE
, CREATE
ANY
INDEX
, CREATE
ANY
PROCEDURE
, ALTER
ANY
TABLE
, and ALTER
ANY
PROCEDURE
privileges must be granted.ALL
PRIVILEGES
must be granted to the apply user.To correct this error, complete the following steps:
SESSION_PRIVS
data dictionary view to determine which required privileges are not granted to the apply user.See Also:
|
Typically, an ORA-01403
error occurs when an apply process tries to update an existing row and the OLD_VALUES
in the row LCR do not match the current values at this destination database.
Typically, one of the following conditions causes these errors:
DBA_CONSTRAINTS
data dictionary view. If no primary key exists for the table, or if the target table has a different primary key than the source table, then specify substitute key columns using the SET_KEY_COLUMNS
procedure in the DBMS_APPLY_ADM
package. You also may encounter error ORA-23416
if a table being applied does not have a primary key. After you make these changes, you can reexecute the error transaction.DATE
columns in the shared table, then make sure your query shows the hours, minutes, and seconds. If there is a mismatch, then you can use a DML handler to modify an LCR so that it matches the table. After you set the DML handler, you can reexecute the error transaction. After successful reexecution, if the DML handler is no longer needed, then remove it.
Alternatively, you can update the current values in the row so that the row LCR can be applied successfully. If changes to the row are captured by a capture process at the destination database, then you probably do not want to replicate this manual change to destination databases. In this case, complete the following steps:
EXEC DBMS_STREAMS.SET_TAG(tag => HEXTORAW('17'));
In some environments, you may need to set the tag to a different value.
EXECUTE_ERROR
procedure in the DBMS_APPLY_ADM
package, and specify the transaction identifier for the transaction that caused the error. For example:
EXEC DBMS_APPLY_ADM.EXECUTE_ERROR(local_transaction_id => '5.4.312');
Or, execute all errors for the apply process by running the EXECUTE_ALL_ERRORS
procedure:
EXEC DBMS_APPLY_ADM.EXECUTE_ALL_ERRORS(apply_name => 'APPLY');
EXEC DBMS_STREAMS.SET_TAG(tag => NULL);
In some environments, you may need to set the tag to a value other than NULL
.
See Also:
|
This error occurs if an incorrect value is used for a Streams parameter or if a row LCR does not contain the correct old and new values. Row LCRs should contain the following old and new values, depending on the operation:
INSERT
operation should contain new values but no old values.UPDATE
operation may contain both new values and old values.DELETE
operation should contain old values but no new values.Verify that the correct parameter type (OLD
, or NEW
, or both) is specified for the row LCR operation (INSERT
, UPDATE
, or DELETE
). For example, if a DML handler or rule-based transformation changes an UPDATE
row LCR into an INSERT
row LCR, then the handler or transformation should remove the old values in the row LCR.
If an apply handler caused the error, then correct the apply handler and reexecute the error transaction. If a rule-based transformation caused the error, then you can create a DML handler that will run when you reexecute the error transaction. Configure this DML handler to correct the problem. After successful reexecution, if the DML handler is no longer needed, then remove it. You also should correct the rule-based transformation that caused the error to prevent future errors.
See Also:
|
This error is caused by an invalid column specified in the column list of a row LCR. Check the column names in the row LCR. This error results if an apply handler or rule-based transformation attempts one of the following actions:
If an apply handler caused the error, then correct the apply handler and reexecute the error transaction. If a rule-based transformation caused the error, then you can create a DML handler that will run when you reexecute the error transaction. Configure this DML handler to correct the problem. After successful reexecution, if the DML handler is no longer needed, then remove it. You also should correct the rule-based transformation that caused the error to prevent future errors.
See Also:
|
This error may occur when an apply handler or a rule-based transformation passes a NULL
value to an LCR member subprogram instead of a SYS.AnyData
value that contains a NULL
.
For example, the following call to the ADD_COLUMN
member procedure for row LCRs may result in this error:
new_lcr.ADD_COLUMN('OLD','LANGUAGE',NULL);
The following example shows the correct way to call the ADD_COLUMN
member procedure for row LCRs:
new_lcr.ADD_COLUMN('OLD','LANGUAGE',SYS.AnyData.ConvertVarchar2(NULL));
If an apply handler caused the error, then correct the apply handler and reexecute the error transaction. If a rule-based transformation caused the error, then you can create a DML handler that will run when you reexecute the error transaction. Configure this DML handler to correct the problem. After successful reexecution, if the DML handler is no longer needed, then remove it. You also should correct the rule-based transformation that caused the error to prevent future errors.
See Also:
|
Typically, this error occurs because the instantiation SCN is not set on an object for which an apply process is attempting to apply changes. You can query the DBA_APPLY_INSTANTIATED_OBJECTS
data dictionary view to list the objects that have an instantiation SCN.
You can set an instantiation SCN for one or more objects by exporting the objects at the source database, and then importing them at the destination database. You may use either Data Pump export/import or original export/import. If you do not want to use export/import, then you can run one or more of the following procedures in the DBMS_APPLY_ADM
package:
Some of the common reasons why an instantiation SCN is not set for an object at a destination database include the following:
DBMS_STREAMS_ADM
package or by running a procedure in the DBMS_CAPTURE_ADM
package. If the objects were not prepared for instantiation before the export, then the instantiation SCN information will not be available in the export file, and the instantiation SCNs will not be set.
In this case, prepare the database objects for instantiation at the source database by following the instructions in "Preparing Database Objects for Instantiation at a Source Database". Next, set the instantiation SCN for the database objects at the destination database.
y
for the STREAMS_INSTANTIATION
import parameter. If this parameter is not set to y
for the import, then the instantiation SCN will not be set.
In this case, repeat the original export/import operation, and set the STREAMS_INSTANTIATION
parameter to y
during import. Follow the instructions in "Instantiating Objects in a Streams Environment Using Transportable Tablespaces".
Alternatively, use Data Pump export/import. An instantiation SCN is set for each imported prepared object automatically when you use Data Pump import.
DBMS_APPLY_ADM
package. When the instantiation SCN is set explicitly by the database administrator, responsibility for the correctness of the data is assumed by the administrator.
In this case, set the instantiation SCN for the database objects explicitly by following the instructions in "Setting Instantiation SCNs Using the DBMS_APPLY_ADM Package". Alternatively, you may choose to perform a metadata-only export/import to set the instantiation SCNs by following the instructions in "Setting Instantiation SCNs at a Destination Database".
In this case, set the instantiation SCN for the appropriate schemas by running the SET_SCHEMA_INSTANTIATION_SCN
procedure, or set the instantiation SCN for the source database by running the SET_GLOBAL_INSTANTIATION_SCN
procedure. Both of these procedures are in the DBMS_APPLY_ADM
package. Follow the instructions in "Setting Instantiation SCNs Using the DBMS_APPLY_ADM Package".
After you correct the condition that caused the error, whether you should reexecute the error transaction or delete it depends on whether the changes included in the transaction were executed at the destination database when you corrected the error condition. Follow these guidelines when you decide whether you should reexecute the transaction in the error queue or delete it:
See Also:
|
Typically, this error occurs because of one of the following conditions:
DBA_CONSTRAINTS
data dictionary view. If no primary key exists for the table, or if the table has a multiple column primary key, then specify substitute key columns using the SET_KEY_COLUMNS
procedure in the DBMS_APPLY_ADM
package. You also may encounter error ORA-23416
if a table does not have a primary key. After you make these changes, you can reexecute the error transaction.
Typically, this error occurs because one or more columns at a table in the source database do not match the corresponding columns at the destination database. The LCRs from the source database may contain more columns than the table at the destination database, or there may be a type mismatch for one or more columns. If the columns differ at the databases, then you can use rule-based transformations to avoid errors.
If you use an apply handler or a rule-based transformation, then make sure any SYS.AnyData
conversion functions match the datatype in the LCR that is being converted. For example, if the column is specified as VARCHAR2
, then use SYS.AnyData.CONVERTVARCHAR2
function to convert the data from type ANY
to VARCHAR2
.
Also, make sure you use the correct character case in rule conditions and apply handlers. For example, if a column name has all uppercase characters in the data dictionary, then you should specify the column name with all uppercase characters in rule conditions and in apply handlers.
This error may also occur because supplemental logging is not specified where it is required for nonkey columns at the source database. In this case, LCRs from the source database may not contain needed values for these nonkey columns.
See Also:
|