CREATE_DATABASE_LINK Procedure

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.

  • When the db_type value is snowflake the hostname is the Snowflake account identifier. To find your Snowflake account identifier, see Account Identifier Formats by Cloud Platform and Region.

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:

'["sales1-svr1.domain", "sales1-svr2.domain",
      "sales1-svr3.domain"]'

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:

  • awsredshift: use port 5439
  • azure: use port 1433
  • db2: use port 2500 for Db2 versions >= 11.5.6
  • db2: use port 5000 for Db2 versions <= 11.5.5
  • google_analytics: use port 443
  • google_bigquery: use port 443
  • hive: use port 433
  • mongodb: use port 27017
  • mysql: use port 3306
  • mysql_community: use port 3306
  • postgres: use port 5432
  • salesforce: use port 19937
  • servicenow: use port 443
  • snowflake: use port 443

service_name

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. Each connection string listed in the Connection string column includes a service_name entry with the connection string for the corresponding service. See View Connection Strings for an Autonomous Database 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
  • 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.

  • snowflake

    * See Usage Notes for additional supported gateway_params when db_type is snowflake.

  • 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.

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
    google_analytics

    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' )

    See Reset Your Security Token for more information.

    servicenow

    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_type servicenow, 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:

    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 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' )
  • 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 grant EXECUTE and CREATE DATABASE LINK privileges to that user. For example, run the following command as ADMIN to grant privileges to atpc_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, the atpc_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.

    See Create Directory in Autonomous Database for information on creating directories.

  • 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.

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;
/