This procedure creates a database link to a target database. There are options to create a database link to another Autonomous Database instance, to an Oracle Database that is not an Autonomous Database, or to a non-Oracle Database using Oracle-managed heterogeneous
connectivity.
This procedure disables resource principal credentials for the database or for the
specified schema. With a user name specified,
other than ADMIN, the procedure revokes the
specified schema access to the resource principal
credential.
This procedure enables resource principal credential and creates the credential OCI$RESOURCE_PRINCIPAL. With a user name specified, other than ADMIN, the procedure grants the specified schema access to the resource principal credential.
DISABLE_APP_CONT Procedure This procedure disables database application continuity for the session associated with the specified service name in Autonomous Database.
DISABLE_PRINCIPAL_AUTH Procedure This procedure revokes principal based authentication for a specified provider on Autonomous Database and applies to the ADMIN user or to the specified user.
ENABLE_APP_CONT Procedure This procedure enables database application continuity for the session associated with the specified service name in Autonomous Database.
ENABLE_AWS_ARN Procedure This procedure enables an Autonomous Database instance to use Amazon Resource Names (ARNs) to access AWS resources.
ENABLE_FEATURE Procedure This procedure enables the specified feature on the Autonomous Database instance.
ENABLE_OPERATOR_ACCESS Procedure Oracle Cloud Operations does not access your Autonomous Database instance and access is disallowed by default. When access is required to troubleshoot or mitigate an issue, you can allow a cloud operator access to the database schemas for a limited time.
ENABLE_PRINCIPAL_AUTH Procedure This procedure enables principal authentication on Autonomous Database for the specified provider and applies to the ADMIN user or the specified user.
ENABLE_RESOURCE_PRINCIPAL Procedure Enable resource principal credential for the database or for the specified schema. This procedure creates the credential OCI$RESOURCE_PRINCIPAL.
FINISH_WORKLOAD_CAPTURE Procedure This procedure finishes the current workload capture, stops any subsequent workload capture requests to the database, and uploads the capture files to Object Storage.
PREPARE_REPLAY Procedure The PREPARE_REPLAY procedure prepares the refreshable clone for a replay.
PURGE_FLASHBACK_ARCHIVE Procedure This procedure enables ADMIN users to purge historical data from Flashback Data Archive. You can either purge all historical data from Flashback Data Archive flashback_archive or selective data based on timestamps or System Change Number.
REPLAY_WORKLOAD Procedure This procedure initiates a workload replay on your Autonomous Database instance. The overloaded form enables you to replay the capture files from an Autonomous Database instance, on-premises database, or other cloud service databases.
This
procedure attaches a file system in the database.
The DBMS_CLOUD_ADMIN.ATTACH_FILE_SYSTEM
procedure attaches a file system in your database and stores information about the file
system in the DBA_CLOUD_FILE_SYSTEMS view.
Syntax
DBMS_CLOUD_ADMIN.ATTACH_FILE_SYSTEM (
file_system_name IN VARCHAR2,
file_system_location IN VARCHAR2,
directory_name IN VARCHAR2,
description IN VARCHAR2 DEFAULT NULL,
params IN CLOB DEFAULT NULL
);
Parameters
Parameter
Description
file_system_name
Specifies the name of the file system.
This parameter is mandatory.
file_system_location
Specifies the location of the file system.
The value you supply with file_system_location
consists of a Fully Qualified Domain Name (FQDN) and a file path in the form:
FQDN:file_path.
For example:
FQDN: myhost.sub000445.myvcn.oraclevcn.com
For Oracle Cloud Infrastructure File
Storage set the FQDN in Show Advanced Options when you
create a file system. See Creating File Systems for
more information.
File Path: /results
This parameter is mandatory.
directory_name
Specifies the directory name for the attached file system. The directory must
exist.
This parameter is mandatory.
description
(Optional) Provides a description of the task.
params
A JSON string that provides an additional parameter for the file
system.
nfs_version: Specifies the NFS version to use
when NFS is attached (NFSv3 or NFSv4). Valid values: 3, 4.
The DBMS_CLOUD_ADMIN.ATTACH_FILE_SYSTEM procedure looks up the Network File System hostname on the customer's virtual cloud network (VCN). The error "ORA-20000: Mounting NFS fails" is returned if the hostname specified in the location cannot be located.
Oracle Cloud Infrastructure File
Storage uses NFSv3 to share
If you attach to non-Oracle Cloud Infrastructure File
Storage systems, the procedure supports NFSv3 and NFSv4
If you have an attached NFS server that uses NFSv3 and the NFS version is updated to
NFSv4 in the NFS server, you must run DBMS_CLOUD_ADMIN.DETACH_FILE_SYSTEM and then DBMS_CLOUD_ADMIN.ATTACH_FILE_SYSTEM (using
the params parameter with nfs_version set to 4). This
attaches NFS with the matching protocol so that Autonomous Database can access the NFSv4 Server. Without detaching and then
reattaching, the NFS server will be inaccessible and you may see an error such as:
"Protocol not supported".
This
procedure creates a database link to a target database in the schema calling the
API.
The overloaded forms support the following:
When you use the gateway_params parameter, this enables you to
create a database link with Oracle-managed heterogeneous
connectivity where the link is to a supported non-Oracle
database.
When you use the rac_hostnames parameter, this enables you to
create a database link from an Autonomous Database on a private endpoint to a target Oracle RAC database. In this
case, you use the rac_hostnames parameter to specify the host
names of one or more individual nodes of the target Oracle RAC database.
Syntax
DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK(
db_link_name IN VARCHAR2,
hostname IN VARCHAR2,
port IN NUMBER,
service_name IN VARCHAR2,
ssl_server_cert_dn IN VARCHAR2 DEFAULT,
credential_name IN VARCHAR2 DEFAULT,
directory_name IN VARCHAR2 DEFAULT,
gateway_link IN BOOLEAN DEFAULT,
public_link IN BOOLEAN DEFAULT,
private_target IN BOOLEAN DEFAULT
gateway_params IN CLOB DEFAULT);
DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK(
db_link_name IN VARCHAR2,
rac_hostnames IN CLOB,
port IN NUMBER,
service_name IN VARCHAR2,
ssl_server_cert_dn IN VARCHAR2 DEFAULT,
credential_name IN VARCHAR2 DEFAULT,
directory_name IN VARCHAR2 DEFAULT,
gateway_link IN BOOLEAN DEFAULT,
public_link IN BOOLEAN DEFAULT,
private_target IN BOOLEAN DEFAULT);
Parameters
Parameter
Description
db_link_name
The name of the database link to create.
hostname
The hostname for the target database.
Specifying localhost for
hostname as is not allowed.
When you specify a connection with Oracle-managed heterogeneous
connectivity by supplying the
gateway_params parameter, note the
following:
When the db_type value is
google_bigquery the
hostname is not used and you can
provide value such as example.com.
Use this parameter or rac_hostnames, do not use
both.
The DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK input should mention the scan name of the target Dedicated Autonomous Database as the 'hostname' parameter.
rac_hostnames
Specifies hostnames for the target Oracle RAC database. The value is a JSON
array that specifies one or more individual host names for the
nodes of the target Oracle RAC database. Multiple host names can
be passed in JSON, separated by a ",". For
example:
When the target is an Oracle RAC
database, use the rac_hostnames parameter to
specify one or more hostnames with DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK.
This allows you to take advantage of the high availability
capabilities of Oracle RAC. Using an IP address, a SCAN IP, or a
SCAN hostname in the rac_hostnames value is not
supported.
When you specify a list of host
names in the rac_hostnames parameter,
CREATE_DATABASE_LINK uses all of the
specified host names as addresses in the connect string. If one of
the specified hosts is not available on the target Oracle RAC
database, Autonomous Database automatically attempts to connect
using another host name from the list.
Use this parameter or hostname, do not use
both.
Specifying localhost for a
rac_hostname value is not allowed.
port
Specifies the port for the connections to the target
database.
When you specify a connection with Oracle-managed heterogeneous
connectivity using the gateway_params
parameter, set the port based on the db_type
value:
The service_name for the database to
link to. For a target Autonomous Database, find the service name by one of
the following methods:
Look in the tnsnames.ora
file in the wallet.zip that you
download from an Autonomous Database for your connection.
Click Database connection on the Oracle Cloud
Infrastructure Console. In the Connection Strings area, each connection string includes a service_name entry with the connection string for the corresponding service. When both Mutual TLS (mTLS) and TLS connections are allowed, under TLS authentication select TLS to view the TNS names and connection strings for connections with TLS authentication. See View TNS Names and Connection Strings for an Autonomous Database Instance for more information.
Query V$SERVICES view. For
example:
SELECT name FROM V$SERVICES;
When you specify a connection with Oracle-managed heterogeneous
connectivity using the gateway_params
parameter, the service_name is the database
name of the non-Oracle database.
ssl_server_cert_dn
The DN value found in the server certificate.
Oracle-managed heterogeneous
connectivity is preconfigured with a wallet that
contains most of the common trusted root and intermediate SSL
certificates. The ssl_server_cert_dn must be
NULL when you supply the
gateway_params parameter or do not include
the ssl_server_cert_dn parameter (the default
value is NULL).
Public Endpoint Link to an Autonomous Database Target without a
Wallet:
To connect to an Autonomous Database target on a public endpoint without a wallet
(TLS):
The directory_name parameter must be
NULL.
The ssl_server_cert_dn parameter must be
NULL or do not include this parameter
(the default value is NULL).
Private Endpoint Link without a Wallet:
To connect to an Oracle Database on a private endpoint without a wallet:
The target database must be on a private
endpoint.
The directory_name parameter
must be NULL.
The ssl_server_cert_dn parameter must be
NULL or do not include this parameter
(the default is NULL).
The private_target parameter
must be TRUE.
credential_name
The name of a stored credential created with DBMS_CLOUD.CREATE_CREDENTIAL.
This is the credentials to access the target database.
directory_name
The directory for the cwallet.sso file. The default
value for this parameter is 'data_pump_dir'.
Oracle-managed heterogeneous
connectivity is preconfigured with a wallet that
contains most of the common trusted root and intermediate SSL
certificates. The directory_name parameter is
not required when you supply the gateway_params
parameter.
Public Endpoint Link to an Autonomous Database Target without a
Wallet:
To connect to an Autonomous Database on a public endpoint without a wallet
(TLS):
The directory_name parameter must be
NULL.
The ssl_server_cert_dn parameter must be
NULL or do not include this parameter
(the default value is NULL).
In addition, to connect to an Autonomous Database with TCP, the
ssl_server_cert_dn parameter must be
NULL or do not include this parameter (the
default value is NULL).
Private Endpoint Link without a Wallet:
To connect to a target Oracle Database on a private endpoint without a
wallet:
The target database must be on a private endpoint.
The directory_name parameter
must be NULL.
The ssl_server_cert_dn
parameter must be NULL or do not include
this parameter (the default value is
NULL).
The private_target parameter
must be TRUE.
gateway_link
Indicates if the database link is created to another
Oracle Database or to an Oracle Database Gateway.
If gateway_link is set to
FALSE, this specifies a database link to
another Autonomous Database or to another Oracle Database.
If gateway_link is set to
TRUE, this specifies a database link to a
non-Oracle system. This creates a connect descriptor in the
database link definition that specifies
(HS=OK).
When gateway_link is set to
TRUE and gateway_params is
NULL, this specifies a database link to a
customer-managed Oracle gateway.
The default value for this parameter is
FALSE.
public_link
Indicates if the database link is created as a
public database link.
To run DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK
with this parameter set to TRUE, the user
invoking the procedure must have EXECUTE
privilege on the credential associated with the public database
link and must have the CREATE PUBLIC DATABASE
LINK system privilege. The EXECUTE
privilege on the credential can be granted either by the
ADMIN user or by the credential owner.
The default value for this parameter is
FALSE.
private_target
When a database link accesses a hostname that needs
to be resolved in a VCN DNS server, specify the
private_target parameter with value
TRUE.
When private_target is TRUE, the
hostname parameter must be a single
hostname (on a private endpoint, using an IP
address, a SCAN IP, or a SCAN hostname is not supported).
The default value for this parameter is
FALSE.
gateway_params
db_type This parameter specifies the target
database type for Oracle-managed heterogeneous
connectivity to connect
to non-Oracle databases. The db_type value is
one of:
awsredshift
azure
* See Usage Notes for additional supported gateway_params when db_type is azure.
db2
google_analytics
google_bigquery
* See Usage Notes for additional supported
gateway_params when
db_type is
google_bigquery.
hive
* See Usage
Notes for additional supported
gateway_params when
db_type is
hive.
mongodb
mysql
postgres
salesforce
*
See Usage Notes for additional supported
gateway_params when
db_type is
salesforce.
servicenow
* See
Usage Notes for additional supported
gateway_params when
db_type is
servicenow.
sharepoint
* See Usage Notes for additional supported gateway_params when db_type is sharepoint.
snowflake
* See
Usage Notes for additional supported
gateway_params when
db_type is
snowflake.
youtube
* See Usage Notes for additional supported gateway_params when db_type is youtube.
NULL
When
gateway_params is
NULL and
gateway_link is set to
TRUE, this specifies a database
link to a customer-managed Oracle gateway.
Specify the parameter with the
json_object form.
For example:
gateway_params => json_object('db_type' value
'awsredshift')
When gateway_params is
NULL and private_target is
TRUE, if directory_name is
NULL, a TCP-based database link is created.
When gateway_params is
NULL and private_target is
TRUE, if directory_name is
NULL, a TCPS-based database link is
created.
enable_ssl:
For a database on a private endpoint, the gateway_params parameter supports the optional enable_ssl parameter. Set this parameter to true to support SSL/TLS connections for a remote target database on a private endpoint. By default enable_ssl is false.
For example:
gateway_params => JSON_OBJECT(
'db_type' value 'snowflake',
'enable_ssl' value true)
Usage Notes
When you specify the gateway_params parameter, for some
db_type values, additional
gateway_params parameters are supported:
db_type
Additional gateway_params Values
azure
When the db_type value is azure there are two optional parameters, auth_method and domain to support NTLM/AD authentication.
When NTLMv2 is configured, set auth_method=10 and set domain to the Windows domain value.
To use an Azure Active Directory password, set auth_method=13. Do not use auth_method=13 to access an Oracle on-premises Database.
When the
db_type is
google_analytics, the credential
you specify must be a Google OAuth credential
(gcp_oauth2) See CREATE_CREDENTIAL Procedure for more information.
google_bigquery
When the db_type is google_bigquery, the credential you specify must be a Google OAuth credential (gcp_oauth2) See CREATE_CREDENTIAL Procedure for more information.
When db_type is
google_bigquery, the parameter
project is valid. This parameter
specifies the project name for
google_bigquery and is
required.
The table name you specify when you use
SELECT with Google BigQuery must be
in quotes. For example:
SELECT * FROM "sales"@GOOGLE_BIGQUERY_LINK
hive
When db_type is
hive, the parameter
http_path is valid. This parameter
specifies the HttpPath value, if required, to connect to
the Hive instance.
salesforce
When the db_type is
salesforce, the parameter:
security_token is valid. A security
token is a case-sensitive alphanumeric code. Supplying a
security_token value is required to
access Salesforce. For example:
gateway_params => JSON_OBJECT(
'db_type' value 'salesforce',
'security_token' value 'security_token_value' )
To connect to ServiceNow and get data you
must supply the gateway parameters
directory_name and
file_name. These parameters specify
a model file (REST config file) that maps the JSON
response to the relational model. The model file
specifies the endpoints, table mapping, and HTTP
response code for processing the JSON response. See
Model
file syntax and Example
Model file for more information.
When you use gateway_params parameter with
db_typeservicenow, there are two supported
options:
Basic Authentication: you must
supply the gateway_params
parameter db_type with the value
'servicenow', and supply the
directory_name and
file_name parameters along with
username/password type credentials.
OAuth 2.0 Authentication: you must
supply the gateway_params
parameter db_type with the value
'servicenow', and the
directory_name,
file_name, and
token_uri parameters, along with
OAuth type credentials.
The directory_name
parameter specifies the directory with the ServiceNow
REST config file. You could create this directory as
follows:
create or replace directory servicenow_dir as 'SERVICENOW_DIR';
Obtain and download the ServiceNow REST
config file to the specified directory. For example:
Set the file_name value to
the name of the REST config file you downloaded,
"servicenow.rest".
Then you can use the ServiceNow REST config file with either basic authentication or OAuth2.0.
Then you can use the ServiceNow REST config file with either basic authentication or OAuth2.0. See HETEROGENEOUS_CONNECTIVITY_INFO View for samples.
sharepoint
When you use gateway_params parameter with db_typesharepoint, also specify values for auth_uri, scope, service_url, and token_uri.
For db_typesharepoint, the credential you supply with DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK must be an OAuth type credential using the params parameter with gcp_oauth2 values specified (client_id, client_secret, and refresh_token). See CREATE_CREDENTIAL Procedure for more information. Generate the refresh_token for tenant_id.sharepoint.com/.default offline_access. See the following for more information: Determine the scope and OAuth 2.0 authentication.
Set values for gateway_params for db_typesharepoint:
When the db_type is SNOWFLAKE, the
optional parameters: role,
schema, and
warehouse are valid. These values
specify a different schema, role, or warehouse value,
other than the default. For example:
gateway_params => JSON_OBJECT(
'db_type' value 'snowflake',
'role' value 'ADMIN',
'schema' value 'PUBLIC',
'warehouse' value 'TEST' )
youtube
To connect to Youtube and get data you must supply the gateway parameters directory_name and file_name. These parameters specify a model file (REST config file) that maps the JSON response to the relational model. The model file specifies the endpoints, table mapping, and HTTP response code for processing the JSON response. See Model file syntax and Example Model file for more information.
When you use gateway_params parameter with db_typeyoutube, the credential you specify must be a Google OAuth credential (gcp_oauth2) See CREATE_CREDENTIAL Procedure for more information.
OAuth 2.0 Authentication: you must supply the gateway_params parameter db_type with the value youtube, and the directory_name and file_name parameters, along with OAuth type credentials.
The directory_name parameter specifies the directory with the ServiceNow REST config file. You could create this directory as follows:
create or replace directory youtube_dir as 'YOUTUBE_DIR';
Obtain and download the ServiceNow REST config file to the specified directory. For example:
To run DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK with a
user other than ADMIN, you need to grant EXECUTE and
CREATE DATABASE LINK privileges to that user. For
example, run the following command as ADMIN to grant privileges
to adb_user:
GRANT EXECUTE ON DBMS_CLOUD_ADMIN TO adb_user;
GRANT CREATE DATABASE LINK TO adb_user;
In addition, when you create a Database Link in a schema other than the ADMIN
schema, for example in a schema named adb_user, the adb_user schema must own the credential you use with
DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK.
Only one wallet file is valid per directory specified with the
directory_name parameter. You can only upload one
cwallet.sso at a time to the directory you choose
for wallet files. This means with a cwallet.sso in a
directory, you can only create database links to the databases for which the
wallet in that directory is valid. To use multiple
cwallet.sso files with database links you need to
create additional directories and put each cwallet.sso
in a different directory.
To create a database link to an Autonomous Database, set
GLOBAL_NAMES to FALSE on the source
database (non-Autonomous Database).
SQL> ALTER SYSTEM SET GLOBAL_NAMES = FALSE;
System altered.
SQL> SHOW PARAMETER GLOBAL_NAMES
NAME TYPE VALUE
---------------------- ----------- -----------
global_names boolean FALSE
When the private_target parameter is
TRUE, the hostname parameter specifies
a private host inside the VCN.
This
procedure detaches a file system from the database.
The DBMS_CLOUD_ADMIN.DETACH_FILE_SYSTEM
procedure detaches a file system from your database. In addition to that, the DBMS_CLOUD_ADMIN.DETACH_FILE_SYSTEM procedure
also removes the information about the file system from the
DBA_CLOUD_FILE_SYSTEMS view.
Syntax
DBMS_CLOUD_ADMIN.DETACH_FILE_SYSTEM(
file_system_name IN VARCHAR2
);
Parameters
Parameter
Description
file_system_name
Specifies the name of the file system.
This parameter is mandatory.
Example:
BEGIN
DBMS_CLOUD_ADMIN.DETACH_FILE_SYSTEM (
file_system_name => 'FSS'
);
END;
/
Usage Notes
To run this procedure, you must be logged in as the ADMIN user or have the EXECUTE privilege on DBMS_CLOUD_ADMIN.
You must have the WRITE privilege on the directory object in the
database, to detach a file system from a directory using the DBMS_CLOUD_ADMIN.DETACH_FILE_SYSTEM procedure.
The DBMS_CLOUD_ADMIN.DETACH_FILE_SYSTEM
procedure can only detach a private File Storage Service in databases with Private
Endpoints enabled.
The DBMS_CLOUD_ADMIN.DETACH_FILE_SYSTEM procedure looks up the Network File System hostname on the customer's virtual cloud network (VCN). The error "ORA-20000: Mounting NFS fails" is returned if the hostname specified in the location cannot be located.
This
procedure disables database application continuity for the session associated with the
specified service name in Autonomous Database.
Syntax
DBMS_CLOUD_ADMIN.DISABLE_APP_CONT(
service_name IN VARCHAR2);
Parameters
Parameter
Description
service_name
The service_name for the Autonomous Database service.
To find service names:
Look in the tnsnames.ora
file in the wallet.zip that you
download from an Autonomous Database for your connection.
Click Database connection on the Oracle Cloud
Infrastructure Console. In the Connection
strings area, each connection string
includes a service_name entry that
contains the connection string for the corresponding
service. When both Mutual TLS (mTLS) and TLS connections
are allowed, under TLS
authentication select
TLS to view the TNS names and
connection strings for connections with TLS
authentication. See View TNS
Names and Connection Strings for an Autonomous
Database Instance for more information.
BEGIN
DBMS_CLOUD_ADMIN.DISABLE_APP_CONT(
service_name => 'nv123abc1_adb1_high.adb.oraclecloud.com' );
END;
/
Verify the value as follows:
SELECT name, failover_type FROM DBA_SERVICES;
NAME FAILOVER_TYPE
------------------------------------------------------- --------------
nv123abc1_adb1_high.adb.oraclecloud.com
This
procedure disables the specified feature on the Autonomous Database instance.
Syntax
DBMS_CLOUD_ADMIN.DISABLE_FEATURE(
feature_name IN VARCHAR2);
Parameters
Parameter
Description
feature_name
Specifies the feature type to be disabled. Supported values are:
'AUTO_DST_UPGRADE': Disable
AUTO DST feature.
'AUTO_DST_UPGRADE_EXCL_DATA': Disable
AUTO DST EXCL DATA feature.
'ORAMTS': Disable OraMTS
feature.
'OWM': Disable Oracle Workspace Manager.
'WORKLOAD_AUTO_REPLAY': Disable workload auto replay feature.
This parameter is mandatory.
Examples
BEGIN
DBMS_CLOUD_ADMIN.DISABLE_FEATURE(
feature_name => 'ORAMTS');
END;
/
BEGIN
DBMS_CLOUD_ADMIN.DISABLE_FEATURE(
feature_name => 'AUTO_DST_UPGRADE');
END;
/
BEGIN
DBMS_CLOUD_ADMIN.DISABLE_FEATURE(
feature_name => 'AUTO_DST_UPGRADE_EXCL_DATA');
END;
/
BEGIN
DBMS_CLOUD_ADMIN.DISABLE_FEATURE(
feature_name => 'OWM');
END;
/
BEGIN
DBMS_CLOUD_ADMIN.DISABLE_FEATURE(
feature_name => 'WORKLOAD_AUTO_REPLAY');
END;
/
Usage Notes
To disable the OraMTS, AUTO_DST_UPGRADE, AUTO_DST_UPGRADE_EXCL_DATA, OWM, or WORKLOAD_AUTO_REPLAY features for your Autonomous Database instance, you must be logged in as the ADMIN user or have the EXECUTE privilege on DBMS_CLOUD_ADMIN.
When both AUTO_DST_UPGRADE and
AUTO_DST_UPGRADE_EXCL_DATA are disabled, if new time
zone versions are available the Autonomous Database instance does not upgrade to use the latest
available time zone files.
Query dba_cloud_config to verify that
AUTO_DST_UPGRADE is disabled.
SELECT param_name, param_value FROM dba_cloud_config WHERE
LOWER(param_name) = 'auto_dst_upgrade';
0 rows selected.
Query dba_cloud_config to verify that
AUTO_DST_UPGRADE_EXCL_DATA is
disabled.
SELECT param_name, param_value FROM dba_cloud_config WHERE
LOWER(param_name) = 'auto_dst_upgrade_excl_data';
0 rows selected.
This procedure revokes
principal based authentication for a specified provider on Autonomous Database and applies to the ADMIN user
or to the specified user.
Syntax
DBMS_CLOUD_ADMIN.DISABLE_PRINCIPAL_AUTH(
provider IN VARCHAR2,
username IN VARCHAR2 DEFAULT 'ADMIN' );
Parameters
Parameter
Description
provider
Specifies the type of provider.
Valid values:
AWS
AZURE
GCP
OCI
username
Specifier the user to disable principal based authentication
for.
A null value is valid for the
username. If username is
not specified, the procedure applies for the
"ADMIN" user.
Usage Notes
When the provider value is AZURE and the
username is ADMIN, the procedure
disables Azure service principal based authentication on Autonomous Database and deletes
the Azure application on the Autonomous Database instance.
When the provider value is AZURE and the
username is a user other than the
ADMIN user, the procedure revokes the privileges from
the specified user. The ADMIN user and other users that are
enabled to use the Azure service principal can continue to use
ADMIN.AZURE$PA and the application that is created for
the Autonomous Database instance
remains on the instance.
Examples
BEGIN
DBMS_CLOUD_ADMIN.DISABLE_PRINCIPAL_AUTH(
provider => 'AZURE',
username => 'SCOTT');
END;
/
BEGIN
DBMS_CLOUD_ADMIN.DISABLE_PRINCIPAL_AUTH(
provider => 'GCP');
END;
/
After you are done using a database link and you run DBMS_CLOUD_ADMIN.DROP_DATABASE_LINK, to ensure security
of your Oracle database remove any stored wallet files. For example:
Remove the wallet file in Object Store.
Use DBMS_CLOUD.DELETE_FILE to
remove the wallet file from the data_pump_dir directory
or from the user defined directory where the wallet file was uploaded.
This
procedure enables database application continuity for the session associated with the
specified service name in Autonomous Database.
Syntax
DBMS_CLOUD_ADMIN.ENABLE_APP_CONT(
service_name IN VARCHAR2);
Parameters
Parameter
Description
service_name
The service_name for the Autonomous Database service.
To find service names:
Look in the tnsnames.ora file in the
wallet.zip that you download
from an Autonomous Database for your connection.
Click Database connection on the Oracle Cloud
Infrastructure Console. In the Connection
strings area, each connection string
includes a service_name entry that
contains the connection string for the corresponding
service. When both Mutual TLS (mTLS) and TLS connections
are allowed, under TLS
authentication select
TLS to view the TNS names and
connection strings for connections with TLS
authentication. See View TNS
Names and Connection Strings for an Autonomous
Database Instance for more information.
Enable
users to login to the database with external authentication schemes.
Syntax
DBMS_CLOUD_ADMIN.ENABLE_EXTERNAL_AUTHENTICATION(
type IN VARCHAR2,
force IN BOOLEAN DEFAULT FALSE,
params IN CLOB DEFAULT NULL
);
Parameter
Parameter
Description
type
Specifies the external authentication type. Valid
values: or .
'OCI_IAM'
'AZURE_AD'
'CMU'
'KERBEROS'
force
(Optional) Override a currently enabled external
authentication scheme. Valid values are TRUE or
FALSE.
The default value is FALSE.
params
A JSON string that provides additional parameters
for the external authentication.
CMU parameters:
location_uri: specifies the
cloud storage URI for the bucket where files required for
CMU are stored.
If you specify
location_uri there is a fixed name
directory object CMU_WALLET_DIR created
in the database at the path
'cmu_wallet' to save the CMU
configuration files. In this case, you do not need to
supply the directory_name
parameter.
credential_name: specifies the
credentials that are used to download the CMU configuration
files from the Object Store to the directory
object.
Default value is NULL which
allows you to provide a Public, Preauthenticated, or
pre-signed URL for Object Store bucket or
subfolder.
directory_name: specifies the
directory name where configuration files required for CMU
are stored. If directory_name is supplied,
you are expected to copy the CMU configuration files
dsi.ora and
cwallet.sso to this directory
object.
KERBEROS parameters:
location_uri: specifies the
cloud storage URI for the bucket where the files required
for Kerberos are stored.
If you specify
location_uri there is a fixed name
directory object KERBEROS_DIR created
in the database to save the Kerberos configuration
files. In this case, you do not need to supply the
directory_name parameter.
credential_name: specifies the credential that are used to
download Kerberos configuration files from the Object Store
location to the directory object.
Default value is
NULL which allows you to provide a
Public, Preauthenticated, or pre-signed URL for Object
Store bucket or subfolder.
directory_name: specifies the
directory name where files required for Kerberos are stored.
If directory_name is supplied, you are
expected to copy the Kerberos configuration files to this
directory object.
kerberos_service_name:
specifies a name to use as the Kerberos service name. This
parameter is optional.
Default value: When not
specified, the kerberos_service_name
value is set to the Autonomous Database instance's GUID.
AZURE_AD parameters:
tenant_id: Tenant ID of the
Azure Account. Tenant Id specifies the Autonomous Database instance's Azure AD application
registration.
application_id: Azure
Application ID created in Azure AD to assign roles/schema
mappings for external authentication in the Autonomous Database instance.
application_id_uri: Unique URI
assigned to the Azure Application.
This it the identifier
for the Autonomous Database instance. The name must be domain
qualified (this supports cross tenancy resource
access).
The maximum length for this parameter is
256 characters.
Exceptions
Exception
Error
Description
invalid_ext_auth
ORA-20004
See the accompanying message for a detailed
explanation.
Usage Notes
With typeOCI_IAM, if the resource principal is not enabled on the
Autonomous Database instance,
this routine enables resource principal with DBMS_CLOUD_ADMIN.ENABLE_RESOURCE_PRINCIPAL.
This procedure sets the system parameters IDENTITY_PROVIDER_TYPE and IDENTITY_PROVIDER_CONFIG to required users to access the instance with Oracle Cloud Infrastructure Identity
and Access Management authentication and authorization.
Examples
Enable OCI_IAM
Authentication
BEGIN DBMS_CLOUD_ADMIN.ENABLE_EXTERNAL_AUTHENTICATION(
type => 'OCI_IAM',
force=> TRUE );
END;
/
PL/SQL procedure successfully completed.
Enable CMU Authentication for Microsoft Active Directory
You pass in a directory name that contains the CMU configuration files
through params JSON argument.
BEGIN DBMS_CLOUD_ADMIN.ENABLE_EXTERNAL_AUTHENTICATION(
type => 'CMU',
force => TRUE,
params => JSON_OBJECT('directory_name' value 'CMU_DIR'); // CMU_DIR directory object already exists
END;
/
PL/SQL procedure successfully completed.
You pass in a location URI pointing to an Object Storage location that
contains CMU configuration files through params JSON argument.
BEGIN
DBMS_CLOUD_ADMIN.ENABLE_EXTERNAL_AUTHENTICATION(
type => 'CMU',
params => JSON_OBJECT('location_uri' value 'https://objectstorage.us-phoenix-1.oraclecloud.com/n/namespace-string/b/bucketname/o',
'credential_name' value 'my_credential_name')
);
END;
/
PL/SQL procedure successfully completed.
Enable Azure AD Authentication
BEGIN DBMS_CLOUD_ADMIN.ENABLE_EXTERNAL_AUTHENTICATION(
type => 'AZURE_AD',
force => TRUE,
params => JSON_OBJECT( 'tenant_id' VALUE '....',
'application_id' VALUE '...',
'application_id_uri' VALUE '.....' ));
END;
/
PL/SQL procedure successfully completed.
Enable Kerberos Authentication
You pass in a directory name that contains Kerberos configuration files
through params JSON argument.
BEGIN DBMS_CLOUD_ADMIN.ENABLE_EXTERNAL_AUTHENTICATION(
type => 'KERBEROS',
force => TRUE,
params => JSON_OBJECT('directory_name' value 'KERBEROS_DIR'); // KERBEROS_DIR directory object already exists
END;
/
PL/SQL procedure successfully completed.
You pass in a location URI pointing to an Object Storage location that
contains Kerberos configuration files through params JSON
argument:
BEGIN DBMS_CLOUD_ADMIN.ENABLE_EXTERNAL_AUTHENTICATION(
type => 'KERBEROS',
force => TRUE,
params => JSON_OBJECT('location_uri' value 'https://objectstorage.us-phoenix-1.oraclecloud.com/n/namespace-string/b/bucketname/o',
'credential_name' value 'my_credential_name');
END;
/
You pass in a service name with the
kerberos_service_name in the params JSON
argument:
BEGIN DBMS_CLOUD_ADMIN.ENABLE_EXTERNAL_AUTHENTICATION(
type => 'KERBEROS',
force => TRUE,
params => JSON_OBJECT('directory_name' value 'KERBEROS_DIR', // KERBEROS_DIR directory object already exists
'kerberos_service_name' value 'oracle' ));
END;
/
After Kerberos is enabled on your Autonomous Database instance, use the following query to view the Kerberos
service name:
SELECT SYS_CONTEXT('USERENV','KERBEROS_SERVICE_NAME') FROM DUAL;
This procedure enables the specified feature on the Autonomous Database instance.
Syntax
DBMS_CLOUD_ADMIN.ENABLE_FEATURE(
feature_name IN VARCHAR2,
params IN CLOB DEFAULT NULL);
Parameters
Parameter
Description
feature_name
Name of the feature to enable. The supported values are:
'AUTO_DST_UPGRADE': Enable AUTO DST
feature.
'AUTO_DST_UPGRADE_EXCL_DATA': Enable
AUTO DST EXCL DATA feature.
'JAVAVM': Enable JAVAVM feature.
'OLAP': Enable OLAP feature. OLAP requires that
Java is enabled. When you enable OLAP, Java is automatically
enabled along with the OLAP feature.
'ORAMTS': Enable OraMTS feature.
'OWM': Enable Oracle Workspace Manager.
'WORKLOAD_AUTO_REPLAY': Enable the workload auto replay
feature.
This parameter is mandatory.
params
A JSON string that provides additional parameters for some features.
For the OraMTS feature the params parameter is:
location_uri: the location_uri accepts a string value. The value specifies the HTTPS URL for the OraMTS server in a customer network.
For the WORKLOAD_AUTO_REPLAY feature the params
parameters are:
target_db_ocid: A
string value. The value specifies the OCID of a
target refreshable clone database on which the captured workload is
replayed. The refreshable clone must have the
Early patch level set.
This parameter is mandatory.
capture_duration: A
number value. The value specifies the duration
in minutes for which the workload is captured on the production
database. The value must be in the range between 1 and 720 minutes.
This parameter is mandatory.
capture_day: A
string value. The value specifies the day of
the week the workload capture on the production database should
begin.
This parameter is optional.
capture_time: A value in the
HH24:MM format. The value specifies the time of
the day the workload capture on the production database should
begin.
This parameter is optional.
By default the workload capture starts when you enable
WORKLOAD_AUTO_REPLAY. If the optional
capture_day and capture_time are
specified, the capture and the replay happen at the specified timestamp.
For example, if capture_day is Monday and
capture_time is 15:00, the first capture happens at
3PM on the next Monday. The day of week and time are also used to
schedule the later replay on the refreshable clone.
Example to Enable JAVAVM Feature:
BEGIN
DBMS_CLOUD_ADMIN.ENABLE_FEATURE (
feature_name => 'JAVAVM' );
END;
/
Example to Enable Auto DST Feature:
BEGIN
DBMS_CLOUD_ADMIN.ENABLE_FEATURE (
feature_name => 'AUTO_DST_UPGRADE' );
END;
/
Example to Enable Auto DST EXCL Data Feature:
BEGIN
DBMS_CLOUD_ADMIN.ENABLE_FEATURE (
feature_name => 'AUTO_DST_UPGRADE_EXCL_DATA' );
END;
/
Example to Enable OraMTS Feature:
BEGIN
DBMS_CLOUD_ADMIN.ENABLE_FEATURE(
feature_name => 'ORAMTS',
params => JSON_OBJECT('location_uri' VALUE 'https://mymtsserver.mycorp.com')
);
END;
/
Example to Enable OWM Feature:
BEGIN
DBMS_CLOUD_ADMIN.ENABLE_FEATURE(
feature_name => 'OWM' );
END;
/
Example to Enable Workload Auto Replay
Feature
BEGIN
DBMS_CLOUD_ADMIN.ENABLE_FEATURE(
feature_name => 'WORKLOAD_AUTO_REPLAY',
params => JSON_OBJECT('target_db_ocid' VALUE 'OCID1.autonomousdatabase.REGION..ID1', 'capture_duration' VALUE 120, 'capture_day' VALUE 'MONDAY', 'capture_time' VALUE '15:00'));
END;
/
A an error value of ORA-20000: Invalid argument for target_db_ocid
could indicate that the OCID you supplied is not a refreshable clone. In this case, you
need to supply an OCID with a value for a refreshable clone.
Usage Notes
You must be logged in as the ADMIN user or have the
EXECUTE privilege on DBMS_CLOUD_ADMIN to run
DBMS_CLOUD_ADMIN.ENABLE_FEATURE.
After you run DBMS_CLOUD_ADMIN.ENABLE_FEATURE with feature_name value 'JAVAVM', you must
restart the Autonomous Database instance
to install Oracle Java.
After you restart the Autonomous Database instance, the Java installation proceeds for some time after the
database is opened.
After you run DBMS_CLOUD_ADMIN.ENABLE_FEATURE with feature_name value 'OWM', you must restart the Autonomous Database instance to enable Oracle Workspace Manager. Oracle.
To enable AUTO_DST_UPGRADE, AUTO_DST_UPGRADE_EXCL_DATA, ORAMTS, JAVAVM, OWM, or WORKLOAD_AUTO_REPLAY features for your database, you must be logged in as the ADMIN user or have the EXECUTE privilege on DBMS_CLOUD_ADMIN.
By default, both AUTO_DST_UPGRADE and AUTO_DST_UPGRADE_EXCL_DATA are disabled. You can enable one or the other of these options, but not both.
After you enable AUTO_DST_UPGRADE, the next time you restart, or stop and then start the Autonomous Database instance, the instance upgrades to use the latest available time zone files. After AUTO_DST_UPGRADE is enabled, when new time zone files are available, the instance continues to upgrade to the latest available version on every subsequent restart or stop and start, until the feature is disabled.
Query dba_cloud_config to verify that AUTO_DST_UPGRADE is enabled.
SELECT param_name, param_value FROM dba_cloud_config WHERE
LOWER(param_name) = 'auto_dst_upgrade';
PARAM_NAME PARAM_VALUE
---------------- --------------
auto_dst_upgrade enabled
After you enable AUTO_DST_UPGRADE_EXCL_DATA the Autonomous Database instance upgrades to
use the latest available time zone files. After this feature is enabled, every
subsequent maintenance window upgrades the instance to use the latest available
time zone version. This feature assures that the time zone files are upgraded for
the database (enabling AUTO_DST_UPGRADE_EXCL_DATA does not update
any affected rows).
Query dba_cloud_config to verify that AUTO_DST_UPGRADE_EXCL_DATA is enabled.
SELECT param_name, param_value FROM dba_cloud_config WHERE
LOWER(param_name) = 'auto_dst_upgrade_excl_data';
PARAM_NAME PARAM_VALUE
-------------------------- -----------
auto_dst_upgrade_excl_data enabled
Oracle
Cloud Operations does not access your Autonomous Database instance and access is disallowed by default. When access is required to
troubleshoot or mitigate an issue, you can allow a cloud operator access to the database
schemas for a limited time.
Syntax
DBMS_CLOUD_ADMIN.ENABLE_OPERATOR_ACCESS(
auth_duration IN NUMBER DEFAULT 1
);
Parameters
Parameter
Description
auth_duration
Specifies the number of Hours for which Cloud Operator is granted access.
Valid values: must be whole numbers in the range of 1 to 24.
Default value: 1
Example
BEGIN
DBMS_CLOUD_ADMIN.ENABLE_OPERATOR_ACCESS(
auth_duration => 12 );
END;
/
Usage Notes
ORA-20000: Operator access is already enabled
indicates that operator access was already granted. In this case you have
two options:
Wait for operator access to expire, and then grant
operator access again with DBMS_CLOUD_ADMIN.ENABLE_OPERATOR_ACCESS
DBMS_CLOUD_ADMIN.ENABLE_OPERATOR_ACCESS
allows access only to the Cloud Operator and does not enable access for any
other user. All operations performed by the Cloud Operator are stored in the
view DBA_OPERATOR_ACCESS. See View Oracle Cloud Infrastructure Operations Actions for more information.
You allow a cloud operator to access the database schemas by
running the procedure DBMS_CLOUD_ADMIN.ENABLE_OPERATOR_ACCESS. This
means if you file a service request with Oracle Cloud Support and Oracle Cloud Operators need
to access your database schemas, you must also enable operator access by
runningDBMS_CLOUD_ADMIN.ENABLE_OPERATOR_ACCESS.
This
procedure enables principal authentication on Autonomous Database for the specified provider and applies to the ADMIN user or
the specified user.
Syntax
DBMS_CLOUD_ADMIN.ENABLE_PRINCIPAL_AUTH(
provider IN VARCHAR2,
username IN VARCHAR2 DEFAULT 'ADMIN',
params IN CLOB DEFAULT NULL);
Parameters
Parameter
Description
provider
Specifies the type of provider.
Valid values:
AWS: Enable use of Amazon
Resource Names (ARNs)
AZURE: Enable use of Azure
Service Principal
GCP: Enable use of Google
Service Account
OCI: Enable use of Resource
Principal
username
Name of the user who has principal authentication
usage enabled.
A null value is valid for the
username. If username is
not specified, the procedure applies for the
"ADMIN" user.
params
Specifies the configuration parameters.
When the provider parameter is
AWS, GCP, or
OCI, params is not
required. The default value is NULL.
grant_option: This parameter is
valid for all providers and is a Boolean value
TRUE or FALSE. The default
is FALSE.
When TRUE and a username is
specified, the specified user can use
ENABLE_PRINCIPAL_AUTH to enable other
users.
When the provider parameter is
AWS, these options are also
valid:
aws_role_arn: Specifies the AWS role
ARN.
external_id_type: Specifies the external
ID type. Valid values are:
"TENANT_OCID",
"DATABASE_OCID", or
"COMPARTMENT_OCID". The default
value for external_id_type is
"DATABASE_OCID".
When the provider parameter is
AZURE, this option is also
valid:
azure_tenantid: with the
value of the Azure tenant ID.
Usage Notes
When the provider parameter is
AZURE, the params parameter must
include the azure_tenantid in the following cases:
When DBMS_CLOUD_ADMIN.ENABLE_PRINCIPAL_AUTH
is called for the first time.
When DBMS_CLOUD_ADMIN.ENABLE_PRINCIPAL_AUTH
is called for the first time after DBMS_CLOUD_ADMIN.DISABLE_PRINCIPAL_AUTH
is called with the provider parameter
AZURE and the usernameADMIN.
When the provider parameter is
AWS:
After you enable ARN on the Autonomous Database
instance by running DBMS_CLOUD_ADMIN.ENABLE_PRINCIPAL_AUTH,
the credential named AWS$ARN is available to use
with any DBMS_CLOUD API that takes a
credential as the input.
Examples
BEGIN
DBMS_CLOUD_ADMIN.ENABLE_PRINCIPAL_AUTH(
provider => 'AZURE',
username => 'SCOTT',
params => JSON_OBJECT('azure_tenantid' value 'azure_tenantid'));
END;
/
BEGIN
DBMS_CLOUD_ADMIN.ENABLE_PRINCIPAL_AUTH(
provider => 'GCP',
username => 'SCOTT',
params => JSON_OBJECT(
'grant_option' value 'TRUE' ));
END;
/
BEGIN
DBMS_CLOUD_ADMIN.ENABLE_PRINCIPAL_AUTH(
provider => 'AWS',
username => 'SCOTT',
params => JSON_OBJECT(
'aws_role_arn' value 'arn:aws:iam::123456:role/AWS_ROLE_ARN',
'external_id_type' value 'TENANT_OCID'));
END;
/
Enable
resource principal credential for the database or for the specified schema. This procedure
creates the credential OCI$RESOURCE_PRINCIPAL.
Syntax
DBMS_CLOUD_ADMIN.ENABLE_RESOURCE_PRINCIPAL(
username IN VARCHAR2,
grant_option IN BOOLEAN DEFAULT FALSE);
Parameter
Parameter
Description
username
Specifies an optional user name. The name of the
database schema to be granted resource principal access.
If you do not supply a username, the
username is set to ADMIN.
grant_option
When username is supplied, if
grant_option is TRUE the
specified username can enable resource
principal usage for other users.
Exceptions
Exception
Error
Description
resource principal is already
enabled
ORA-20031
If you attempt to enable the resource principal when it is
already enabled.
Usage Notes
You must call DBMS_CLOUD_ADMIN.ENABLE_RESOURCE_PRINCIPAL
with the ADMIN username or with no arguments before you
call DBMS_CLOUD_ADMIN.ENABLE_RESOURCE_PRINCIPAL
with a username for a database user schema.
You must set up a dynamic group and policies for the dynamic
group before you call DBMS_CLOUD_ADMIN.ENABLE_RESOURCE_PRINCIPAL.
See the following for more information on policies, creating a
dynamic group, and creating rules:
Enabling the resource principal with DBMS_CLOUD_ADMIN.ENABLE_RESOURCE_PRINCIPAL is
one-time operation. You do not need to enable the resource principal again,
unless you run DBMS_CLOUD_ADMIN.DISABLE_RESOURCE_PRINCIPAL
to disable the resource principal.
Resource principal is not available with refreshable clones.
This procedure finishes the current workload capture, stops any subsequent workload capture requests to the database, and uploads the capture files to Object Storage.
Example
BEGIN
DBMS_CLOUD_ADMIN.FINISH_WORKLOAD_CAPTURE
END;
/
Usage Notes
To run this procedure you must be logged in as the ADMIN user or have the EXECUTE privilege on DBMS_CLOUD_ADMIN.
When you pass the duration parameter to START_WORKLOAD_CAPTURE, the capture finishes when it reaches the specified time. However, if you call FINISH_WORKLOAD_CAPTURE, this stops the workload capture (possibly before the time specified with the duration parameter).
You can query the DBA_CAPTURE_REPLAY_STATUS view to check the finish workload status. See DBA_CAPTURE_REPLAY_STATUS View for more information.
Note
You must subscribe to the Information event com.oraclecloud.databaseservice.autonomous.database.information to be notified about the completion of FINISH_WORKLOAD_CAPTURE as well as the Object Storage link to download the capture file. This PAR URL is contained in the captureDownloadURL field of the event and is valid for 7 days from the date of generation. See Information Events on Autonomous Database for more information.
The PREPARE_REPLAY procedure prepares the refreshable clone for a replay.
Parameters
Parameter
Description
capture_name
Specifies the name of the workload capture.
This parameter is mandatory.
Syntax
DBMS_CLOUD_ADMIN.PREPARE_REPLAY(
capture_name IN VARCHAR2);
Example
BEGIN
DBMS_CLOUD_ADMIN.PREPARE_REPLAY
capture_name => 'cap_test1');
END;
/
This example prepares the refreshable clone to replay the workload indicated by the capture_name parameter, which involves bringing it up to the capture start time and then disconnecting it.
Usage Note
To run this procedure you must be logged in as the ADMIN user or have the EXECUTE privilege on DBMS_CLOUD_ADMIN.
This procedure enables ADMIN users to purge historical data from Flashback Data Archive. You can either purge all historical data from Flashback Data Archive flashback_archive or selective data based on timestamps or System Change Number.
Syntax
DBMS_CLOUD_ADMIN.PURGE_FLASHBACK_ARCHIVE(
scope IN VARCHAR2,
before_scn IN INTEGER DEFAULT NULL,
before_ts IN TIMESTAMP DEFAULT NULL);
Parameter
Description
scope
This specifies the scope to remove data from the flashback data archive.
all implies PURGE ALL;before_scn and before_timestamp must both be NULL.
scn implies PURGE BEFORE SCN;before_scn must be non-NULL and before_timestamp must be NULL.
TIMESTAMP implies PURGE BEFORE timestamp;before_scn must be NULL and before_timestamp must be non-NULL.
before_scn
This specifies the system change number before which all the data is removed from the flashback archive.
before_timestamp
This specifies the timestamp before which all the data is removed from the flashback archive.
Example
BEGIN
DBMS_CLOUD_ADMIN.PURGE_FLASHBACK_ARCHIVE(
scope => 'ALL'); // Purge all historical data from Flashback Data Archive flashback_archive
END;
/
This procedure initiates a
workload replay on your Autonomous Database instance.
The overloaded form enables you to replay the capture files from an Autonomous Database
instance, on-premises database, or other cloud service databases.
Syntax
DBMS_CLOUD_ADMIN.REPLAY_WORKLOAD(
capture_name IN VARCHAR2,
replay_name IN VARCHAR2 DEFAULT NULL,
capture_source_tenancy_ocid IN VARCHAR2 DEFAULT NULL,
capture_source_db_name IN VARCHAR2 DEFAULT NULL);
DBMS_CLOUD_ADMIN.REPLAY_WORKLOAD(
location_uri IN VARCHAR2,
credential_name IN VARCHAR2 DEFAULT NULL,
synchronization IN BOOLEAN DEFAULT TRUE,
process_capture IN BOOLEAN DEFAULT TRUE);
Parameters
Parameter
Description
CAPTURE_NAME
Specifies the name of the workload capture.
This parameter is mandatory.
REPLAY_NAME
Specifies the replay name.
If you do not supply a REPLAY_NAME value, the REPLAY_NAME is auto-generated with the format REPLAY_RANDOMNUMBER, for example, REPLAY_1678329506.
CAPTURE_SOURCE_TENANCY_OCID
Specifies the source tenancy OCID of the workload capture.
If you do not supply a CAPTURE_SOURCE_TENANCY_OCID value, the CAPTURE_SOURCE_TENANCY_OCID is set to NULL.
This parameter is only mandatory when running the workload capture in a full clone.
CAPTURE_SOURCE_DB_NAME
Specifies the source database name of the workload capture
If you do not supply a CAPTURE_SOURCE_DB_NAME value, the CAPTURE_SOURCE_DB_NAME is set to NULL.
This parameter is only mandatory when running the workload capture in a full clone.
LOCATION_URI
Specifies URI that points to an Object Storage location that contains the captured files.
This parameter is mandatory.
CREDENTIAL_NAME
Specifies the credential to access the object storage bucket.
If you do not supply a credential_name value, the database's default credentials are used.
SYNCHRONIZATION
Specifies the synchronization method used during workload replay.
TRUE specifies that the synchronization is based on SCN.
FALSE specifies that the synchronization is based on TIME.
If you do not supply a synchronization value, the synchronization is set to TRUE.
PROCESS_CAPTURE
Specifies whether or not you need to specify process_capture value. It can be set to FALSE only when you replay the same workload on the target database repeatedly.
If you do not supply a process_capture value, the process_capture is set to TRUE.
Example to replay the workload from an on-premises database on an Autonomous Database instance:
Downloads the capture files from the Object Storage location specified in location_uri and processes the capture files based on the process_capture parameter value.
Replays the captured workload based on the synchronization parameter value.
In this example, namespace-string is the Oracle
Cloud Infrastructure object storage namespace and
bucketname is the bucket
name. See Understanding
Object Storage Namespaces for more
information.
Example to replay the workload from an Autonomous Database instance on another Autonomous Database:
BEGIN
DBMS_CLOUD_ADMIN.REPLAY_WORKLOAD(
capture_name => 'CAP_TEST1');
END;
/
When you run this example, it:
Disconnects the current Autonomous Database instance.
Downloads the capture files from the Object Storage.
Replays the captured workload.
Uploads replay report after a replay.
Usage Notes for Replaying the Workload from an On-Premises or Other Cloud Service Database on another Autonomous Database
To run this procedure you must be logged in as the ADMIN user or have the EXECUTE privilege on DBMS_CLOUD_ADMIN.
Before you start replay, you should upload the cap and capfiles subdirectories, which contain the workload capture files, to the object storage location.
Usage Notes for Replaying the Workload from an Autonomous Database instance on another Autonomous Database
To run this procedure you must be logged in as the ADMIN user or have the EXECUTE privilege on DBMS_CLOUD_ADMIN.
The replay files are automatically uploaded to the Object Store as a zip file.
You can query the DBA_CAPTURE_REPLAY_STATUS view to check the workload replay status.
You must subscribe to the Information event com.oraclecloud.databaseservice.autonomous.database.information to be notified about the start and completion of the REPLAY_WORKLOAD as well as the Object Storage link to download the replay reports. This PAR URL is contained in the replayDownloadURL field of the event and is valid for 7 days from the date of generation. See Information Events on Autonomous Database for more information.
This procedure initiates a workload capture on your Autonomous Database instance.
Syntax
DBMS_CLOUD_ADMIN.START_WORKLOAD_CAPTURE(
capture_name IN VARCHAR2,
duration IN NUMBER DEFAULT NULL);
Parameters
Parameter
Description
capture_name
Specifies the name of the workload capture.
This parameter is mandatory.
duration
Specifies the duration in minutes for which you want to run the workload capture.
If you do not supply a duration value, the duration is set to NULL.
If set to NULL, the workload will continue until you run the FINISH_WORKLOAD_CAPTURE procedure.
Example
BEGIN
DBMS_CLOUD_ADMIN.START_WORKLOAD_CAPTURE(
capture_name => 'test');
END;
/
Usage Notes
To run this procedure you must be logged in as the ADMIN user or have the EXECUTE privilege on DBMS_CLOUD_ADMIN.
To measure the impacts of a system change on a workload, you must ensure that the capture and replay systems are in the same logical state.
Before initiating a workload capture, you should consider provisioning a refreshable clone to ensure the same start point for the replay.
Note
You must subscribe to the Information event com.oraclecloud.databaseservice.autonomous.database.information to be notified at the start of START_WORKLOAD_CAPTURE. See Information Events on Autonomous Database for more information.