8i | 9i | 10g | 11g | 12c | 13c | 18c | 19c | 21c | 23c | Misc | PL/SQL | SQL | RAC | WebLogic | Linux

Home » Articles » Misc » Here

SQLcl : Deploying Oracle Application Express (APEX) Applications using the SQLcl implementation of Liquibase

This article demonstrates how to deploy Oracle Application Express (APEX) applications using the SQLcl implementation of Liquibase.

This is a rewrite of a Liquibase article, but using SQLcl instead of the regular Liquibase client.

Related articles.

SQLcl (runOracleScript)

Running a change log with the basic sqlFile tag has many of the same limitations in both the SQLcl implementation of Liquibase and the default JDBC connector in the regular Liquibase client. It is fine for running simple SQL files, but it struggles with more complex files, especially those including SQL*Plus-specific settings and commands. This makes trying to load an Oracle APEX workspace or application export file impossible without a lot of editing. In the past your options were as follows.

Both options were quite frankly annoying.

The runOracleScript tag solves this buy running the named script using the SQLcl engine, which understands most of the SQL*Plus settings and commands. This allows you to deploy unmodified APEX workspace and application export files with just a few minor changes to the relevant change log.

This article provides a simple example of how you might approach that.

Assumptions

This article makes some assumptions about what you have available and your preexisting knowledge.

The Demo Files

The demos will use the following files.

+--- normal
|   +--- changelogs
|   |   +--- changelog_master_dev_ws.xml
|   |   +--- changelog_setup_demo_app_sqlcl.xml
|   |   +--- changelog_setup_tab1.xml
|   |   +--- changelog_setup_tab2.xml
|   +--- scripts
|   |   +--- demo_app_f101.sql
|   |   +--- get_tab1_count.sql
|   |   +--- tab1.sql
|   |   +--- tab1_seq.sql
|   |   +--- tab2.sql
|   |   +--- tab2_seq.sql
+--- privileged
|   +--- changelogs
|   |   +--- changelog_create_dev_workspace_sqlcl.xml
|   |   +--- changelog_create_dev_workspace_user.xml
|   |   +--- changelog_master.xml
|   +--- scripts
|   |   +--- create_apex_priv_user.sql
|   |   +--- create_dev_workspace.sql
|   |   +--- create_dev_workspace_user.sql
|   |   +--- remove_apex_priv_user.sql
|   |   +--- remove_dev_workspace.sql
|   |   +--- remove_dev_workspace_user.sql

They are available from a GitHub repository (here).

The privileged and normal operations are kept in a single repository for this demonstration, but you may wish to split the privileged operations off into a separate repository, depending the the trust level in your organisation.

Create Privileged User

In any deployment process you will occasionally need to make changes that require elevated privileges. You can choose to leave these as manual operations, or you can automate them with Liquibase. In this example we want a user called APEX_PRIV_USER to perform privileged actions and administer the APEX instance. You may prefer to split these roles into separate users.

The "create_apex_priv_user.sql" file contains the commands to create this privileged user. The addition of APEX_ADMINISTRATOR_ROLE allows the user to administer the APEX instance. In this case we've included the DBA role to allow other privileged actions, which is rather excessive. You need to grant the least privileges necessary for the user to perform the operations you need, which may vary on a project-by-project basis. Needless to say, this should really have a strong password and have a restricted audience.

create user apex_priv_user identified by apex_priv_user quota unlimited on users;
grant dba, apex_administrator_role to apex_priv_user;

With this user in place, all the following actions can be performed using SQLcl.

Create a New APEX Workspace

We are going to split the creation of a new workspace into two parts.

We use the "create_dev_workspace_user.sql" script to create a new user for the workspace.

create user dev_ws identified by dev_ws quota unlimited on users;
grant create session, create cluster, create dimension, create indextype,
      create job, create materialized view, create operator, create procedure,
      create sequence, create synonym, create table,
      create trigger, create type, create view to dev_ws;

The "changelog_create_dev_workspace_user.xml" change log for this action is shown below. It uses a standard sqlFile tag to reference the script.

<?xml version="1.0" encoding="UTF-8"?> 
<databaseChangeLog
  xmlns="http://www.liquibase.org/xml/ns/dbchangelog"
  xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
  xsi:schemaLocation="http://www.liquibase.org/xml/ns/dbchangelog
                      http://www.liquibase.org/xml/ns/dbchangelog/dbchangelog-3.6.xsd">

    <changeSet author="tim" id="create_dev_workspace_user">
      <sqlFile dbms="oracle"
               endDelimiter=";"
               path="../scripts/create_dev_workspace_user.sql"
               relativeToChangelogFile="true"
               splitStatements="true"
               stripComments="false"/>
    </changeSet>
</databaseChangeLog>

The "create_dev_workspace.sql" file contains an APEX workspace definition. This was manually created in an APEX environment, then exported so it could be replayed in other environments. The "changelog_create_dev_workspace_sqlcl.xml" change log for this action is shown below. It uses the runOracleScript tag to reference the script, with the script name included as CDATA under the source tag. Notice also the "dbchangelog-ext" namespace for the Oracle extentions.

<?xml version="1.0" encoding="UTF-8"?>
<databaseChangeLog 
  xmlns="http://www.liquibase.org/xml/ns/dbchangelog" 
  xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" 
  xmlns:n0="http://www.oracle.com/xml/ns/dbchangelog-ext" 
  xsi:schemaLocation="http://www.liquibase.org/xml/ns/dbchangelog
                      http://www.liquibase.org/xml/ns/dbchangelog/dbchangelog-3.6.xsd">
  <changeSet author="tim" id="create_dev_workspace_v1" failOnError="true">
    <n0:runOracleScript objectName="create_dev_workspace" ownerName="DEV_WS" sourceType="FILE">
      <n0:source>
        <![CDATA[/git/oraclebase/liquibase_sqlcl_apex_demo/privileged/scripts/create_dev_workspace.sql]]>
      </n0:source>
    </n0:runOracleScript>
  </changeSet>
</databaseChangeLog>

We add these two changesets to the "changelog_master.xml" file for the privileged user.

<?xml version="1.0" encoding="UTF-8"?>
<databaseChangeLog
  xmlns="http://www.liquibase.org/xml/ns/dbchangelog"
  xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
  xsi:schemaLocation="http://www.liquibase.org/xml/ns/dbchangelog
                      http://www.liquibase.org/xml/ns/dbchangelog/dbchangelog-3.6.xsd">
  <include file="./changelog_create_dev_workspace_user.xml" relativeToChangelogFile="true"/>
  <include file="./changelog_create_dev_workspace_sqlcl.xml" relativeToChangelogFile="true"/> 
</databaseChangeLog>

We connect to the APEX_PRIV_USER user and issue the lb update command relevant to your SQLcl version.

conn apex_priv_user/apex_priv_user@//localhost:1521/pdb1
Connected.
SQL> 

-- >= 22.3
lb update -changelog-file /git/oraclebase/liquibase_sqlcl_apex_demo/privileged/changelogs/changelog_master.xml
SQL>

-- 20.2 - 22.2
lb update -changelog /git/oraclebase/liquibase_sqlcl_apex_demo/privileged/changelogs/changelog_master.xml
SQL>

-- < v20.2
lb update /git/oraclebase/liquibase_sqlcl_apex_demo/privileged/changelogs/changelog_master.xml
SQL>

If you check your APEX instance, you will see the DEV_WS workspace is now present. You can log into it with the "Dev1Workspace2!" password, then you'll be prompted to reset it.

Create a New APEX Application

With the APEX workspace in place, we can create some objects and an APEX application to reference those objects. Most of the SQL files for the supporting objects are straight from this article, so I won't waste time explaining them again. They create some tables that will be referenced by the APEX application. Instead we will focus on the APEX-specific piece.

The "demo_app_f101.sql" file contains a really basic APEX application called "Demo App", which we'll use to demonstrate the deployment process. The "changelog_setup_demo_app_sqlcl.xml" change log shows how to load this file. Similar to the workspace example, we use the runOracleScript tag to reference the script, with the script name included as CDATA under the source tag.

<?xml version="1.0" encoding="UTF-8"?>
<databaseChangeLog 
  xmlns="http://www.liquibase.org/xml/ns/dbchangelog" 
  xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" 
  xmlns:n0="http://www.oracle.com/xml/ns/dbchangelog-ext" 
  xsi:schemaLocation="http://www.liquibase.org/xml/ns/dbchangelog
                      http://www.liquibase.org/xml/ns/dbchangelog/dbchangelog-3.6.xsd">
  <changeSet author="tim" id="demo_app_v1" runOnChange="true" failOnError="true">
    <n0:runOracleScript objectName="demo_app" ownerName="DEV_WS" sourceType="FILE">
      <n0:source>
        <![CDATA[/git/oraclebase/liquibase_sqlcl_apex_demo/normal/scripts/demo_app_f101.sql]]>
      </n0:source>
    </n0:runOracleScript>
  </changeSet>
</databaseChangeLog>

We include this change log into the "changelog_master_dev_ws.xml" file, which is the master change log for this environment.

<?xml version="1.0" encoding="UTF-8"?>
<databaseChangeLog
  xmlns="http://www.liquibase.org/xml/ns/dbchangelog"
  xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
  xsi:schemaLocation="http://www.liquibase.org/xml/ns/dbchangelog
                      http://www.liquibase.org/xml/ns/dbchangelog/dbchangelog-3.6.xsd">
  <include file="./changelog_setup_tab1.xml" relativeToChangelogFile="true"/> 
  <include file="./changelog_setup_tab2.xml" relativeToChangelogFile="true"/> 
  <include file="./changelog_setup_demo_app_sqlcl.xml" relativeToChangelogFile="true"/> 
</databaseChangeLog>

We connect to the DEV_WS user and issue the lb update command relevant to your SQLcl version.

CONN dev_ws/dev_ws@//localhost:1521/pdb1

-- >= 22.3
lb update -changelog-file /git/oraclebase/liquibase_sqlcl_apex_demo/normal/changelogs/changelog_master_dev_ws.xml
SQL>

-- 20.2 - 22.2
lb update -changelog /git/oraclebase/liquibase_sqlcl_apex_demo/normal/changelogs/changelog_master_dev_ws.xml
SQL>

-- < v20.2
lb update /git/oraclebase/liquibase_sqlcl_apex_demo/normal/changelogs/changelog_master_dev_ws.xml
SQL>

If you check your APEX instance, you will see the DEV_WS workspace now includes an application called "Demo App".

Clean Up

The "remove_*.sql" files have been provided to allow you to clean up the demo. Collectively they perform the following commands.

-- Run as the APEX_PRIV_USER.
begin
  apex_instance_admin.remove_workspace('DEV_WS', 'N', 'N');
end;
/

-- Run as another privileged user.
drop user dev_ws cascade;
drop user apex_priv_user cascade;

For more information see:

Hope this helps. Regards Tim...

Back to the Top.