You can
translate SQL statements written in PostgreSQL to Oracle SQL and run the translated statements
on Autonomous Database.
Use DBMS_CLOUD_MIGRATION.MIGRATE_SQL to translate the PostgreSQL statement to Oracle SQL. There are procedure and function variants of DBMS_CLOUD_MIGRATION.MIGRATE_SQL.
Migrate PostgreSQL statement to Oracle
SQL with MIGRATE_SQL Procedure
The following example accepts the SQL statement written in PostgreSQL as input,
translates the statement to Oracle SQL, assigns the translated SQL statement to
output_sql_result, and prints the result:
SET SERVEROUTPUT ON
declare output_sql_result CLOB;
BEGIN
DBMS_CLOUD_MIGRATION.MIGRATE_SQL(
original_sql => 'SELECT e.employee_id, e.last_name, e.salary FROM employees AS e;',
output_sql => output_sql_result,
source_db => 'POSTGRES');
DBMS_OUTPUT.PUT_LINE (output_sql_result);
END;
/
Output
–-------------------------------------------------------------
SELECT e.employee_id, e.last_name, e.salary FROM employees e;
The original_sql parameter specifies the PostgreSQL statement.
The output_sql parameter stores the translated SQL.
The source_db parameter specifies the PostgreSQL database name.
Migrate PostgreSQL statement to Oracle SQL with MIGRATE_SQL Function
The following example shows the DBMS_CLOUD_MIGRATION.MIGRATE_SQL function within a SELECT statement. The function input is a PostgreSQL statement and the function returns the translated statement in Oracle SQL:
SELECT DBMS_CLOUD_MIGRATION.MIGRATE_SQL(
'CREATE TABLE IF NOT EXISTS cars (brand VARCHAR(255), model VARCHAR(255), year INT)',
'POSTGRES') AS output FROM DUAL;
OUTPUT
------------------------------------------------------------------------------
create table cars (brand VARCHAR2(255), model VARCHAR2(255), year NUMBER(10);
Run PostgreSQL Statements in Autonomous
Database 🔗
You can
interactively translate and run PostgreSQL statements in your Autonomous Database.
Use the ENABLE_TRANSLATION procedure to enable real-time translation of SQL statements written in PostgreSQL. After you enable translation in a session, PostgreSQL statements are automatically translated and run as Oracle SQL statements, and you can see the results.
For example, after you enable translation by running
ENABLE_TRANSLATION you can interactively do the following in a session:
Create the tables. For example, create the tables MOVIE and
INVENTORY.
Insert data into tables.
Query tables.
Perform JOIN operations on tables. For example, you can perform a left outer join on tables.
To enable translation with PostgreSQL and run commands:
Connect to your Autonomous Database using a SQL client.
Perform a left outer join on tables MOVIE and INVENTORY:
SELECT m.film_id, m.title, inventory.inventory_id
FROM movie AS m LEFT JOIN inventory
ON inventory.film_id = m.film_id;
FILM_ID TITLE INVENTORY_ID
---------- ---------- ------------
234 Frozen 334
123 Tangled 223
This example performs a LEFT OUTER JOIN on the movie and inventory tables. The AS keyword for table aliases in the FROM clause is not supported in Oracle SQL. The query is first translated to Oracle SQL and then run in your session.
Use DBMS_CLOUD_MIGRATION.DISABLE_TRANSLATION procedure to disable real-time SQL language translation for your session.
BEGIN
DBMS_CLOUD_MIGRATION.DISABLE_TRANSLATION;
END;
/
This returns an error if SQL language translation is not enabled for your session.
You can query the V$MAPPED_SQL view to list
the PostgreSQL statements that are translated and mapped in memory to Oracle SQL
statements.
For
example:
SELECT v.*
FROM v$mapped_sql v, dba_objects o
WHERE v.sql_translation_profile_id = o.object_id
AND o.object_name = 'POSTGRES'
AND o.object_type = 'TRANSLATION PROFILE';
You can
migrate a file containing PostgreSQL statements to a file containing Oracle SQL
statements.
The DBMS_CLOUD_MIGRATION.MIGRATE_FILE procedure translates SQL
statements in a PostgreSQL file in Object Storage and generates a new file containing Oracle
SQL.
As a prerequisite, upload one or more PostgreSQL files with a .sql
extension to a location on Object Storage. The following examples use the file
postgrestest.sql that is uploaded to Object Storage. See Put data into object storage for more
information.
If your files reside in another vendor's Cloud Object Storage, define
the appropriate policies and roles to access the resource. See Configure Policies and Roles to Access Resources for more information.
Create a credential to access Cloud Object Storage:
You can create a credential to access Cloud Object Storage.
Optionally, you can list the files in Object Storage. For example:
VAR function_list CLOB;
SELECT object_name FROM DBMS_CLOUD.LIST_OBJECTS
(credential_name => 'OCI$RESOURCE_PRINCIPAL', location_uri => 'https://objectstorage.region.oraclecloud.com/n/namespace/b/bucket/o/files');
OBJECT_NAME
---------------------
postgrestest.sql
Alternatively, if you create a credential instead of the resource principal,
OCI$RESOURCE_PRINCIPAL, specify the credential name in the
credential_name parameter.
The credential_name parameter specifies the credential to
access the Cloud Object Storage URI. The user that runs DBMS_CLOUD_MIGRATION.MIGRATE_FILE must have
EXECUTE privilege for the credential object used to access the Object
Storage URI. That is, the credential you specify with the
credential_name parameter. If you use a credential instead of a
resource principal, specify the credential name in the credential_name
parameter.
The location_uri parameter specifies the source file URI.
The format of the URI depends on the Cloud Object Storage service you are using. See
DBMS_CLOUD URI Formats for more
information.
The source_db parameter specifies the PostgreSQL as database language. Use the value POSTGRES to translate PostgreSQL files to Oracle SQL.
Running this command translates the PostgreSQL file
postgrestest.sql to Oracle SQL and generates a new file with the name
original_filename_oracle.sql.
For this example, running DBMS_CLOUD_MIGRATION.MIGRATE_FILE with the input file
postgrestest.sql generates postgrestest_oracle.sql.
After the translation step the procedure uploads
postgrestest_oracle.sql to Object Storage.
Optionally, use the target_uri parameter to specify the
location where the translated file is uploaded. The default value for this parameter is
NULL, which means the translated file is uploaded to the same
location as specified in the location_uri parameter.
Alternatively, if you create a credential instead of the resource principal,
OCI$RESOURCE_PRINCIPAL, specify the credential name in the
credential_name parameter.
Run the following query to view the content of the
postgrestest_oracle.sql file:
SELECT UTL_RAW.CAST_TO_VARCHAR2 (DBMS_CLOUD.GET_OBJECT(
credential_name => 'OCI$RESOURCE_PRINCIPAL',
object_uri => 'https://objectstorage.region.oraclecloud.com/n/namespace/b/bucket/o/files'))
FROM dual;
UTL_RAW.CAST_TO_VARCHAR2(DBMS_CLOUD.GET_OBJECT(CREDENTIAL_NAME=>'CRED1',OBJECT_U
--------------------------------------------------------------------------------
SELECT f.film_id, f.title, inventory_id
FROM film f LEFT JOIN inventory
ON inventory.film_id = f.film_id;
Alternatively, if you create a credential instead of the resource principal,
OCI$RESOURCE_PRINCIPAL, specify the credential name in the
credential_name parameter.
Limitations for Migration and Translation of PostgreSQL Statements to Oracle SQL
🔗
This section summarizes the limitations for migrating SQL statements from PostgreSQL to Oracle SQL.
The following list of PostgreSQL statements are not supported when
migrating to Autonomous Database:
CREATE DOMAIN
CREATE EXTENSION
CREATE DATABASE
CREATE TYPE
SET
The following list of PostgreSQL statements are supported with
restrictions:
ALTER TABLE: Only ALTER TABLE ADD
CONSTRAINT is supported when migrating to Autonomous
Database.
DELETE: The RETURNING *
keyword in the DELETE statement is not supported in
Autonomous Database. You must replace the RETURNING *
clause with the RETURNING INTO clause. For example,
DELETE FROM tasks WHERE status = 'DONE' RETURNING *;.