Oracle® Streams Concepts and Administration 10g Release 1 (10.1) Part Number B10727-01 |
|
|
View PDF |
This chapter provides instructions for preparing a database or a distributed database environment to use Streams and for configuring a Streams environment.
This chapter contains these topics:
To manage a Streams environment, either create a new user with the appropriate privileges or grant these privileges to an existing user. You should not use the SYS
or SYSTEM
user as a Streams administrator, and the Streams administrator should not use the SYSTEM
tablespace as its default tablespace.
Complete the following steps to configure a Streams administrator at each database in the environment that will use Streams:
CREATE TABLESPACE streams_tbs DATAFILE '/usr/oracle/dbs/streams_tbs.dbf' SIZE 25M REUSE AUTOEXTEND ON MAXSIZE UNLIMITED;
strmadmin
and specify that this user uses the streams_tbs
tablespace, run the following statement:
CREATE USER strmadmin IDENTIFIED BY strmadminpw DEFAULT TABLESPACE streams_tbs QUOTA UNLIMITED ON streams_tbs;
CONNECT
and RESOURCE
role so that this administrator can connect to the database and manage different types of database objects in the administrator's own schema. Also, grant the Streams administrator DBA
role.
GRANT CONNECT, RESOURCE, DBA TO strmadmin;
GRANT_ADMIN_PRIVILEGE
procedure in the DBMS_STREAMS_AUTH
package. You may choose to run this procedure on the Streams administrator created in Step3 if any of the following conditions are true:
DBMS_STREAMS_ADM
package.DBA_APPLY_ERROR
data dictionary view.A user must have explicit EXECUTE
privilege on a package to execute a subprogram in the package inside of a user-created subprogram, and a user must have explicit SELECT
privilege on a data dictionary view to query the view inside of a user-created subprogram. These privileges cannot be through a role. You may run the GRANT_ADMIN_PRIVILEGE
procedure to grant such privileges to the Streams administrator, or you may grant them directly.
Depending on the parameter settings for the GRANT_ADMIN_PRIVILEGE
procedure, it either grants the privileges needed to be a Streams administrator directly, or it generates a script that you can edit and then run to grant these privileges.
See Also:
PL/SQL Packages and Types Reference for more information about this procedure |
Use the GRANT_ADMIN_PRIVILEGE procedure to grant privileges directly:
BEGIN DBMS_STREAMS_AUTH.GRANT_ADMIN_PRIVILEGE( grantee => 'strmadmin', grant_privileges => true); END; /
Use the GRANT_ADMIN_PRIVILEGE procedure to generate a script:
CREATE
DIRECTORY
to create a directory object for the directory into which you want to generate the script. A directory object is similar to an alias for the directory. For example, to create a directory object called admin_dir
for the /usr/admin
directory on your computer system, run the following procedure:
CREATE DIRECTORY admin_dir AS '/usr/admin';
GRANT_ADMIN_PRIVILEGE
procedure to generate a script named grant_strms_privs.sql
and place this script in the /usr/admin
directory on your computer system:
BEGIN DBMS_STREAMS_AUTH.GRANT_ADMIN_PRIVILEGE( grantee => 'strmadmin', grant_privileges => false, file_name => 'grant_strms_privs.sql', directory_name => 'admin_dir'); END; /
Notice that the grant_privileges
parameter is set to false
so that the procedure does not grant the privileges directly. Also, notice that the directory object created in Step a is specified for the directory_name
parameter.
SET ECHO ON SPOOL grant_strms_privs.out @/usr/admin/grant_strms_privs.sql SPOOL OFF
SELECT_CATALOG_ROLE
if you want to grant the user privileges to query non-Streams data dictionary viewsSELECT
ANY
DICTIONARY
privilege if you plan to use the Streams tool in the Oracle Enterprise Manager ConsoleEXECUTE
privilege on any PL/SQL procedure owned by another user that is executed by a Streams apply process. These procedures may be used in apply handlers or error handlers. If an apply user is specified, then the apply user must have these privileges.EXECUTE
privilege on any PL/SQL function owned by another user that is specified in a rule-based transformation for a rule used by a Streams capture process, propagation, apply process, or messaging client. For a capture process, if a capture user is specified, then the capture user must have these privileges. For an apply process, if an apply user is specified, then the apply user must have these privileges.ENQUEUE
or DEQUEUE
privileges on the queue, or both. See "Enabling a User to Perform Operations on a Secure Queue" for instructions.EXECUTE
privilege on any object types that the Streams administrator may need to accessTable 8-1 lists initialization parameters that are important for the operation, reliability, and performance of a Streams environment. Set these parameters appropriately for your Streams environment. This table specifies whether each parameter is modifiable. A modifiable initialization parameter can be modified using the ALTER
SESSION
or ALTER
SYSTEM
statement while an instance is running.
See Also:
Oracle Database Reference for more information about these initialization parameters |
Parameter | Values | Description |
---|---|---|
Range: Modifiable?: No |
This parameter specifies the release with which the Oracle server must maintain compatibility. Oracle servers with different compatibility levels can interoperate. To use the new Streams features introduced in Oracle Database 10g, this parameter must be set to | |
Modifiable?: Yes |
Specifies whether a database link is required to have the same name as the database to which it connects. To use Streams to share information between databases, set this parameter to | |
Modifiable?: Yes |
Specifies the number of This parameter must be set to at least | |
Modifiable?: Yes |
Defines up to ten log archive destinations, where To use downstream capture and copy the redo log files to the downstream database using log transport services, at least one log archive destination must be at the site running the downstream capture process. | |
Range: One of the following: Modifiable?: Yes |
Specifies the availability state of the corresponding destination. The parameter suffix ( To use downstream capture and copy the redo log files to the downstream database using log transport services, make sure the destination that corresponds to the | |
Modifiable?: No |
Specifies the maximum number of concurrent open connections to remote databases in one session. These connections include database links, as well as external procedures and cartridges, each of which uses a separate process. In a Streams environment, make sure this parameter is set to the default value of | |
Default: Derived from the values of the following parameters: Modifiable?: Yes |
Specifies the maximum number of parallel execution processes and parallel recovery processes for an instance. As demand increases, Oracle will increase the number of processes from the number created at instance startup up to this value. In a Streams environment, each capture process and apply process may use multiple parallel execution servers. Set this initialization parameter to an appropriate value to ensure that there are enough parallel execution servers. | |
Default: Derived from Range: Modifiable?: No |
Specifies the maximum number of operating system user processes that can simultaneously connect to Oracle. Make sure the value of this parameter allows for all background processes, such as locks, job queue processes, and parallel execution processes. In Streams, capture processes and apply processes use background processes and parallel execution processes, and propagation jobs use job queue processes. | |
Modifiable?: No |
Enables or disables the sending of redo archival to remote destinations and the receipt of remotely archived redo. To use downstream capture and copy the redo log files to the downstream database using log transport services, this parameter must be set to | |
Modifiable?: No |
Specifies the maximum number of sessions that can be created in the system. To run one or more capture processes or apply processes in a database, you may need to increase the size of this parameter. Each background process in a database requires a session. | |
Default: Initial size of SGA at startup Range: Modifiable?: No |
Specifies the maximum size of SGA for the lifetime of a database instance. To run multiple capture processes on a single database, you may need to increase the size of this parameter. | |
32-bit platforms: 64-bit platforms: Maximum: operating system-dependent Modifiable?: Yes |
Specifies (in bytes) the size of the shared pool. The shared pool contains shared cursors, stored procedures, control structures, and other structures. If the | |
Maximum: operating system-dependent Modifiable?: Yes |
Specifies (in bytes) the size of the Streams pool. The Streams pool contains captured events. In addition, the Streams pool is used for internal communications during parallel capture and apply. If the size of the Streams pool is greater than zero, then any SGA memory used by Streams is allocated from the Streams pool. If the Streams pool size is set to zero, then SGA memory used by Streams is allocated from the shared pool and may use up to 10% of the shared pool. This parameter is modifiable. However, if this parameter is set to zero when an instance starts, then increasing it beyond zero has no effect on the current instance because it is using the shared pool for Streams allocations. Also, if this parameter is set to a value greater than zero when an instance starts and is then reduced to zero when the instance is running, then Streams processes and jobs will not run. You should increase the size of the Streams pool for each of the following factors:
For example, if parallelism is set to | |
If If The default for Modifiable?: Yes |
Specifies whether or not statistics related to time are collected. To collect elapsed time statistics in the dynamic performance views related to Streams, set this parameter to | |
Range: Modifiable?: Yes |
Specifies (in seconds) the amount of committed undo information to retain in the database. For a database running one or more capture processes, make sure this parameter is set to specify an adequate undo retention period. If you are running one or more capture processes and you are unsure about the proper setting, then try setting this parameter to at least See Also: Oracle Database Administrator's Guide for more information about the retention period and the undo tablespace |
Any source database that generates redo log information that will be captured by a capture process must be running in ARCHIVELOG
mode. In addition, make sure the initialization parameters are set properly on any database that will run a capture process.
See Also:
|
If you plan to use Streams to share information between databases, then configure network connectivity and database links between these databases:
CONNECT
TO
clause for the user propagating events between databases.
For example, to create a database link to a database named dbs2.net
connecting as a Streams administrator named strmadmin
, run the following statement:
CREATE DATABASE LINK dbs2.net CONNECT TO strmadmin IDENTIFIED BY strmadminpw USING 'dbs2.net';
See Also:
Oracle Database Administrator's Guide for more information about creating database links |