CREATE_DATABASE_LINK Procedure
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 therac_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 |
---|---|
|
The name of the database link to create. |
|
The hostname for the target database. Specifying When you specify a connection with Oracle-managed heterogeneous connectivity by supplying the
Use this parameter or The |
|
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 "
When the target is an Oracle RAC database, use the When you specify a list of host names in the Use this parameter or Specifying |
port |
Specifies the port for the connections to the target database. When you specify a connection with Oracle-managed heterogeneous connectivity using the
|
|
The
When you specify a connection with Oracle-managed heterogeneous connectivity using the |
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 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):
Private Endpoint Link without a Wallet: To connect to an Oracle Database on a private endpoint without a wallet:
|
credential_name |
The name of a stored credential created with |
directory_name |
The directory for the Oracle-managed heterogeneous connectivity is preconfigured with a wallet that
contains most of the common trusted root and intermediate SSL
certificates. The 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):
In addition, to connect to an Autonomous Database with TCP, the
Private Endpoint Link without a Wallet: To connect to a target Oracle Database on a private endpoint without a wallet:
|
gateway_link |
Indicates if the database link is created to another Oracle Database or to an Oracle Database Gateway. If If When The default value for this parameter is
|
public_link |
Indicates if the database link is created as a public database link. To run The default value for this parameter is
|
private_target |
When a database link accesses a hostname that needs
to be resolved in a VCN DNS server, specify the
When The default value for this parameter is
|
|
Specify the parameter with the
For example:
When When |
Usage Notes
-
When you specify the
gateway_params
parameter, for somedb_type
values, additionalgateway_params
parameters are supported:db_type
Additional gateway_params
Valuesgoogle_analytics
When the
db_type
isgoogle_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
isgoogle_bigquery
, the credential you specify must be a Google OAuth credential (gcp_oauth2)
See CREATE_CREDENTIAL Procedure for more information.When
db_type
isgoogle_bigquery
, the parameterproject
is valid. This parameter specifies the project name forgoogle_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
ishive
, the parameterhttp_path
is valid. This parameter specifies the HttpPath value, if required, to connect to the Hive instance.salesforce
When the
db_type
issalesforce
, the parameter:security_token
is valid. A security token is a case-sensitive alphanumeric code. Supplying asecurity_token
value is required to access Salesforce. For example:gateway_params => JSON_OBJECT( 'db_type' value 'salesforce', 'security_token' value 'security_token_value' )
See Reset Your Security Token for more information.
servicenow
To connect to ServiceNow and get data you must supply the gateway parameters
directory_name
andfile_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 withdb_type
servicenow
, there are two supported options:-
Basic Authentication: you must supply the
gateway_params
parameterdb_type
with the value'servicenow'
, and supply thedirectory_name
andfile_name
parameters along with username/password type credentials. -
OAuth 2.0 Authentication: you must supply the
gateway_params
parameterdb_type
with the value'servicenow'
, and thedirectory_name
,file_name
, andtoken_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:
exec DBMS_CLOUD.get_object('servicenow_dir_cred', 'https://objectstorage.<...>/servicenow.rest','SERVICENOW_DIR');
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.
snowflake
When the
db_type
isSNOWFLAKE
, the optional parameters:role
,schema
, andwarehouse
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' )
-
-
When you use the
private_target
parameter, note that database links from an Autonomous Database to a database service that is on a private endpoint are only supported in commercial regions and US Government regions.This feature is enabled by default in all commercial regions.
This feature is enabled by default in US Government regions for newly provisioned databases.
For existing US Government databases on a private endpoint, if you want to create database links from an Autonomous Database to a target in a US Government region, please file a Service Request at Oracle Cloud Support and request to enable the private endpoint in government regions database linking feature.
US Government regions include the following:
- When connecting to a non-Oracle database, database linking is only supported if the target database is accessible through a public IP or a public hostname.
-
To run
DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK
with a user other than ADMIN, you need to grantEXECUTE
andCREATE DATABASE LINK
privileges to that user. For example, run the following command as ADMIN to grant privileges toatpc_user
:GRANT EXECUTE ON DBMS_CLOUD_ADMIN TO atpc_user; GRANT CREATE DATABASE LINK TO atpc_user;
In addition, when you create a Database Link in a schema other than the ADMIN schema, for example in a schema named
atpc_user
, theatpc_user
schema must own the credential you use withDBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK
. -
Only one wallet file is valid per directory specified with the
directory_name
parameter. You can only upload onecwallet.sso
at a time to the directory you choose for wallet files. This means with acwallet.sso
in a directory, you can only create database links to the databases for which the wallet in that directory is valid. To use multiplecwallet.sso
files with database links you need to create additional directories and put eachcwallet.sso
in a different directory.See Create Directory in Autonomous Database for information on creating directories.
-
To create a database link to an Autonomous Database, set
GLOBAL_NAMES
toFALSE
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 isTRUE
, thehostname
parameter specifies a private host inside the VCN.
Examples
BEGIN
DBMS_CLOUD.CREATE_CREDENTIAL
(
credential_name => 'DB_LINK_CRED',
username => 'adb_user',
password => 'password');
DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK
(
db_link_name => 'SALESLINK',
hostname => 'adb.eu-frankfurt-1.oraclecloud.com',
port => '1522',
service_name => 'example_medium.atpc.example.oraclecloud.com',
ssl_server_cert_dn => 'CN=atpc.example.oraclecloud.com,OU=Oracle BMCS FRANKFURT,O=Oracle Corporation,L=Redwood City,ST=California,C=US',
credential_name => 'DB_LINK_CRED');
END;
/
BEGIN
DBMS_CLOUD.CREATE_CREDENTIAL
(
credential_name => 'AWS_REDSHIFT_LINK_CRED',
username => 'NICK',
password => 'password'
);
DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK
(
db_link_name => 'AWSREDSHIFT_LINK',
hostname => 'example.com',
port => '5439',
service_name => 'example_service_name',
ssl_server_cert_dn => NULL,
credential_name => 'AWS_REDSHIFT_LINK_CRED',
gateway_params => JSON_OBJECT('db_type' value 'awsredshift'));
END;
/
BEGIN
DBMS_CLOUD.CREATE_CREDENTIAL
(
credential_name => 'PRIVATE_ENDPOINT_CRED',
username => 'db_user',
password => 'password'
);
DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK
(
db_link_name => 'PRIVATE_ENDPOINT_DB_LINK',
hostname => 'exampleHostname',
port => '1521',
service_name => 'exampleServiceName',
credential_name => 'PRIVATE_ENDPOINT_CRED',
ssl_server_cert_dn => NULL,
directory_name => NULL,
private_target => TRUE);
END;
/
BEGIN
DBMS_CLOUD.CREATE_CREDENTIAL
(
credential_name => 'GOOGLE_BIGQUERY_CRED',
params => JSON_OBJECT( 'gcp_oauth2' value JSON_OBJECT(
'client_id' value 'client_id',
'client_secret' value 'client_secret',
'refresh_token' value 'refresh_token' )));
DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK
(
db_link_name => 'GOOGLE_BIGQUERY_LINK',
hostname => 'example.com',
port => '443',
service_name => 'example_service_name',
credential_name => 'GOOGLE_BIGQUERY_CRED',
gateway_params => JSON_OBJECT(
'db_type' value 'google_bigquery',
'project' value 'project_name1' ));
END;
/
The table name you specify when you use SELECT
with
Google BigQuery or Google Analytics must be in quotes. For example:
SELECT * FROM "sales"@GOOGLE_BIGQUERY_LINK
Use the rac_hostnames
parameter with a target Oracle RAC database on
a private endpoint.
BEGIN
DBMS_CLOUD.CREATE_CREDENTIAL
(
credential_name => 'DB_LINK_CRED1',
username => 'adb_user',
password => 'password');
DBMS_CLOUD_ADMIN.CREATE_DATABASE_LINK
(
db_link_name => 'SALESLINK',
rac_hostnames => '["sales1-svr1.example.adb.us-ashburn-1.oraclecloud.com",
"sales1-svr2.example.adb.us-ashburn-1.oraclecloud.com",
"sales1-svr3.example.adb.us-ashburn-1.oraclecloud.com"]',
port => '1522',
service_name => 'example_high.adb.oraclecloud.com',
ssl_server_cert_dn => 'CN=adb.example.oraclecloud.com,OU=Oracle BMCS FRANKFURT,O=Oracle Corporation,L=Redwood City,ST=California,C=US',
credential_name => 'DB_LINK_CRED1',
directory_name => 'EXAMPLE_WALLET_DIR',
private_target => TRUE);
END;
/
Parent topic: Summary of DBMS_CLOUD_ADMIN Subprograms