Introduction
This article describes creating a PL/SQL package in your ATP database to execute SFTP operations.
SFTP (Secure File Transfer Protocol) is a network protocol that provides secure file transfer capabilities. It's built on the SSH (Secure Shell) protocol and offers encrypted command execution and data transfer over a network.
Oracle Integration Cloud supports SFTP to facilitate secure file transfers and automate data workflows, but PL/SQL running in Oracle Autonomous Database can also invoke SFTP via OCI Functions.
This Proof of Concept implementation re-uses much of the OCI SFTP function code on the following blog, extending it to be called from the database.
https://blogs.oracle.com/dataintegration/post/data-integration-and-sftp
PL/SQL API Examples
Once the code is installed and configured, you will be able to send, receive, and list files on a remote SFTP server, as shown in the following examples:
SFTP - GET
This example creates a CLOB from the text content of a file called MYDEMO_GET.csv located in the /home/opc/outbound directory on a remote SFTP server.
set serveroutput on
DECLARE
l_response CLOB;
l_content CLOB;
BEGIN
jmj_sftp_pkg.sftp_file_to_clob
(p_sftp_folder => '/home/opc/outbound'
,p_sftp_filename => 'mytargetdata.csv'
,p_content => l_content
,p_response => l_response);
DBMS_OUTPUT.PUT_LINE(DBMS_LOB.SUBSTR(l_response,1000,1));
DBMS_OUTPUT.PUT_LINE('FILE CONTENT');
DBMS_OUTPUT.PUT_LINE(DBMS_LOB.SUBSTR(l_content,1000,1));
END;
/
{"STATUS":200,"RESPONSE_BODY":"{'status': 400, 'info': 'Cannot find:/home/opc/outbound/mytargetdata.csv'}"}
FILE CONTENT
MY DATA TEST
SFTP - PUT
This example sends a CLOB text document to a file named MYDEMO_PUT.csv in the /home/opc/inbound directory on a remote SFTP server.
set serveroutput on
DECLARE
l_response CLOB;
BEGIN
jmj_sftp_pkg.clob_to_sftp
(p_content => q'[MYCLOB
,myclob]'
,p_sftp_folder => '/home/opc/inbound'
,p_sftp_filename => 'MYDEMO_PUT.csv'
,p_response => l_response);
DBMS_OUTPUT.PUT_LINE(DBMS_LOB.SUBSTR(l_response,1000,1));
END;
/
{"STATUS":200,"RESPONSE_BODY":"{'status': 200}"}
SFTP - LIST
This example lists the files in the /home/opc directory on a remote SFTP server.
SET SERVEROUTPUT ON
DECLARE
l_response CLOB;
BEGIN
jmj_sftp_pkg.list_files
(p_sftp_folder => '/home/opc'
,p_sftp_pattern => '*.csv'
,p_response => l_response);
dbms_output.put_line(dbms_lob.substr(l_response,1000,1));
FOR rec IN (SELECT column_value filename
FROM TABLE
(jmj_sftp_pkg.file_list_as_array(l_response))) LOOP
dbms_output.put_line(rec.filename);
END LOOP;
END;
/
{"STATUS":200,"RESPONSE_BODY":"['mytargetdata.csv', 'mytargetdata2.csv', 'mytargetdata3.csv', 'mytargetdataFROMOCI.csv']"}
mytargetdata.csv
mytargetdata2.csv
mytargetdata3.csv
Solution Components
The main components supporting the demo PLSQL API are:
OCI Storage Bucket. An OCI bucket is used to store inbound and outbound files.
OCI Vault. An OCI vault is configured to store the SSH key used for the SFTP connection as a secret.
OCI Function. The function uses the Paramiko and OCI libraries to execute SFTP using SSH. The OCI bucket is used for file storage, and the SSH key is retrieved from the OCI vault. Paramiko is an open-source Python implementation of the SSHv2 protocol1.
DBMS_CLOUD and DBMS_CLOUD_CATALOG Packages. These packages are used to access the OCI function from the ATP database.
JMJ_SFTP_PKG. This custom package is a wrapper around the OCI function to simplify calls from PL/SQL.
Configuration and Code
OCI Storage Bucket
Create an OCI storage bucket with inbound and outbound folders.
Note your bucket’s namespace; this will be used in later steps.
OCI Vault
The example in this blog assumes your SFTP server is accessed using a passwordless SSH key, so you can access it using the following syntax:
$ sftp -i $HOME/.ssh/mykey.key myuser@myserver
Last login: Sun Oct 13 13:29:23 on ttys000
$ sftp -i $HOME/.ssh/mykey.key user@host
Connected to host.
sftp>
The SSH private key is stored as a secret in an OCI vault.
Create a vault, then add the secret using the entire contents of your secret key file including the opening -----BEGIN RSA PRIVATE KEY----- and the closing -----END RSA PRIVATE KEY-----.
-----BEGIN RSA PRIVATE KEY-----
MIIEowIBAAKCAQEAxGF… AND SO ON ...
-----END RSA PRIVATE KEY-----
Note the SSH Key Secret OCID; this is used in later steps.
OCI Function
Creation of an OCI python function requires three files:
func.py (function source code, with an entry point named handler)
func.yaml (function configuration file, including the function name, fun_jmj_sftp_demo)
requirements.txt (list of required python libraries, such as oci and paramiko)
The demo code is located here: https://github.com/greendragoncloud/jmjsftpdemo
The easiest way to create an OCI function is via Cloud Shell. Before you begin, you’ll need to gather the following information:
OCI Region (e.g. us-phoenix-1)
OCI Compartment ID
OCI Bucket Namespace
Your Cloud Infrastructure Registry address (e.g. phx.ocir.io)
An Auth Token for your OCI user. This is used to login to the OCI Registry from Cloud Shell.
Under Functions - Applications, create the application that will hold your OCI function:
Then, start Cloud Shell and build your function.
# Set Demo Application Context
fn use context <REGION>
fn update context oracle.compartment-id <COMPARTMENT OCID>
fn update context registry <OCI REGISTRY>/<NAMESPACE>/sftp-demo-app
# Login to Registry (e.g. phx.ocir.io) using your Auth Token
docker login -u '<your namespace>/<your OCI username>' <OCI REGISTRY>
# Create sftp-demo-app shell
fn init --runtime python sftp-demo-app
cd sftp-demo-app
# Replace code in the following files with the
# code from https://github.com/greendragoncloud/jmjsftpdemo
vi func.py
vi func.yaml
vi requirements.txt
# Deploy application function (this takes a while to run - like 10min)
fn -v deploy --app sftp-demo-app
Back in the OCI console, locate the Function within sftp-demo-app and copy the Function OCID (note, not the Application OCID).
Create a dynamic OCI group to identify the function.
Create a Resource Principal policy allowing dynamic group members to access the vault, bucket, etc.
The OCI function can then be tested from Cloud Shell.
Stage a file on the SFTP home directory named mytargetdata.csv.
The SFTP username, host, and SSH key secret OCID are used to connect to the SFTP server.
The following Cloud Shell command copies the mytargetdata.csv file to the inbound directory in the storage bucket.
echo '{"operation":"PUT","sftp_file":"mytargetdata.csv", "object_name":"inbound/mytargetdata.csv","bucket":"<BUCKET NAME>", "user":"<USERNAME>", "host":"<HOST>", "secret":"<VAULT SECRET>"}' | fn invoke sftp-demo-app fun_jmj_sftp_demo
All being well, you should see a successful 200 status response as below:
$ echo '{"operation":"PUT","sftp_file":"mytargetdata.csv", "object_name":"inbound/mytargetdataTEST1.csv","bucket":"gdsftp", "user":"opc", "host":"myhost", "secret":"ocid1.vaultsecret.oc1.phx.xxxx"}' | fn invoke sftp-demo-app fun_jmj_sftp_demo
{'status': 200}
The file can also be seen in the inbound directory within the OCI bucket.
Add Function Catalog to Database
In OCI, create an OIC API Key and note the resulting User OCID, Fingerprint, Tenancy OCID, OCI Region, and API Private Key Content.
Create a DBMS_CLOUD credential using these values - this will be used to sync the function catalogs.
BEGIN
DBMS_CLOUD.CREATE_CREDENTIAL (
credential_name => 'OCI_KEY_CRED',
user_ocid => '<USER OCID>',
tenancy_ocid => '<TENANCY OCID>',
private_key => 'MIIEvgIBADANBgk API KEY CONTENT WITHOUT HEADER AND FOOTER
1uLrQRk42q9U1M8osqGH4fGl',
fingerprint => '<API KEY FINGERPRINT>');
END;
/
Create the function catalog from OCI:
BEGIN
DBMS_CLOUD_FUNCTION.CREATE_CATALOG (
credential_name => 'OCI_KEY_CRED',
catalog_name => 'OCI_DEMO_CATALOG',
service_provider => 'OCI',
cloud_params => '{"region_id":"<API KEY REGION>","compartment_id":"<OCI COMPARTMENT OCID>"}'
);
END;
/
Create PL/SQL functions in the database from the OCI Functions:
BEGIN
DBMS_CLOUD_FUNCTION.SYNC_FUNCTIONS (
catalog_name => 'OCI_DEMO_CATALOG'
);
END;
/
SELECT object_name
FROM sys.all_objects
WHERE owner = 'DEMOSFTP'
AND object_type = 'FUNCTION'
AND object_name = 'FUN_JMJ_SFTP_DEMO';
OBJECT_NAME
__________________
FUN_JMJ_SFTP_DEMO
Test the PL/SQL function works successfully.
SET SERVEROUTPUT ON
DECLARE
v_return CLOB;
BEGIN
v_return := FUN_JMJ_SFTP_DEMO('{"operation":"PUT","sftp_file":"mytargetdata.csv", "object_name":"inbound/mytargetdataTEST2.csv","bucket":"<BUCKET NAME>", "user":"<USERNAME>", "host":"<HOST>", "secret":"<VAULT SECRET>"}');
dbms_output.put_line(dbms_lob.substr(v_return,1000,1));
END;
/
{"STATUS":200,"RESPONSE_BODY":"{'status': 200}"}
All being well, you should get the success message above and see the file inbound/mytargetdataTEST2.csv in the inbound directory of the storage bucket.
Compile PL/SQL
Edit the jmj_sftp_constants_pkg package specification to match your test SFTP server and compile to the database.
CREATE OR REPLACE PACKAGE jmj_sftp_constants_pkg AS
-- Target SFTP Credentials
GC_HOSTNAME CONSTANT VARCHAR2(240) := '<MY HOST>';
GC_SFTP_USER CONSTANT VARCHAR2(100) := '<MY USER>';
GC_SFTP_SSH_SECRET_OCID CONSTANT VARCHAR2(1000) := '<MY SECRET OCID>';
-- OCI Storage
GC_OCI_KEY CONSTANT VARCHAR2(100) := 'OCI_KEY_CRED';
GC_BUCKET CONSTANT VARCHAR2(1000) := '<MY BUCKET>';
GC_BUCKET_INBOUND_FOLDER CONSTANT VARCHAR2(1000) := 'inbound';
GC_BUCKET_OUTBOUND_FOLDER CONSTANT VARCHAR2(1000) := 'outbound';
GC_OCI_NAMESPACE CONSTANT VARCHAR2(100) := '<MY NAMESPACE>';
GC_OCI_OBJECT_BASE_URL CONSTANT VARCHAR2(100) := 'https://objectstorage.<MY REGION>.oraclecloud.com';
END jmj_sftp_constants_pkg;
/
Compile the code objects:
FILENAME_TABLE_TYPE.sql
JMJ_SFTP_CONSTANTS_PKS.sql
JMJ_SFTP_PKS.sql
JMJ_SFTP_PKB.sql
JMJ_SFTP_PKG has the following subprograms:
PROCEDURE oci_file_to_sftp - Send a file already in an OCI bucket to the SFTP.
PROCEDURE sftp_file_to_oci - Pull a file from the SFTP to an OCI bucket.
PROCEDURE clob_to_sftp - Create a text file from the CLOB, put it into the OCI bucket and send to the SFTP.
PROCEDURE sftp_file_to_clob - Pull a file from the SFTP to an OCI bucket, then return it’s text content.
PROCEDURE list_files - List files on the SFTP folder.
PROCEDURE file_list_as_array - Pipelined function parsing the response from list_files into a TABLE, allowing simple looping and select.
Test PL/SQL
Run the following tests to make sure the API is working:
- List Files - Matched file.
SET SERVEROUTPUT ON
-- LIST FILE
DECLARE
l_response CLOB;
BEGIN
jmj_sftp_pkg.list_files
(p_sftp_folder => '/home/opc'
,p_sftp_pattern => 'mytargetdata.csv'
,p_response => l_response);
dbms_output.put_line(dbms_lob.substr(l_response,1000,1));
FOR rec IN (SELECT column_value filename FROM TABLE(jmj_sftp_pkg.file_list_as_array(l_response))) LOOP
dbms_output.put_line(rec.filename);
END LOOP;
END;
/
{"STATUS":200,"RESPONSE_BODY":"['mytargetdata.csv']"}
mytargetdata.csv
- List Files - Unmatched file pattern.
SET SERVEROUTPUT ON
-- LIST FILE
DECLARE
l_response CLOB;
BEGIN
jmj_sftp_pkg.list_files
(p_sftp_folder => '/home/opc'
,p_sftp_pattern => 'mytargetdataMISSING.csv'
,p_response => l_response);
dbms_output.put_line(dbms_lob.substr(l_response,1000,1));
FOR rec IN (SELECT column_value filename FROM TABLE(jmj_sftp_pkg.file_list_as_array(l_response))) LOOP
dbms_output.put_line(rec.filename);
END LOOP;
END;
/
{"STATUS":200,"RESPONSE_BODY":null}
- Get Files - Pull matched file into the default OCI bucket
set serveroutput on
DECLARE
l_response CLOB;
BEGIN
jmj_sftp_pkg.sftp_file_to_oci
(p_sftp_filename => 'mytargetdata.csv'
,p_oci_object_name => 'mytargetdataFROMSFTP2.csv'
,p_response => l_response);
DBMS_OUTPUT.PUT_LINE(DBMS_LOB.SUBSTR(l_response,1000,1));
END;
/
{"STATUS":200,"RESPONSE_BODY":"{'status': 200}"}
Review the file in the OCI bucket inbound folder:
- Get Files - Missing File
DECLARE
l_response CLOB;
BEGIN
jmj_sftp_pkg.sftp_file_to_oci
(p_sftp_filename => 'mytargetdataXX.csv'
,p_oci_object_name => 'mytargetdataFROMSFTP2XX.csv'
,p_response => l_response);
DBMS_OUTPUT.PUT_LINE(DBMS_LOB.SUBSTR(l_response,1000,1));
END;
/
{"STATUS":200,"RESPONSE_BODY":"{'status': 400, 'info': 'Cannot find:mytargetdataXX.csv'}"}
Further Ideas
There a lots of ways the demo code can be extended and improved:
Add SFTP commands to delete files, create directories etc.
Include the ability to specify a non-standard SFTP port, i.e. one that is not 22.
Extend the PL/SQL API to allow the caller to specify the host, post and secret OCID, instead of using the defaults in the jmj_sftp_constants_pkg package.
Support for PGP encryption/decryption using the pgpy python library.
Improvements for error trapping/logging.
Use of a resource principal to sync the functions down to the Oracle database, replacing the user credential.
Overload the API to support password based authentication.
Summary
The proof of concept solution above shows how to use SFTP within Oracle Autonomous Database and Oracle APEX.
APEX is a powerhouse integration and extension tool for Oracle ERP Cloud. It can connect to ERP Cloud REST APIs, store data, display data with and without synchronization, call SOAP and REST web services, host REST web services, zip and unzip files, run background jobs, process approvals via workflow and create embedded page extensions in ERP Cloud.
A missing element was the ability to send and receive files using SFTP. While SFTP can be seen as an older style of integration, it is often required in banking and payroll environments, or any third party that doesn’t support alternatives such as REST web services.
The solution above fixes this gap. The OCI python function allows SFTP to be used without needing Oracle Integration Cloud. If SFTP is your main reason for adding Oracle Integration Cloud to your Oracle footprint … it could be that you don’t need Oracle Integration Cloud in your implementation.
The Green Dragon
The cover image is of the 14th century Green Dragon pub in Wymondham, Norfolk, UK. Sadly this is now 4,928 miles away from where I live but I still manage to visit 4 or 5 times a year.
No particular reason for choosing the image, other than the fact that I love the pub - and I like to think that Joel would have too.