Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
@@ -0,0 +1,187 @@
--
-- NAME:
-- provision_autonomous_database - Provision an Autonomous Database in OCI
--
-- DESCRIPTION:
-- This function provisions an Autonomous Database (ADB-S) in a specified
-- compartment within OCI. It takes workload type, compute and storage
-- configurations, and database options as inputs, builds the request object,
-- and calls DBMS_CLOUD_OCI_DB_DATABASE.CREATE_AUTONOMOUS_DATABASE to create
-- the database. The result is returned as a structured JSON response (CLOB).
--
-- PARAMETERS:
-- compartment_name (IN) - Name of the compartment where the ADB will be provisioned
-- db_name (IN) - Database name (uppercase enforced)
-- display_name (IN) - Optional display name for the database
-- workload_type (IN) - Workload type: OLTP, ADW, JSON, or APEX
-- ecpu_count (IN) - Number of ECPUs
-- storage_tb (IN) - Storage size in TB
-- region (IN) - Target OCI region for provisioning
-- data_guard (IN) - Enable/Disable Data Guard ('ENABLED' / 'DISABLED')
-- credential_name (IN) - Name of the stored credential (for DBMS_CLOUD)
-- database_pwd (IN) - Admin password for the database
-- is_auto_scaling_enabled (IN) - Flag for auto-scaling (1 = enabled, 0 = disabled)
--
-- RETURNS:
-- CLOB containing JSON object with keys:
-- - status : 'success' or 'error'
-- - message : Status message
-- - status_code : HTTP status code from OCI API (if success)
-- - database_ocid : OCID of the provisioned database (if success)
-- - database_name : Name of the provisioned database
-- - workload_type : Workload type used for provisioning
-- - ecpu_count : Number of ECPUs
-- - region : Provisioned region
-- - data_guard_enabled : 'ENABLED' or 'DISABLED'
--
-- EXAMPLE:
-- SELECT provision_adbs_tool(
-- compartment_name => 'COMP_DB',
-- db_name => 'MYDB',
-- display_name => 'My ADB',
-- workload_type => 'OLTP',
-- ecpu_count => 4,
-- storage_tb => 2,
-- region => 'us-ashburn-1',
-- data_guard => 'DISABLED',
-- credential_name => 'OCI_CRED',
-- database_pwd => 'MySecurePwd#123',
-- is_auto_scaling_enabled => 1
-- )
-- FROM dual;
--
-- NOTES:
-- - Relies on get_compartment_ocid_by_name function to resolve the
-- compartment OCID from its name.
-- - Password must meet OCI’s complexity requirements.
-- - Returns JSON error object if provisioning fails.
-- - Uses DBMS_CLOUD_OCI to interact with OCI APIs.
--


CREATE OR REPLACE FUNCTION provision_autonomous_database(
compartment_name IN VARCHAR2,
db_name IN VARCHAR2,
display_name IN VARCHAR2 default NULL,
workload_type IN VARCHAR2,
ecpu_count IN NUMBER,
storage_tb IN NUMBER,
region IN VARCHAR2,
data_guard IN VARCHAR2,
credential_name IN VARCHAR2,
database_pwd IN VARCHAR2,
is_auto_scaling_enabled IN NUMBER
) RETURN CLOB
IS
in_details dbms_cloud_oci_database_create_autonomous_database_base_t :=
dbms_cloud_oci_database_create_autonomous_database_base_t();
resp dbms_cloud_oci_db_database_create_autonomous_database_response_t;
result_json JSON_OBJECT_T := JSON_OBJECT_T();
l_workload VARCHAR2(20);
compartment_id VARCHAR2(256);
l_compartment_name VARCHAR2(256);

BEGIN


SELECT
JSON_VALUE(
get_compartment_ocid_by_name(credential_name, compartment_name),
'$.compartment_ocid'
) AS comp_ocid
INTO compartment_id
FROM dual;

-- Map workload types
CASE UPPER(workload_type)
WHEN 'OLTP' THEN l_workload := 'OLTP';
WHEN 'ADW' THEN l_workload := 'DW';
WHEN 'JSON' THEN l_workload := 'JSON';
WHEN 'APEX' THEN l_workload := 'APEX';
ELSE l_workload := 'OLTP';
END CASE;

-- Setup the database details
in_details.compartment_id := compartment_id;
in_details.db_name := UPPER(db_name);
in_details.compute_model := 'ECPU';
in_details.compute_count := ecpu_count;
in_details.data_storage_size_in_t_bs := storage_tb;
in_details.admin_password := database_pwd; -- In production, use secure password generation
in_details.db_workload := l_workload;
in_details.display_name := display_name;
in_details.is_auto_scaling_enabled := is_auto_scaling_enabled;

-- Enable Data Guard if requested
IF UPPER(data_guard) = 'ENABLED' THEN
in_details.is_data_guard_enabled := 0;
result_json.put('data_guard_enabled', 'ENABLED');
ELSE
in_details.is_data_guard_enabled := 0;
result_json.put('data_guard_enabled', 'DISABLED');
END IF;

-- Create the database
BEGIN
resp := DBMS_CLOUD_OCI_DB_DATABASE.CREATE_AUTONOMOUS_DATABASE(
create_autonomous_database_details => in_details,
credential_name => credential_name,
region => region
);

-- Build success response
result_json.put('status', 'success');
result_json.put('message', 'Autonomous Database provisioning initiated successfully');
result_json.put('status_code', resp.status_code);
result_json.put('database_ocid', resp.response_body.id);
result_json.put('database_name', db_name);
result_json.put('workload_type', l_workload);
result_json.put('ecpu_count', ecpu_count);
result_json.put('region', region);


EXCEPTION
WHEN OTHERS THEN
result_json.put('status', 'error');
result_json.put('message', 'Failed to provision Autonomous Database: ' || SQLERRM);
END;

RETURN result_json.to_clob();

END provision_autonomous_database;
/

--Drop tool if exists

DECLARE
l_tool_count NUMBER;
BEGIN
-- Check if the tool exists
SELECT COUNT(*)
INTO l_tool_count
FROM USER_AI_AGENT_TOOLS
WHERE TOOL_NAME = 'ADBS_PROVISIONING_TOOL';

-- Drop only if it exists
IF l_tool_count > 0 THEN
DBMS_CLOUD_AI_AGENT.DROP_TOOL('ADBS_PROVISIONING_TOOL');
END IF;
END;
/

BEGIN
DBMS_CLOUD_AI_AGENT.CREATE_TOOL(
tool_name => 'ADBS_PROVISIONING_TOOL',
attributes => '{"instruction": "This tool provisions an Oracle Autonomous Database.'||
'Use LIST_SUBSCRIBED_REGIONS_TOOL to check all available regions that the user subscribes to. ' ||
'You need confirm which region to use with the user if there are multiple regions ' ||
'If there is only one region, you can use it by default. ' ||
'Use LIST_COMPARTMENTS_TOOL and provide the list of compartments as bullet list.You need confirm which compartment to use with the user.'||
'Use ADBS_PROVISIONING_TOOL to provision database only after you have gathered ALL required information. ' ||
'Get all the inputs at once ' ||
'Must get final confirmation by summarizing all choices before provisioning. ",
"function" : "provision_autonomous_database"}',
description => 'Tool for provisioning Oracle Autonomous Databases'
);
END;
/
Original file line number Diff line number Diff line change
@@ -0,0 +1,129 @@
--
-- NAME:
-- get_compartment_ocid - Retrieve the OCID of a given compartment
--
-- DESCRIPTION:
-- This function retrieves the OCID (Oracle Cloud Identifier) for a specific
-- compartment by name within a tenancy. It internally calls the
-- list_compartments function to fetch all available compartments, then
-- searches for the compartment with the given name. The result is returned
-- as a structured JSON object (CLOB).
--
-- PARAMETERS:
-- credential_name (IN) - Name of the stored credential (for DBMS_CLOUD)
-- compartment_name (IN) - Name of the compartment to search for
--
-- RETURNS:
-- CLOB containing JSON object with keys:
-- - status : 'success' or 'error'
-- - compartment_name : Name of the matched compartment (if success)
-- - compartment_ocid : OCID of the matched compartment (if success)
-- - message : Error message if compartment not found or request fails
--
-- EXAMPLE:
-- SELECT get_compartment_ocid('OCI_CRED', 'COMP_DB')
-- FROM dual;
--
-- NOTES:
-- - Relies on the list_compartments function to fetch compartment details.
-- - Returns an error JSON if the compartment name is not found or if an
-- unexpected error occurs.
-- - Uses DBMS_CLOUD.send_request and JSON parsing APIs.
--


create or replace FUNCTION get_compartment_ocid(
credential_name IN VARCHAR2,
compartment_name IN VARCHAR2
) RETURN CLOB
IS
l_comp_json_clob CLOB;
l_result_json JSON_OBJECT_T := JSON_OBJECT_T();
l_compartments JSON_ARRAY_T;
l_comp_obj JSON_OBJECT_T;
l_name VARCHAR2(200);
l_ocid VARCHAR2(200);
found BOOLEAN := FALSE;
l_compartment_name VARCHAR2(256);
BEGIN

-- Call existing list_compartments function
l_comp_json_clob := list_compartments(credential_name);

-- Parse returned JSON object
l_result_json := JSON_OBJECT_T.parse(l_comp_json_clob);

IF l_result_json.get('status').to_string() = '"success"' THEN
-- Extract compartments array
l_compartments := l_result_json.get_Array('compartments');

-- Loop through compartments to find matching name
FOR i IN 0 .. l_compartments.get_size() - 1 LOOP
l_comp_obj := JSON_OBJECT_T(l_compartments.get(i));
l_name := l_comp_obj.get_string('name');

IF l_name = compartment_name THEN
l_ocid := l_comp_obj.get_string('id');
found := TRUE;
EXIT;
END IF;
END LOOP;

IF found THEN
l_result_json := JSON_OBJECT_T();
l_result_json.put('status', 'success');
l_result_json.put('compartment_name', compartment_name);
l_result_json.put('compartment_ocid', l_ocid);
ELSE
l_result_json := JSON_OBJECT_T();
l_result_json.put('status', 'error');
l_result_json.put('message', 'Compartment name "' || compartment_name || '" not found');
END IF;

ELSE
-- Forward error from list_compartments function
RETURN l_comp_json_clob;
END IF;

RETURN l_result_json.to_clob();

EXCEPTION
WHEN OTHERS THEN
l_result_json := JSON_OBJECT_T();
l_result_json.put('status', 'error');
l_result_json.put('message', 'Unexpected error: ' || SQLERRM);
RETURN l_result_json.to_clob();
END get_compartment_ocid;
/

--Drop tool if exists

DECLARE
l_tool_count NUMBER;
BEGIN
-- Check if the tool exists
SELECT COUNT(*)
INTO l_tool_count
FROM USER_AI_AGENT_TOOLS
WHERE TOOL_NAME = 'GET_COMPARTMENT_OCID_TOOL';

-- Drop only if it exists
IF l_tool_count > 0 THEN
DBMS_CLOUD_AI_AGENT.DROP_TOOL('GET_COMPARTMENT_OCID_TOOL');
END IF;
END;
/

--Create tool

BEGIN
DBMS_CLOUD_AI_AGENT.CREATE_TOOL(
tool_name => 'GET_COMPARTMENT_OCID_TOOL',
attributes => '{
"instruction": "This tool accepts OCI credentials and a compartment name, and returns the OCID of that compartment.",
"function": "get_compartment_ocid"
}',
description => 'Tool to get compartment OCID by name'
);
END;
/
Loading