Chapter 5 Migrating PL/SQL
---
This chapter explains how to migrate Oracle database PL/SQL. Note that in this document, PL/SQL refers to the language to be migrated to PostgreSQL PL/pgSQL.
### 5.1 Notes on Migrating from PL/SQL to PL/pgSQL
This section provides notes on migration from PL/SQL to PL/pgSQL.
#### 5.1.1 Transaction Control
PL/pgSQL does not allow transaction control within a process. Terminate a procedure whenever a transaction is terminated in the Oracle database and execute a transaction control statement from the application.
### 5.2 Basic Elements
This section explains how to migrate the basic elements of PL/SQL.
#### 5.2.1 Migrating Data Types
The table below lists the PostgreSQL data types that correspond to data types unique to PL/SQL.
Data type correspondence with PL/SQL
- **Character**
|Oracle database Data type|Remarks|Migratability|PostgreSQL Data type|Remarks|
|:---|:---|:---:|:---|:---|
| STRING | The number of bytes or number of characters can be specified. | MR | varchar | Only the number of characters can be specified. |
- **Numeric**
|Oracle database Data type|Remarks|Migratability|PostgreSQL Data type|Remarks|
|:---|:---|:---:|:---|:---|
| BINARY_INTEGER | | M | integer | |
| NATURAL | | M | integer | |
| NATURALN | Type with NOT NULL constraints | MR | integer | Set "not null" constraints for variable declarations. |
| PLS_INTEGER | | M | integer | |
| POSITIVE | | M | integer | |
| POSITIVEN | Type with NOT NULL constraints | MR | integer | Set "not null" constraints for variable declarations. |
| SIGNTYPE | | M | smallint | |
| SIMPLE_DOUBLE | Type with NOT NULL constraints | MR | double precision | Set "not null" constraints for variable declarations. |
| SIMPLE_FLOAT | Type with NOT NULL constraints | MR | real | Set "not null" constraints for variable declarations. |
| SIMPLE_INTEGER | Type with NOT NULL constraints | MR | integer | Set "not null" constraints for variable declarations. |
- **Date and time**
|Oracle database Data type|Remarks|Migratability|PostgreSQL Data type|Remarks|
|:---|:---|:---:|:---|:---|
| DSINTERVAL_UNCONSTRAINED | | N | | |
| TIME_TZ_UNCONSTRAINED | | N | | |
| TIME_UNCONSTRAINED | | N | | |
| TIMESTAMP_LTZ_UNCONSTRAINED | | N | | |
| TIMESTAMP_TZ_UNCONSTRAINED | | N | | |
| TIMESTAMP_UNCONSTRAINED | | N | | |
| YMINTERVAL_UNCONSTRAINED | | N | | |
- **Other**
|Oracle database Data type|Remarks|Migratability|PostgreSQL Data type|Remarks|
|:---|:---|:---:|:---|:---|
| BOOLEAN | | Y | boolean | |
| RECORD | | M | Complex type | |
| REF CURSOR (cursor variable) | | M | refcursor type | |
| Subtype with constraints | | N | | |
| Subtype that uses the base type within the same data type family | | N | | |
| Unconstrained subtype | | N | | |
Y: Data type can be migrated as is
M: Modified data type can be migrated
N: Cannot be migrated
MR: Modified data type can be migrated with restrictions
**See**
----
Refer to "Data Types" for information on migrating data types other than those unique to PL/SQL.
----
#### 5.2.2 Error-Related Elements
This section explains elements related to PL/SQL errors.
##### 5.2.2.1 Predefined Exceptions
**Description**
A predefined exception is an error defined beforehand in an Oracle database.
**Functional differences**
- **Oracle database**
- Predefined exceptions can be used.
- **PostgreSQL**
- Predefined exceptions cannot be used. Use PostgreSQL error codes instead.
**Migration procedure**
Use the following procedure to perform migration:
1. Identify where predefined exceptions are used.
2. Refer to the table below and replace the values of predefined exceptions with PostgreSQL error codes.
|Predefined exception
(Oracle database)|Migratability|Corresponding PostgreSQL error code|
|:---|:---:|:---|
| ACCESS_INTO_NULL | N | Not generated |
| CASE_NOT_FOUND | Y | case_not_found |
| COLLECTION_IS_NULL | N | Not generated |
| CURSOR_ALREADY_OPEN | Y | duplicate_cursor |
| DUP_VAL_ON_INDEX | Y | unique_violation |
| INVALID_CURSOR | Y | invalid_cursor_name |
| INVALID_NUMBER | Y | invalid_text_representation |
| LOGIN_DENIED | Y | invalid_authorization_specification
invalid_password |
| NO_DATA_FOUND | Y | no_data_found |
| NO_DATA_NEEDED | N | Not generated |
| NOT_LOGGED_ON | N | Not generated |
| PROGRAM_ERROR | Y | internal_error |
| ROWTYPE_MISMATCH | N | Not generated |
| SELF_IS_NULL | N | Not generated |
| STORAGE_ERROR | Y | out_of_memory |
| SUBSCRIPT_BEYOND_COUNT | N | Not generated |
| SUBSCRIPT_OUTSIDE_LIMIT | N | Not generated |
| SYS_INVALID_ROWID | N | Not generated |
| TIMEOUT_ON_RESOURCE | N | Not generated |
| TOO_MANY_ROWS | Y | too_many_rows |
| VALUE_ERROR | Y | null_value_not_allowed
invalid_text_representation
string_data_right_truncation
invalid_parameter_value |
| ZERO_DIVIDE | Y | division_by_zero |
Y: Can be migrated
N: Cannot be migrated
**Migration example**
The example below shows how to migrate the VALUE_ERROR exception. Note that OR is used in the migration example to group error codes so that VALUE_ERROR corresponds to multiple PostgreSQL error codes.
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|
Oracle database | PostgreSQL |
---|---|
|
|