Azure SQL data in APEX

One of the big announcements this month was the Oracle Database Service for Microsoft Azure. With this new fully managed service, Azure customers can seamlessly build Azure applications using the high-performance, high-availability, and automated management of Oracle Database services such as Autonomous Database running on OCI. Did you know that even before this announcement you could have a REST interface to Azure SQL through ORDS?

In this article I’ll show you how I have data from a hosted Azure SQL database used in an APEX application all made possible through ORDS. Although I’m using released products it is important to point out that using ORDS with SQL Server is not officially supported. Therefore, although you can use this approach, you mind find a use case that does not work. For example, an unsupported column data type.

Key components in this article

This is your goal, sample data from Azure SQL rendered in an APEX application

Azure SQL Sample Database

To get started, if you do not have an Azure SQL database already, head over to https://portal.azure.com/ and set yours up. By default you will get a functional, but empty database. In my case, I selected Sample for Use existing data option in the Additional Settings section of the create database sequence so that I had some data in place.

Create your database with sample data
SQL Server and Database

The overall process from zero involves creating an SQL Server ( pobdemo in my case ) and an SQL Database ( pobsample in my case ) which can be accessed outside of Azure.

You will also need to create some logins and users to access the database so Azure Data Studio, or some other client for working with Azure SQL will be needed. The administrator user should not be used for anything more than managing the database.

One login will be used by ORDS to verify the pool connection configuration. It does not require any specific privileges in the database just the ability to make a connection over JDBC. The login could be any value but for consistency we’ll call it ORDS_PUBLIC_USER

CREATE LOGIN ORDS_PUBLIC_USER WITH PASSWORD = '< keep this secret >'; 

The other login and database user is for the account that will be used to interact with the database. In this example: ords_demo

CREATE LOGIN ords_demo WITH PASSWORD = '< keep this secret >'; 
CREATE USER ords_demo FROM LOGIN ords_demo;
ALTER ROLE db_datareader ADD MEMBER [ords_demo];
ALTER ROLE db_datawriter ADD MEMBER [ords_demo];

Configure ORDS

Now that we have our database accounts let’s configure ORDS. In my case I already have an ORDS instance setup with the default pool configured for my Oracle 19c database and APEX is installed.

The directory that I extracted the ORDS 22.2.0 distribution to is ~/Downloads/ords-22.2.0.172.1758/ and the configuration directory is ~/Documents/Personal/azure_sql/. That directory looks like this:

├──databases
│   ├── azure_sql
│   │   ├── pool.xml
│   │   └── wallet
│   │       └── cwallet.sso
│   └── default
│       ├── pool.xml
│       └── wallet
│           └── cwallet.sso
├── global
│   └── settings.xml

The configuration for the azure_sql pool was achieved as follows while the configuration directory is the working directory. Note that you will need to know your JDBC connection string from your Azure Dashboard. You’ll find that under Show database connection strings.

See the ‘Show database connection strings’ to get your JDBC connection string

Armed with that information it is time to configure your azure_sql pool:

~/Downloads/ords-22.2.0.172.1758/bin/ords config --db-pool azure_sql set db.connectionType customurl

~/Downloads/ords-22.2.0.172.1758/bin/ords config --db-pool azure_sql set db.customURL jdbc:sqlserver://<rest of the JDBC connection string from Azure dashboard>

~/Downloads/ords-22.2.0.172.1758/bin/ords config --db-pool azure_sql set jdbc.driverName com.microsoft.sqlserver.jdbc.SQLServerDriver

~/Downloads/ords-22.2.0.172.1758/bin/ords config --db-pool azure_sql set db.credentialsSource request

~/Downloads/ords-22.2.0.172.1758/bin/ords config --db-pool azure_sql set restEnabledSql.active true

~/Downloads/ords-22.2.0.172.1758/bin/ords config --db-pool azure_sql set db.username ORDS_PUBLIC_USER

Every command entry should show a message confirming that the setting was applied. Now to set the password for ORDS_PUBLIC_USER. That should be treated as a secret:

~/Downloads/ords-22.2.0.172.1758/bin/ords config --db-pool azure_sql secret db.password

Enter the database password: 
Confirm password: 
The setting named: db.password was set to: ****** in configuration: azure_sql

When done, assuming that you are using the same pool name, your databases/azure_sql/pool.xml should look like this but without the comments:

<?xml version="1.0" encoding="UTF-8" standalone="no"?>
<!DOCTYPE properties SYSTEM "http://java.sun.com/dtd/properties.dtd">
<properties>
<comment>Saved on Fri Oct 11 11:21:28 IST 2019</comment>
<entry key="db.connectionType">customurl</entry>
<entry key="db.customURL">jdbc:sqlserver://your_sql_server.database.windows.net:1433;database=your_sql_db;encrypt=true;trustServerCertificate=false;hostNameInCertificate=*.database.windows.net;loginTimeout=30;</entry>
<entry key="jdbc.driverName">com.microsoft.sqlserver.jdbc.SQLServerDriver</entry>
<!-- username for account required to verify pool connection details are
correct. User does not require special privileges -->
<entry key="db.username">ORDS_PUBLIC_USER</entry>
<!-- Credentials in the request will be used to create injected DB connection
and ORDS Role will be SQL Developer. Authentication mode will be ANY_SCHEMA -->
<entry key="db.credentialsSource">request</entry>
<!-- REST Enabled SQL must be enabled -->
<entry key="restEnabledSql.active">true</entry>
</properties>

One of the settings is the JDBC driver to use ( jdbc.driverName ) and that is com.microsoft.sqlserver.jdbc.SQLServerDriver but ORDS does not ship with that JDBC driver. Download the SQL Server JDBC driver and copy the Java 11 jar into the ORDS lib/ext directory. In my case that is ~/Downloads/ords-22.2.0.172.1758/lib/ext

Time to startup ORDS in standalone mode and verify the connection pool is loaded correctly.

~/Downloads/ords-22.2.0.172.1758/bin/ords serve

ORDS: Release 22.2 Production on Fri Jul 29 13:52:06 2022

Copyright (c) 2010, 2022, Oracle.
...
2022-07-29T13:52:10.561Z INFO        Configuration properties for: |azure_sql|lo|
gopherProxySet=false
awt.toolkit=sun.lwawt.macosx.LWCToolkit
java.specification.version=11
...
2022-07-29T13:52:45.126Z INFO        Oracle REST Data Services initialized
Oracle REST Data Services version : 22.2.0.r1721758
Oracle REST Data Services server info: jetty/9.4.46.v20220331
Oracle REST Data Services java info: Java HotSpot(TM) 64-Bit Server VM 11.0.13+10-LTS-370

Test REST Enabled SQL

If you have gotten this far without errors that means ORDS can connect to the Azure SQL database using the db.username account and therefore the custom connection aspect of the pool configuration is correct. Now to confirm the REST Enabled SQL can use that pool configuration to access the database with basic authentication credentials provided. For that we’ll use the login that is a user in the database and cURL to submit a GET request

curl -u ords_demo http://localhost:8080/ords/azure_sql/_/sql
Enter host password for user 'ords_demo': ********
{
 "database_product_name":"Microsoft SQL Server",
 "database_product_version":"12.00.312",
 "database_major_version":12,
 "database_minor_version":0,
 "env":{"defaultTimeZone":"UTC","ordsVersion":"22.2.0.r1721758"}
}

We could just stop here and just use REST Enabled SQL directly with our Azure SQL database but let’s do something really interesting with APEX, which is probably why you’re here. First, a few words about how APEX works with SQL Server natively: it does not.

SQL Server Syntax

APEX has powerful support for consuming data over REST services including the ability to construct queries for Oracle and MySQL which are executed through ORDS REST Enabled SQL. This allows for a very dynamic no code approach to developing applications. See previous article How to use the Oracle Database Tools Service to provide MySQL data to APEX on this topic.

APEX does not provide the same level of support for SQL Server. Although one can configure an ORDS pool so that REST Enabled SQL can be used, APEX will not recognise the database type when you try create the REST Enabled SQL reference. All is not lost though. The work around is to write ORDS REST Services which have the specific SQL Server statements. Those services make the REST Enabled SQL calls and return the response. They are effectively custom wrapper services.

APEX calls custom ORDS Service which calls ORDS REST Enabled SQL which talks to Azure SQL

Now, on with the APEX adventure…

APEX Workspace

In my local Oracle database I have APEX installed and have created a workspace called AZURE which is using the AZURE database schema. That schema has been REST Enabled too.

The ‘azure’ workspace is in the ‘AZURE’ schema and that schema is REST Enabled

This AZURE database schema in the Oracle database will have the REST Services ( module/template/handler ) defined and those services will make the REST Enabled SQL calls. For convenience these services are not secured but obviously should be if they are to be used in a real world scenario. What is secured is the REST Enabled SQL endpoint. A username and password for the database user in Azure SQL must be provided but rather than having that in plain text in the handler source we’ll use an APEX Web Credential that the AZURE schema will have access to.

APEX Web Credentials

Web Credentials are a really useful feature in APEX that allows you to store authentication credentials for external REST services or REST Enabled SQL services. We’ll use that in our ORDS Service handler pl/sql block but more on that later. First, let’s define a Web Credential in the workspace.

Web Credential with Azure SQL username and password

There are a few things to highlight about the above Credentials for Azure

  • The Static Identifier is Credentials_for_Azure – we will refer to that later in the ORDS handler
  • The Authentication Type is Basic Authentication – the REST Enabled SQL endpoint uses this Authentication Type
  • The Valid for URLs specifies host.docker.internal as the server address. Remember how I said that Oracle 19c database was running in docker? Localhost would just point to the running container in my case. This is how the database can address the host machine ( my laptop ) which is running ORDS.

Stating the obvious here but it’s significant that you can change the username and password in the Web Credential without modifying the handler. Just thought I’d mention that.

And now with the Web Credential in place lets define the services in the AZURE schema that will submit SQL queries over REST Enabled SQL to Azure SQL database.

Wrapper Services

We’re going to define two services which follow this pattern: send a query, return the response. This relies on the APEX_WEB_SERVICE.MAKE_REST_REQUEST function to create the POST request, with Content-Type application/sql, and return the payload response. The previously defined Web Credentials are used to authenticate those requests.

The module, templates and handlers can be defined in APEX or SQL Developer Web. One module with Base Path /sales/ along with two templates: customer_count_by_country and order_header.

One module with /sales/ Base Path and two templates
Of course the ORDS REST Services can be edited in SQL Developer Web too

Handler for /sales/customer_count_by_country

This handler executes an aggregation query to get the number of customers with a Main Office in each country.

DECLARE
  l_clob    CLOB;
  l_result  VARCHAR2(32767);
BEGIN
  APEX_WEB_SERVICE.g_request_headers.delete();
  APEX_WEB_SERVICE.g_request_headers(1).name := 'Content-Type';
  APEX_WEB_SERVICE.g_request_headers(1).value := 'application/sql';
 
  l_clob := APEX_WEB_SERVICE.make_rest_request(
    p_url         => 'http://host.docker.internal:8080/ords/azure_sql/_/sql',
    p_http_method => 'POST',
    p_credential_static_id => 'Credentials_for_Azure',
    p_body => 'select address.CountryRegion, count(CustomerAddress.CustomerID) as "CustomerCount"
from SalesLT.Address, SalesLt.CustomerAddress
where CustomerAddress.AddressID = Address.AddressID and CustomerAddress.AddressType = ''Main Office''
group by address.CountryRegion'
  );

HTP.print(l_clob);

END;

Handler for /sales/order_header

This handler executes a basic query to get all records from the SalesOrderHeader table.

DECLARE
  l_clob    CLOB;
  l_result  VARCHAR2(32767);
BEGIN
  APEX_WEB_SERVICE.g_request_headers.delete();
  APEX_WEB_SERVICE.g_request_headers(1).name := 'Content-Type';
  APEX_WEB_SERVICE.g_request_headers(1).value := 'application/sql';
  -- Get the XML response from the web service.
  l_clob := APEX_WEB_SERVICE.make_rest_request(
    p_url         => 'http://host.docker.internal:8080/ords/azure_sql/_/sql',
    p_http_method => 'POST',
    p_credential_static_id => 'Credentials_for_Azure',
    p_body => 'SELECT * FROM [SalesLT].[SalesOrderHeader]'
  );
  HTP.print(l_clob);
END;

Service Handler Walkthrough

Keep in mind that these handlers execute in the AZURE database schema which is the schema for the APEX Workspace we’ll create the Data Source references and APEX Application in. Both handlers follow these steps:

  • Set the Content-Type header to application/sql
  • Make a POST request with Web Credentials for authentication and a query
  • Write the REST Enabled SQL result to the HTTP Response stream.

There’s no validation on the response, or parsing that response to change the structure. We’ll leave it to APEX to figure out how to parse the response payload.

Now is it a good time to verify that the two handlers work. We can invoke them through cURL. Remember the schema alias is azure, the module base path is /sales/ so the URL will begin with http://localhost:8080/ords/azure/sales/

curl http://localhost:8080/ords/azure/sales/customer_count_by_country

{
   "env" : {
      "defaultTimeZone" : "UTC"
   },
   "items" : [
      {
         "response" : [],
         "result" : 0,
         "resultSet" : {
            "count" : 3,
            "hasMore" : false,
            "items" : [
               {
                  "countryregion" : "Canada",
                  "customercount" : 106
               },
               {
                  "countryregion" : "United Kingdom",
                  "customercount" : 38
               },
               {
                  "countryregion" : "United States",
                  "customercount" : 263
               }
            ],
            "limit" : 10000,
            "metadata" : [
               {
                  "columnClassName" : "java.lang.String",
                  "columnName" : "CountryRegion",
                  "columnTypeName" : "nvarchar",
                  "isNullable" : 0,
                  "jsonColumnName" : "countryregion",
                  "precision" : 50,
                  "scale" : 0
               },
               {
                  "columnClassName" : "java.lang.Integer",
                  "columnName" : "CustomerCount",
                  "columnTypeName" : "int",
                  "isNullable" : 1,
                  "jsonColumnName" : "customercount",
                  "precision" : 10,
                  "scale" : 0
               }
            ],
            "offset" : 0
         },
         "statementId" : 1,
         "statementPos" : {
            "endLine" : 5,
            "startLine" : 1
         },
         "statementText" : "select address.CountryRegion, count(CustomerAddress.CustomerID) as \"CustomerCount\"\nfrom SalesLT.Address, SalesLt.CustomerAddress\nwhere CustomerAddress.AddressID = Address.AddressID and CustomerAddress.AddressType = 'Main Office'\ngroup by address.CountryRegion",
         "statementType" : "query"
      }
   ]
}
curl http://localhost:8080/ords/azure/sales/order_header

{
   "env" : {
      "defaultTimeZone" : "UTC"
   },
   "items" : [
      {
         "response" : [],
         "result" : 0,
         "resultSet" : {
            "count" : 32,
            "hasMore" : false,
            "items" : [
               {
                  "accountnumber" : "10-4020-000609",
                  "billtoaddressid" : 1092,
                  "comment" : null,
                  "creditcardapprovalcode" : null,
                  "customerid" : 29847,
                  "duedate" : "2008-06-13T00:00:00Z",
                  "freight" : 22.0087,
                  "modifieddate" : "2008-06-08T00:00:00Z",
                  "onlineorderflag" : false,
                  "orderdate" : "2008-06-01T00:00:00Z",
                  "purchaseordernumber" : "PO348186287",
                  "revisionnumber" : 2,
                  "rowguid" : "89E42CDC-8506-48A2-B89B-EB3E64E3554E",
                  "salesorderid" : 71774,
                  "salesordernumber" : "SO71774",
                  "shipdate" : "2008-06-08T00:00:00Z",
                  "shipmethod" : "CARGO TRANSPORT 5",
                  "shiptoaddressid" : 1092,
                  "status" : 5,
                  "subtotal" : 880.3484,
                  "taxamt" : 70.4279,
                  "totaldue" : 972.785
               },
...trimmed for brevity...
            ],
            "limit" : 10000,
            "metadata" : [
               {
                  "columnClassName" : "java.lang.Integer",
                  "columnName" : "SalesOrderID",
                  "columnTypeName" : "int",
                  "isNullable" : 0,
                  "jsonColumnName" : "salesorderid",
                  "precision" : 10,
                  "scale" : 0
               },
...trimmed for more brevity...
            ],
            "offset" : 0
         },
         "statementId" : 1,
         "statementPos" : {
            "endLine" : 2,
            "startLine" : 1
         },
         "statementText" : "SELECT * FROM [SalesLT].[SalesOrderHeader]",
         "statementType" : "query"
      }
   ]
}

Now is a good time to reiterate that the ORDS REST Services are not protected and if the Azure SQL database you’re connecting to had any sensitive data it should be protected but that’s not the focus of this article.

As you can see from the above tests, these are REST Enabled SQL responses with lots of information about the statement executed, the metadata of the columns when all we’re really interested in is the data at items.resultSet.items. That will be relevant when we look into Data Sources.

APEX Data Sources

Let’s create a basic APEX application called Azure SQL with just the defaults.

Basic application with a Home page

Once created, edit the application and navigate to the Shared Components section.

Shared Components is where Data Source references can be defined

The Data Source references section has various options for getting data over REST.

Data Sources section has lots of options

Define REST Data Sources for both endpoints but specify their REST Data Source Type as Simple HTTP.

Note the URL has host.docker.internal has the server name because the Oracle database is running in Docker

Remember how the REST Enabled SQL response structure contains lots of metadata? For Data Profile specify the Row Selector as items.resultSet.items so that APEX can find the array of rows that it can interrogate for Data Profile.

The Row Selector must be specified to find the data in the response

Two Data Source references must be defined. In my case I also defined synchronisation for the AzureSalesHeader Data Source to pull in data to a local table. I’ll cover that in a separate article.

Data Source references that are Simple HTTP types

Now let’s put those to use. Edit the Home page and drop in a Chart and a Classic Report to the body. The Chart will use REST Source AzureCustomerCountByCountry and the Classic Report will use REST Source AzureSalesHeader.

Source for the components are REST Source

The Classic Report is very basic and includes the column list from the AzureSalesHeader Data Source.
For the Customers chart the Series Source Location should be set to Region Source so that it inherits the source from the Chart and columns can be selected.

For the Chart series Source Location is Region Source and the Column Mapping for what to show

With all that in place, run the application to see the Home page with the Chart and Classic Report. Note that by following the default application setup a login is required. Just use the same workspace developer username and password.

Pie Chart and Classic Report with live data from Azure SQL

Conclusion

In theory ORDS REST Enabled SQL can be used with any database that you have a JDBC driver for which will run on Java 11. In practice, only Oracle RDBMS and Oracle Cloud MySQL is supported. Keeping that in mind, the capability of bringing in data from other databases, such as Azure SQL and using it in your APEX applications opens up a lot of integration possibilities.

What projects does this make possible for you now? I’d be really interested to hear about it.

In future articles I will cover synchronisation, joining local with remote data as well as going beyond just select statements.

Addendum to the original article…if you are looking for an approach that is supported you can create database links from Autonomous Database to Non-Oracle databases.

How to use the Oracle Database Tools Service to provide data to APEX

Oracle Database Tools Service does a lot and makes a lot of things possible. At its core is the concept of a connection library that allows you to define the connection details for a database and then reuse that definition in a range of scenarios: SQL Worksheet, SQLcl, Java or Python clients and more.

Providing you with the tools to make Oracle Cloud Infrastructure cloud database connections secure, easy, and reusable for development, DevOps processes, and SQL access.

https://www.oracle.com/database/tools-service/

One of those hosted services that also becomes available through the Database Tools Service is ORDS REST Enabled SQL. The SQL Worksheet in Oracle Database Tools Service and Oracle Database Actions both use the ORDS REST Enabled SQL service to run the given SQL statements in the corresponding database. All you need to construct the relevant service URL is the OCID for your Database Tools Connection definition and a little information about the Oracle Cloud region.

REST Enabled SQL Service URL

Connection definition for the HR schema in an Autonomous Database

In the above Frankfurt region the connection OCID is a really long string ocid1.databasetoolsconnection.oc1.eu-frankfurt-1.amaaaaaamdjeo4qagsuv6lv3acwsomething2y26ya

The corresponding REST Enabled SQL service endpoint is https://sql.dbtools.eu-frankfurt-1.oci.oraclecloud.com/20201005/ords/ocid1.databasetoolsconnection.oc1.eu-frankfurt-1.amaaaaaamdjeo4qagsuv6lv3acwsomething2y26ya/_/sql

The https://sql.dbtools.eu-frankfurt-1.oci.oraclecloud.com/20201005/ords/ prefix will be different for each region. You can use your console URL to guide you on how to construct the URL prefix. For this example, the console URL starts with https://console.eu-frankfurt-1.oraclecloud.com/

The pattern is https://sql.dbtools.< region >.oci.oraclecloud.com/20201005/ords/< connection ocid >/_/sql

But wait, my console URL looks different!

It is possible that your console URL actually starts with https://cloud.oracle.com/ and has the region as a parameter. For example ?region=ap-mumbai-1. That still gives you enough information to construct the REST Enabled SQL endpoint:
https://sql.dbtools.ap-mumbai-1.oci.oraclecloud.com/20201005/ords/ocid1.databasetoolsconnection.oc1.ap-mumbai-1.amaaaaaamdjeo4qagsuv6lv3acwsomething2y26ya/_/sql

Web Credentials

Now that you have the URL for the endpoint you will have to prove to the Database Tools Service who you are. That’s where an API Key is needed. You can define one in your User Settings.

API Key defined with Private Key PEM

With that API Key you can go to your APEX workspace and record the credential details.

Create an Oracle Cloud Infrastructure specific Web Credentials entry in your APEX workspace

APEX REST Enabled SQL Reference

With the OCI Web Credentials specified in the APEX workspace you can now create a REST Enabled SQL Service reference. This brings together the URL you identified earlier and the credentials that will be used to sign each request.

The reference is essentially a name, a URL and credentials definition

Off the charts!

So far, so simple. Now let’s use that REST Enabled SQL reference in an APEX application. In this example we’ll use the HR Connection REST Enabled SQL reference to create a bar chart of employee salaries.

Note the Source for this chart is REST Enabled SQL and the Table Name is specified as EMPLOYEES
Data from the REST Enabled SQL query displayed in a chart

Conclusion

What you have seen is database data to APEX chart in a quick and secure manner. Using the Database Tools Service connection details you can revoke the connection, change the underlying database connection details without having to update the APEX application.

Through a series of screenshot images you’ve been introduced to functionality from a range of Oracle products. In summary:

The Take the time to discover what else you can build with these services available to you. Many of them FREE!

ORDS Pool Usage Chart with APEX

ORDS provides insight to its database pool cache through the ORDS Instance API. This is extremely useful for monitoring the database connection usage on a particular ORDS instance. Such information could reveal how close ORDS gets to using up its available connections as a result of the requests coming in and their correspond SQL statements. That would indicate if more resources or optimisations are required.

The ORDS Instance API is intended for System Administrator use in the deployed infrastructure. Users with this role are extremely powerful. Therefore the credentials for such users are extremely sensitive and how they are used should be carefully considered.

This article introduces an example application which shows how APEX could be used to retrieve the Database Pool Cache information with ORDS System Administrator credentials secured. The number of available and borrowed connections for both the APEX_PUBLIC_USER and ORDS_PUBLIC_USER database accounts are retrieved every 10 minutes and a chart of the data displayed.

Showing a snapshot of pool usage every 10 minutes

Configure ORDS Instance API

Stating the obvious here, but to get the database pool cache information from ORDS, the Instance API has to be enabled first. The steps for doing so are already covered in the product documentation but I’m going to call it out as prerequisite for this exercise. Also, just to repeat the product documentation, using the credentials file ( also known as: File Based User Repository ) is not intended for production use.

Keep secrets secret

In my case I defined a user called sysadmin with the System Administrator role and whose credentials will be provided on every request. To keep the credentials separate from the APEX application I’ll define them in the workspace and state that these credentials can only be used for Instance API requests. That means the same credentials could not be used for other ORDS services such as the Oracle Home information and DBCA operations available through the Database API environment category of services.

Specify Web Credentials for sysadmin in Workspace Utilities

About that URL

At this point you’ve probably noticed the host.docker.internal portion of the URL. I’m using that because I’m running the database in a docker container hosted on the same machine that ORDS is running on. If I was to refer to localhost, that would be the docker container. The host.docker.internal identifies the machine hosting the container. Docker provides a number of other networking options here but this is the simplest for my setup.

In this case, ORDS standalone is running on port 8080 on that machine. We’ll use this URL again when defining a REST Data Source in our APEX application.

>java -jar ords.war standalone

2021-10-11T09:23:33.448Z INFO        HTTP and HTTP/2 cleartext listening on host: localhost port: 8080
2021-10-11T09:23:33.466Z INFO        Disabling document root because the specified folder does not exist: /scratch/ords-21.3.0.266.1100/config/ords/standalone/doc_root
2021-10-11T09:23:35.052Z INFO        Configuration properties for: |apex|pu|
database.api.enabled=true
db.connectionType=basic
db.hostname=localhost
db.port=1521
db.servicename=orclpdb1
feature.sdw=true
instance.api.enabled=true
restEnabledSql.active=true
db.password=******
db.username=ORDS_PUBLIC_USER

2021-10-11T09:23:35.053Z WARNING     *** jdbc.MaxLimit in configuration |apex|pu| is using a value of 10, this setting may not be sized adequately for a production environment ***
2021-10-11T09:23:35.054Z WARNING     *** jdbc.InitialLimit in configuration |apex|pu| is using a value of 3, this setting may not be sized adequately for a production environment ***
2021-10-11T09:23:36.053Z INFO        Configuration properties for: |apex||
database.api.enabled=true
db.connectionType=basic
db.hostname=localhost
db.port=1521
db.servicename=orclpdb1
misc.compress=
misc.defaultPage=apex
security.disableDefaultExclusionList=false
security.maxEntries=2000
security.requestValidationFunction=wwv_flow_epg_include_modules.authorize
security.validationFunctionType=plsql
db.password=******
db.username=APEX_PUBLIC_USER
resource.templates.enabled=true

2021-10-11T09:23:36.054Z WARNING     *** jdbc.MaxLimit in configuration |apex|| is using a value of 10, this setting may not be sized adequately for a production environment ***
2021-10-11T09:23:36.054Z WARNING     *** jdbc.InitialLimit in configuration |apex|| is using a value of 3, this setting may not be sized adequately for a production environment ***
2021-10-11T09:23:37.664Z INFO        Oracle REST Data Services initialized
Oracle REST Data Services version : 21.3.0.r2661100
Oracle REST Data Services server info: jetty/9.4.43.v20210629

Permit the request

At this stage it should be clear that we have a database running in a docker container and ORDS standalone running on the same machine which is hosting that container. ORDS has two pools configured to talk to the database at localhost:1521/orclpdb1.

In my case, I started an Oracle Enterprise Edition 19c database using the image from https://container-registry.oracle.com/ and installed APEX 21.1 to it.

If we were to go ahead and define the APEX REST Data Source at this stage we might encounter this error once we try to test it.

ORA-24247: network access denied by access control list (ACL)

Put simply, the APEX application does not have permission to make a request from the database to the host on port 8080. A network access control list must be defined. In my case I am running APEX 21.1 and therefore will grant access to the APEX_210100 database user. If you have a different version of APEX, you will have a different user in this scenario. To define the ACL and assign it run this script in the database…

DECLARE
  l_principal VARCHAR2(20) := 'APEX_210100';
BEGIN
  DBMS_NETWORK_ACL_ADMIN.create_acl (
    acl          => 'hosted_ords_acl.xml', 
    description  => 'An ACL for the hosted ORDS instance',
    principal    => l_principal,
    is_grant     => TRUE, 
    privilege    => 'connect',
    start_date   => SYSTIMESTAMP,
    end_date     => NULL);

  DBMS_NETWORK_ACL_ADMIN.assign_acl (
    acl         => 'hosted_ords_acl.xml',
    host        => 'host.docker.internal', 
    lower_port  => 8080,
    upper_port  => 8080); 

  COMMIT;
END;

APEX Application

For this example I created a simple database application with just a home page which requires authentication. This means that for someone to access the charts they must authenticate with APEX. At no point will they need the sysadmin credentials. The home page will display two charts showing data from a synchronisation table which is appended to every 10 minutes with the connection pool state at that point in time.

Create a simple APEX application

REST Data Source

In that application Shared Components define a REST Data Source which will automatically make a call every 10 minutes to add records to a table.

Select the REST Data Sources link in Shared Components/Data Sources

The REST Data Source type should be Simple HTTP because there’s no need for pagination or to perform any additional operations such as POST, PUT, or DELETE. Note that the Base URL is the same value as specified for the Web Credential earlier and that ORDS System Administrator web credential is selected in the Authentication section.

Define a Simple HTTP data source for host.docker.internal

Synchronisation must also be defined so that the REST call is made on a regular basis to append to a DATABASE_POOL_CACHE table. Going through the synchronisation setup wizard will result in this table being created.

Define the synchronisation frequency

The table name DATABASE_POOL_CACHE comes from the /database-pools-cache/ portion of the endpoint URL. You can choose to name it whatever suits you but you will be referring to this table later when constructing the charts.

CREATE TABLE  "DATABASE_POOL_CACHE" 
   (	"ID" VARCHAR2(4000), 
	"CREATED" TIMESTAMP (6) WITH TIME ZONE, 
	"VALIDITY" VARCHAR2(4000), 
	"BORROWEDCONNECTIONSCOUNT" NUMBER, 
	"AVAILABLECONNECTIONSCOUNT" NUMBER, 
	"APEX$SYNC_STEP_STATIC_ID" VARCHAR2(255), 
	"APEX$ROW_SYNC_TIMESTAMP" TIMESTAMP (6) WITH TIME ZONE
   )
/

Every ten minutes the APEX REST Data Source synchronisation job will run. It will identify any synchronisation activity that is required and start making the necessary web service requests.

It won’t take long before there are records like this in the synchronisation table

The ID column contains the pool identifier. This column, along with the BORROWEDCONNECTIONSCOUNT, AVAILABLECONNECTSIONCOUNT and APEX$ROW_SYNC_TIMESTAMP will be used to chart the connection pool usage over time.

Application Home Page

Edit the home page and add a Chart instance onto the Content Body. You can first define a chart for |apex|| and then duplicate it for |apex|pu|. These represent the APEX_PUBLIC_USER and ORDS_PUBLIC_USER connection pools respectively.

For the |apex|| chart go to the Attributes section and set it as a Line chart with a 600 second automatic refresh.

Then define a Borrowed series which uses the BORROWEDCONNECTIONSCOUNT column on DATABASE_POOL_CACHE as the value to display. The Order By specifying the Row Sync Timestamp ensures that data is shown in the correct sequence.

Similarly, define a series called Available using AVAILABLECONNECTIONSCOUNT column. Note that the Where Clause restricts the records to just those applicable to the |apex||.

When duplicating this chart for |apex|pu| it is the Where Clause that must change.

The end result with two charts on the Content Body

Conclusion

You now have an APEX Application with a Home Page that is secured. Data from the DATABASE_POOL_CACHE table is shown in a chart for both pools. That data is obtained from the ORDS Instance API database pool cache endpoint. If additional pools are added to the ORDS instance the information for them will also appear in the table. However, they way this APEX application is configured it will not display any information about such new pools unless you specifically add a chart for it.

Here’s the key point though, no information about the sysadmin user credentials are exposed outside of the workspace.

Now try it out. Define an ORDS Based REST Service and use something like JMeter to call it multiple times concurrently over 20 or 30 minutes. You should see the number of borrowed connections go up and the number of available connections go down. Once the high number of requests ends the available connections increases but then drops down as the unused database connections are closed.

If going through those few APEX Application creation steps is too much you can just import the application using this ORDS_Database_Cache_APEX_App.sql script.