DBMS_CLOUD_NOTIFICATION Package
The
DBMS_CLOUD_NOTIFICATION
package allows you to send messages or the output of a SQL query to a provider.
The supported providers with DBMS_CLOUD_NOTIFICATION are: Email,
Microsoft Teams, OCI Notifications (ONS), and Slack.
When you use the OCI Notifications service with
DBMS_CLOUD_NOTIFICATION package, only the
DBMS_CLOUD_NOTIFICATION.SEND_MESSAGE procedure is supported (the
DBMS_CLOUD_NOTIFICATION.SEND_DATA procedure is not supported).
Prerequisites
- Create a NAT gateway in the Virtual Cloud Network (VCN) where your Autonomous AI Database resources reside by following the instructions in Create a NAT Gateway in Oracle Cloud Infrastructure Documentation.
- After creating the NAT gateway, add a route rule and an
egress security rule to each subnet (in the VCN) where Autonomous AI Database resources reside
so that these resources can use the gateway to obtain a public key from
your Azure AD instance:
- Go to the Subnet Details page for the subnet.
- In the Subnet Information tab, click the name of the subnet's Route Table to display its Route Table Details page.
- In the table of existing Route Rules, check
whether there is already a rule with the following
characteristics:
- Destination: 0.0.0.0/0
- Target Type: NAT Gateway
- Target: The name of the NAT gateway you just created in the VCN
If such a rule does not exist, click Add Route Rules and add a route rule with these characteristics.
- Return to the Subnet Details page for the subnet.
- In the subnet's Security Lists table, click the name of the subnet's security list to display its Security List Details page.
- In the side menu, under Resources, click Egress Rules.
- In the table of existing Egress Rules, check
whether there is already a rule with the following
characteristics:
- Destination Type: CIDR
- Destination: 0.0.0.0/0
- IP Protocol: TCP
- Source Port Range: 443
- Destination Port Range: All
If such a rule does not exist, click Add Egress Rules and add an egress rule with these characteristics.
The HTTP Proxy settings in your environment must allow the database to access the cloud service provider.
Note:
The network configuration including the HTTP Proxy can only be edited until the Exadata Infrastructure is in Requires Activation state. Once it is activated, you cannot edit those settings.Setting up an HTTP Proxy for an already provisioned Exadata Infrastructure needs a Service Request (SR) in My Oracle Support. See Create a Service Request in My Oracle Support for details.
Summary of DBMS_CLOUD_NOTIFICATION Subprograms
This table summarizes the subprograms included in the package.
| Subprogram | Description |
|---|---|
|
Send SQL query output to a provider. |
|
|
Send a text message to a provider. |
SEND_DATA Procedure
The SEND_DATA procedure sends the
results of the specified query to a provider.
Syntax
DBMS_CLOUD_NOTIFICATION.SEND_DATA(
provider IN VARCHAR2,
credential_name IN VARCHAR2,
query IN CLOB,
params IN CLOB
);
Parameters
| Parameter | Description |
|---|---|
|
|
Specifies the provider. Valid values are: ' This parameter is mandatory. |
|
|
The name of the credential object to access the provider. For the email provider, the credential is the name of the credential of the SMTP approved sender that contains its username and password. For the msteams provider, the credential is the name of the credential. For the Slack provider, the credential's username
must be This parameter is mandatory. |
|
|
Specifies the SQL query to run. Results are sent to the provider. This parameter is mandatory. |
|
|
Specifies specific parameters for the For the provider type
For the provider type
For the provider type
This parameter is mandatory. |
Usage Notes
Use the procedure DBMS_CLOUD.CREATE_CREDENTIAL(credential_name, username, password) to create the credential object. See CREATE_CREDENTIAL Procedure for more information.
- For the
emailprovider, the user requires an SMTP connection endpoint for the Email Delivery server to obtainsmtp_host. The user also requires an SMTP approved sender and its credentials to authenticate with the Email Delivery server to obtain thecredential_name. SMTP connection must be configured, and SMTP credentials must be generated and approved. - For the
msteamsprovider, the user requires the Microsoft Teams App and a bot configured in it. The app needs to be published to the org and installed after obtaining approval from the admin from the admin center. The user also requires access forFiles.ReadWrite.AllandChannelSettings.Read.Allpermission for Graph API from their Azure Portal. To generate the required token, the user requiresbot_idin the username andbot_secretin the password. The maximum file size supported when usingDBMS_CLOUD_NOTIFICATION.SEND_DATAfor Microsoft Teams is 4MB. - For the
slackprovider, theusernamevalue can be any valid string and thepasswordis the Slack bot token.
Example
Send SQL output with the email provider:
BEGIN
DBMS_CLOUD.CREATE_CREDENTIAL(
credential_name => 'EMAIL_CRED',
username => 'username',
password => 'password');
END;
/
BEGIN
DBMS_CLOUD_NOTIFICATION.SEND_DATA(
provider => 'email',
credential_name => 'EMAIL_CRED',
query => 'SELECT tablespace_name FROM dba_tablespaces',
params => json_object('recipient' value 'mark@oracle.com, suresh@oracle.com',
'to_cc' value 'nicole@oracle.com1, jordan@oracle.com',
'to_bcc' value 'manisha@oracle.com',
'subject' value 'Test subject',
'type' value 'json',
'title' value 'mytitle',
'message' value 'This is the message',
'smtp_host' value 'smtp.email.example.com',
'sender' value 'approver_sender@oracle.com' )
);
END;
/Send SQL output with the msteams provider:
BEGIN
DBMS_CLOUD.CREATE_CREDENTIAL(credential_name => 'TEAMS_CRED',
username => 'bot_id',
password => 'bot_secret');
END;
/
BEGIN
DBMS_CLOUD_NOTIFICATION.SEND_MESSAGE(provider => 'msteams',
credential_name => 'TEAMS_CRED',
query => 'SELECT tablespace_name FROM dba_tablespaces',
params => json_object('tenant'value '5b743bc******c0286',
'team'value '0ae401*********5d2bd',
'channel'value '19%3a94be023*****%40thread.tacv2',
'title'value 'today',
'type'value 'csv'));
END;
/
Send SQL output with the slack provider:
BEGIN
DBMS_CLOUD.CREATE_CREDENTIAL(
credential_name => 'SLACK_CRED',
username => 'SLACK_TOKEN',
password => 'password');
END;
/
BEGIN
DBMS_CLOUD_NOTIFICATION.SEND_DATA(
provider => 'slack',
credential_name => 'SLACK_CRED',
query => 'SELECT username, account_status, expiry_date FROM USER_USERS WHERE rownum < 5',
params => json_object('channel' value 'C0....08','type' value 'csv'));
END;
/
SEND_MESSAGE Procedure
The procedure sends a text message to a provider.
Syntax
DBMS_CLOUD_NOTIFICATION.SEND_MESSAGE(
provider IN VARCHAR2,
credential_name IN VARCHAR2,
message IN CLOB,
params IN CLOB
);
Parameters
| Parameter | Description |
|---|---|
|
|
Specifies the provider. Valid values are: ' This parameter is mandatory. |
|
|
The name of the credential object to access the provider. For the email provider, the credential is the name of the credential of the SMTP approved sender that contains its username and password. For the msteams provider, the credential must contain the For the Slack provider, the credential's username must be For the This parameter is mandatory. |
|
|
Specifies the message text. This parameter is mandatory. |
|
|
Specifies specific parameters for the For the provider type
email, the valid parameters are:
For the provider type
msteams, the valid parameter is:
For the provider type
slack, the valid parameter is:
For the provider OCI Notifications with the type
oci, the valid parameters are:
With the
oci provider, there are
different possible endpoints for a message, based on the
subscriptions. The title parameter is treated
differently for different subscriptions:
The Channel ID is a unique ID for a channel and is different from the channel name. In Slack, when you view channel details you can find the Channel ID on the “About” tab. This parameter is mandatory. |
Usage Notes
Use the procedure DBMS_CLOUD.CREATE_CREDENTIAL(credential_name, username, password) to create the credential object. See CREATE_CREDENTIAL Procedure for more information.
- For the
emailprovider, the user requires an SMTP connection endpoint for the Email Delivery server to obtainsmtp_host. The user also requires an SMTP approved sender and its credentials to authenticate with the Email Delivery server to obtain thecredential_name. SMTP connection must be configured, and SMTP credentials must be generated and approved. - For the
msteamsprovider, the user requires the Microsoft Teams App and a bot configured in it. The app needs to be published to the org and installed after obtaining approval from the admin from the admin center. The user also requires access forFiles.ReadWrite.AllandChannelSettings.Read.Allpermission for Graph API from their Azure Portal. To generate the required token, the user requiresbot_idin the username andbot_secretin the password. - For the
slackprovider, theusernamevalue can be any valid string and thepasswordis the Slack bot token. -
The
DBMS_CLOUD_NOTIFICATIONsupports the OCI Notifications provider. See Overview of Notifications for details on the OCI Notifications provider.- To use the OCI Notifications provider, you must do the
following:
- Create a topic. See Creating a Topic for details on creating a topic
- Create the required subscriptions. See Creating a Subscription for details on creating a subscription.
- After you create the subscriptions, confirm the subscriptions. Messages are only published to confirmed subscriptions. See Confirming a Subscription for details on confirming subscriptions.
- The Autonomous AI Database instance, the credential (if you are using user credentials), and the subscription topic must all be located in the same region.
- Note the following limitations:
- Message Size Limit: The message size limit per request is 64KB. Messages exceeding this size cannot be sent or processed within a single request.
- Message Delivery Rate Limit: There are
different message delivery rate limits depending on the
protocol used.
emailprotocol: the limit is 10 messages per minute per endpoint.
This restriction may impact the speed at which messages can be transmitted and received.
- Transactions Per Minute (TPM) per-Tenancy Limit: There is a TPM limit of 60 per topic for this operation. This limit represents the maximum number of messages per minute that can be processed or handled for a given topic. Exceeding this limit may result in messages not being processed or processed at a slower rate.
- To use the OCI Notifications provider, you must do the
following:
Examples
Send a text message with the email provider:
BEGIN
DBMS_CLOUD.CREATE_CREDENTIAL(
credential_name => 'EMAIL_CRED',
username => 'username',
password => 'password');
END;
/
BEGIN
DBMS_CLOUD_NOTIFICATION.SEND_MESSAGE(
provider => 'email',
credential_name => 'EMAIL_CRED',
message => 'Subject content',
params => json_object('recipient' value 'mark@oracle.com, suresh@oracle.com',
'to_cc' value 'nicole@oracle.com, jordan@oracle.com',
'to_bcc' value 'manisha@oracle.com',
'subject' value 'Test subject',
'smtp_host' value 'smtp.email.example.com',
'sender' value 'approver_sender@oracle.com' )
);
END;
/Send a text message with the msteams provider:
BEGIN
DBMS_CLOUD.CREATE_CREDENTIAL(credential_name => 'TEAMS_CRED',
username => 'bot_id',
password => 'bot_secret');
END;
/
BEGIN
DBMS_CLOUD_NOTIFICATION.SEND_MESSAGE(
provider => 'msteams',
credential_name => 'TEAMS_CRED',
message => 'text from new teams api',
params => json_object('channel'value 'C0....08'),'region'value 'india');
END;
/
Send a text message with the slack provider:
BEGIN
DBMS_CLOUD.CREATE_CREDENTIAL(
credential_name => 'SLACK_CRED',
username => 'SLACK_TOKEN',
password => 'password');
END;
/
BEGIN
DBMS_CLOUD_NOTIFICATION.SEND_MESSAGE(
provider => 'slack',
credential_name => 'SLACK_CRED',
message => 'Send text from Autonomous AI Database.',
params => json_object('channel' value 'C0....08'));
END;
/
Send a text message with the OCI Notifications, type
oci provider:
BEGIN
DBMS_CLOUD_NOTIFICATION.SEND_MESSAGE(
provider => 'oci',
credential_name => 'OCI_CRED',
message => 'Text message for you.',
params => json_object('topic_ocid' value 'oci********pa',
'title' value 'Title for message subject' ));
END;
/