A Autonomous JSON Database for Experienced Oracle Database Users

This appendix provides information on using Autonomous JSON Database for experienced Oracle Database users with Autonomous Database on shared Exadata infrastructure.

For equivalent information about using Oracle Database features and options with Autonomous Database on dedicated Exadata infrastructure, see these resources:

Autonomous Database – Oracle Database Features

Autonomous JSON Database includes features that:

  • Automate index management tasks, such as creating, rebuilding, and dropping indexes based on changes in the application workload.

    See Manage Automatic Indexing on Autonomous Database in Using Oracle Autonomous Database on Shared Exadata Infrastructure for more information.

    Note:

    There are restrictions for Automatic Indexing when you use JSON data with Autonomous JSON Database. See Restrictions for SODA and JSON for more information.
  • Gather real-time statistics automatically while a conventional DML workload is running. Because statistics can go stale between stats gathering jobs, online statistics gathering for conventional DML helps the optimizer generate more optimal plans. Online statistics aim to reduce the possibility of the optimizer being misled by stale statistics.

    See Real-Time Statistics for more information.

  • Gather statistics automatically on a more frequent basis. High-Frequency Automatic Optimizer Statistics Collection complements the standard statistics collection job. By default, the collection occurs every 15 minutes, meaning that statistics have less time in which to be stale. High-Frequency Automatic Optimizer Statistics Collection is enabled by default.

    See Configuring High-Frequency Automatic Optimizer Statistics Collection for more information.

  • Quarantine execution plans for SQL statements, for example, statements that are terminated by the Resource Manager for consuming excessive system resources in an Oracle Database. Automatic SQL Quarantine based on Resource Manager consumption limit violations is disabled by default but any manually quarantined SQL statement will be honored.

    See Quarantine for Execution Plans for SQL Statements Consuming Excessive System Resources for more information.

  • Automatically assess the opportunity for SQL plan changes to improve the performance for known statements.

    See Managing the SPM Evolve Advisor Task for more information.

  • Apache ORC format is supported in Autonomous Database for loading and querying data in object store.

    See Create Credentials and Load Data Pump Dump Files into an Existing Table and Query External Data with ORC, Parquet, or Avro Source Files in Using Oracle Autonomous Database on Shared Exadata Infrastructure for more information.

  • Complex types are supported in Autonomous Database for ORC, Avro, and Parquet structured files.

    See DBMS_CLOUD Package ORC, Parquet and Avro Complex Types in Using Oracle Autonomous Database on Shared Exadata Infrastructure for more information.

Restrictions for Database Initialization Parameters

Autonomous JSON Database configures database initialization parameters automatically when you provision a database. You do not need to set any initialization parameters to start using your service. But, you can modify some parameters if you need to.

List of Initialization Parameters that can be Modified

APPROX_FOR_AGGREGATION
APPROX_FOR_COUNT_DISTINCT
APPROX_FOR_PERCENTILE
AWR_PDB_AUTOFLUSH_ENABLED
CURSOR_SHARING
DDL_LOCK_TIMEOUT
FIXED_DATE
LDAP_DIRECTORY_ACCESS
MAX_IDLE_TIME
MAX_STRING_SIZE (See Restrictions for Data Types for details)
NLS_CALENDAR
NLS_COMP
NLS_CURRENCY
NLS_DATE_FORMAT
NLS_DATE_LANGUAGE
NLS_DUAL_CURRENCY
NLS_ISO_CURRENCY
NLS_LANGUAGE
NLS_LENGTH_SEMANTICS
NLS_NCHAR_CONV_EXCP
NLS_NUMERIC_CHARACTERS
NLS_SORT
NLS_TERRITORY
NLS_TIMESTAMP_FORMAT
NLS_TIMESTAMP_TZ_FORMAT
OPTIMIZER_CAPTURE_SQL_PLAN_BASELINES  (Allowed only with ALTER SESSION)
OPTIMIZER_IGNORE_HINTS
OPTIMIZER_IGNORE_PARALLEL_HINTS
OPTIMIZER_MODE
PLSCOPE_SETTINGS
PLSQL_CCFLAGS
PLSQL_DEBUG
PLSQL_OPTIMIZE_LEVEL
PLSQL_WARNINGS
QUERY_REWRITE_INTEGRITY
RESULT_CACHE_MODE
STATISTICS_LEVEL (Allowed only with ALTER SESSION)

For more information on initialization parameters see Oracle Database Reference. For more information on TIME_ZONE, see Oracle Database SQL Language Reference.

For more information on OPTIMIZER_IGNORE_HINTS and OPTIMIZER_IGNORE_PARALLEL_HINTS, see Manage Optimizer Statistics on Autonomous Database.

Restrictions for SQL Commands

Autonomous JSON Database allows most of the SQL commands available in Oracle Database. To ensure the security and the performance of Autonomous JSON Database, some SQL commands are restricted.

This section provides a list of SQL command limitations that are required to protect security and for the performance integrity of Autonomous Databases. Most of the standard SQL and PL/SQL syntax and constructs available with Oracle Database work in Autonomous Databases.

Note:

If you try to use a restricted SQL command the system reports:

ORA-01031: insufficient privileges

This error indicates that you are not allowed to run the SQL command in Autonomous JSON Database.

The following SQL statements are not available in Autonomous JSON Database:

SQL Statements with Restrictions in Autonomous JSON Database

The following DDL statements are available in Autonomous JSON Database with restrictions:

SQL Command Restrictions

ALTER PLUGGABLE DATABASE and ALTER DATABASE

Only the following clauses are allowed:

DATAFILE AUTOEXTEND ON

DATAFILE AUTOEXTEND OFF

DATAFILE RESIZE

DEFAULT EDITION

SET TIME_ZONE

SET CMU_WALLET

ALTER PROFILE

PASSWORD_VERIFY_FUNCTION

PASSWORD_VERIFY_FUNCTION (See Managing Password Complexity on Autonomous Database for more information.)

Using ALTER PROFILE, the optional CONTAINER clause is ignored if specified.

See Create Users on Autonomous Database for information on the password parameter values defined in the default profile.

ALTER SESSION

Only the following clauses are allowed:

ADVISE COMMIT, ADVISE ROLLBACK, ADVISE NOTHING

CLOSE DATABASE LINK

ENABLE COMMIT IN PROCEDUREDISABLE COMMIT IN PROCEDURE

ENABLE PARALLEL <QUERY|DDL|DML>, DISABLE PARALLEL <QUERY|DDL|DML>, FORCE PARALLEL <QUERY|DDL|DML>

ENABLE RESUMABLE, DISABLE RESUMABLE

SET DEFAULT_COLLATION

SET EDITION

SET ISOLATION_LEVEL

SET ROW ARCHIVAL VISIBILITY

SET TIME_ZONE

ALTER SYSTEM

ALTER SYSTEM is not allowed except ALTER SYSTEM SET and ALTER SYSTEM KILL SESSION

SET can only be used to set parameters listed in Restrictions for Database Initialization Parameters.

ALTER USER

The following clause is ignored: DEFAULT TABLESPACE

The IDENTIFIED with the EXTERNALLY clause is not supported.

The IDENTIFIED BY VALUES clause is not allowed.

ALTER TABLE

For restrictions, see ALTER TABLE Restrictions.

CREATE PROFILE

PASSWORD_VERIFY_FUNCTION

Using ALTER PROFILE, the optional CONTAINER clause is ignored if specified.

See Create Users on Autonomous Database for information on the password parameter values defined in the default profile.

CREATE TABLE

For restrictions, see CREATE TABLE Restrictions.

CREATE USER

The following clause is ignored:

  • DEFAULT TABLESPACE

IDENTIFIED with the EXTERNALLY clause is not supported.

The IDENTIFIED BY VALUES clause is not allowed.

CREATE TABLE Restrictions

XMLType tables using XML schema-based storage are not allowed. See Restrictions for Oracle XML DB for more information.

The clauses not in this list are allowed.

Clause Comment

cluster

Ignored

ilm_clause

Ignored

inmemory_table_clause

Ignored

LOB_storage_clause

Ignored

logging_clause

Ignored

organization external

Ignored

organization index

Creates a regular table with a primary key. Using the organization index clause does not create an index-organized table. You should test and verify the performance of the generated table for your application.

physical_properties

Ignored

Note:

For more information on CREATE TABLE, see Database SQL Language Reference.

ALTER TABLE Restrictions

The clauses not in this list are allowed.

Clause Comment

allocate_extent_clause

Ignored

alter_iot_clauses

Ignored

deallocate_unused_clause

Ignored

ilm_clause

Ignored

inmemory_table_clause

Ignored

logging_clause

Ignored

modify_LOB_storage_clause

Ignored

physical_attributes_clause

Ignored

shrink_clause

Ignored

Note:

For more information on ALTER TABLE, see Database SQL Language Reference.

Restrictions for Data Types

Autonomous JSON Database allows most of the data types available in the Oracle Database. To ensure the security and the performance of Autonomous JSON Database, some data types are restricted.

The following data types are not supported or have limited support in Autonomous JSON Database:

  • Media types are not supported (Oracle Multimedia is desupported)

  • Oracle Spatial and Graph types are supported with restrictions. See Restrictions for Oracle Graph for more information.

Checking and Setting MAX_STRING_SIZE

By default Autonomous JSON Database uses extended data types and the value of MAX_STRING_SIZE is set to the value EXTENDED. With this setting you can specify a maximum size of 32767 bytes for the VARCHAR2, NVARCHAR2, and RAW data types. The default, EXTENDED, is the recommended setting and allows Autonomous Database to take full advantage of database capabilities.

Use DBMS_MAX_STRING_SIZE subprograms to check usage of extended data types and to change the database to revert to the older style STANDARD, supporting a maximum size of 4000 bytes for VARCHAR2, NVARCHAR2, and RAW data types.

Note:

Using DBMS_MAX_STRING_SIZE.MODIFY_MAX_STRING_SIZE is a one-way change that cannot be reverted. After a database is switched back to the STANDARD style of supporting a maximum length of 4000 bytes for the VARCHAR2, NVARCHAR2, and RAW data types, you cannot re-enable EXTENDED data types.

The ADMIN user is granted EXECUTE privilege WITH GRANT OPTION clause on DBMS_MAX_STRING_SIZE. Oracle recommends that you do not GRANT EXECUTE on this package to other users.

  1. Check whether your environment can be reverted to the old style, STANDARD behavior:

    SELECT * FROM TABLE(DBMS_MAX_STRING_SIZE.CHECK_MAX_STRING_SIZE('STANDARD'));

    See CHECK_MAX_STRING_SIZE Function in Using Oracle Autonomous Database on Shared Exadata Infrastructure for more information.

  2. Check and correct all reported violations from Step 1, if applicable.

  3. After fixing any reported violations found in Step 1, if you want to revert to a maximum length of 4000 bytes for VARCHAR2, NVARCHAR2, and RAW data types, use DBMS_MAX_STRING_SIZE.MODIFY_MAX_STRING_SIZE as follows:

    EXEC DBMS_MAX_STRING_SIZE.MODIFY_MAX_STRING_SIZE('STANDARD');

    See MODIFY_MAX_STRING_SIZE Procedure in Using Oracle Autonomous Database on Shared Exadata Infrastructure for more information.

See Extended Data Types for details on extended data types.

For a list of Oracle data types see Oracle Database SQL Language Reference.

Restrictions and Notes for Database PL/SQL Packages

Lists Oracle Database PL/SQL packages with restrictions and notes in Autonomous Database.

Removed PL/SQL Packages

  • UTL_TCP

  • DBMS_LDAP

  • DBMS_DEBUG_JDWP

  • DBMS_DEBUG_JDWP_CUSTOM

PL/SQL Packages Restrictions

  • UTL_HTTP Restrictions

    • Connections through IP addresses are not allowed.

    • Only HTTPS connections are allowed (HTTP and HTTP_PROXY are disallowed).

    • All web services must be secured. The only allowed ports are 443 and 8443. Your instance is preconfigured with an Oracle Wallet that contains more than 90 of the most commonly trusted root and intermediate SSL certificates. This Oracle Wallet is centrally managed and therefore you cannot consume 3rd party web services that are protected using self-signed SSL certificates.

    • The SET_AUTHENTICATION_FROM_WALLET procedure is disallowed.

    • The WALLET_PATH and WALLET_PASSWORD arguments for the CREATE_REQUEST_CONTEXT, REQUEST, and REQUEST_PIECES APIs are ignored.

    • Oracle Wallet configuration cannot be altered. All arguments for SET_WALLET API are ignored.

    • UTL_HTTP usage is audited by default. You cannot disable auditing for UTL_HTTP.

    • The UTL_HTTP URL must be accessible over the internet. The UTL_HTTP call is unable to reach URLs that are on private subnets or behind on-premises firewalls.

  • UTL_SMTP Restrictions

    • The only supported email provider is Oracle Cloud Infrastructure Email Delivery service. See Overview of the Email Delivery Service for more information.

    • Mail with an IP address in the host name is not allowed.

    • The only allowed ports are 25 and 587.

    • UTL_SMTP usage is audited by default. You cannot disable auditing for UTL_SMTP.

  • DBMS_NETWORK_ACL_ADMIN Restrictions

    • Granting ACL privileges on IP addresses is not allowed.

    • The http_proxy and use_passwords ACL privileges are not allowed.

See UTL_HTTP, DBMS_LDAP, UTL_SMTP, and DBMS_NETWORK_ACL_ADMIN in PL/SQL Packages and Types Reference for more information.

PL/SQL Packages Notes

  • UTL_HTTP Errors

    The following table shows error messages and possible causes for these error messages when using UTL_HTTP:

    Error Message Potential Cause

    ORA-12545: Connect failed because target host or object does not exist

    Target host or object does not exist or it is private.

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

    Access control list (ACL) for the specified host could not be found.

    ORA-29024: Certificate validation failure

    Certificate of the host does not exist or is not among the supported certificates.

  • UTL_HTTP Example

    Submit an HTTP request for the host www.example.com:

    -- Create an Access Control List for the host
    BEGIN
       DBMS_NETWORK_ACL_ADMIN.APPEND_HOST_ACE(
             host => 'www.example.com',
             ace =>  xs$ace_type(privilege_list => xs$name_list('http'),
                                 principal_name => 'ADMIN',
                                 principal_type => xs_acl.ptype_db));
    END;
    /
    -- Set Oracle Wallet location (no arguments needed)
    BEGIN
       UTL_HTTP.SET_WALLET('');
    END;
    /
    -- Submit an HTTP request
    SELECT UTL_HTTP.REQUEST('https://www.example.com/') FROM dual;

Restrictions for SODA and JSON

When you use SODA with Autonomous Database the following restrictions apply:

  • Automatic indexing is not supported for SQL and PL/SQL code that uses the SQL/JSON function json_exists. See SQL/JSON Condition JSON_EXISTS for more information.

  • Automatic indexing is not supported for SODA query-by-example (QBE).

Restrictions for Database Features

Autonomous Database is built to support multiple workloads. In some cases, features which are present in Oracle Database Enterprise Edition are not available in Autonomous Database. Additionally, database features designed for administration are not available.

Restrictions for Oracle XML DB

The following describes Autonomous Database support for Oracle XML DB features. To ensure the security and the performance of your JSON database, some Oracle XML DB features are restricted.

The following is supported, in addition to the features listed:

  • Full support for XMLQuery, XMLTable, and other SQL/XML standard functions

  • Indexing schema including functional indexes using SQL/XML expressions, Structured XMLIndex and XQuery Full Text Index

Note:

If you migrate tables containing XMLType columns to Autonomous JSON Database using Oracle Data Pump, you need to convert to Non-Schema Binary XML prior to using Oracle Data Pump Export (expdp).
Area XML DB Feature Supported in Autonomous Database More Information
Repository XML DB Protocol No Repository Access Using Protocols
Repository XML DB Resources No Oracle XML DB Repository Resources
Repository XML DB ACLs No Repository Access Control
Storage XML Schema Registration No XML Schema Registration with Oracle XML DB
Storage CLOB No Deprecated
Storage Object Relational No XML Schema and Object-Relational XMLType
Storage Binary XML Yes (Non schema-based only) XMLType Storage Models
Index Structured XML Index Yes XMLIndex Structured Component
Index XQuery Full Text Index Yes Indexing XML Data for Full-Text Queries
Index Unstructured XMLIndex No XMLIndex Unstructured Component
Packages XML DOM package Yes PL/SQL DOM API for XMLType (DBMS_XMLDOM)
Packages XML Parser Package Yes PL/SQL Parser API for XMLType (DBMS_XMLPARSER)
Packages XSL Processor (DBMS_XSLPROCESSOR) Yes PL/SQL XSLT Processor for XMLType (DBMS_XSLPROCESSOR)

For details on Oracle XML DB, see Oracle XML DB Developer's Guide.

Restrictions for Oracle Text

The following describes Autonomous Database support for Oracle Text features. To ensure the security and the performance of your JSON database, some Oracle Text features are restricted.

Oracle Text Feature Supported in Autonomous Database More Information
All logging, and APIs which perform logging such as ctx_report.query_log_summary Not Supported QUERY_LOG_SUMMARY
File and URL datastore Not Supported Datastore Type
CREATE INDEX with BIG_IO option Not supported by default.Foot 1 Improved Response Time Using the BIG_IO Option of CONTEXT Index
OPTIMIZE_INDEX in rebuild mode Not supported by default.(see Footnote 1). OPTIMIZE_INDEX

Footnote 1 This is supported if you grant the privilege to create a trigger to the user (GRANT CREATE TRIGGER). You must also disable parallel DML at the session level (ALTER SESSION DISABLE PARALLEL DML).

For details on Oracle Text, see Oracle Text Application Developer's Guide.

Restrictions for Oracle Graph

To ensure the security and the performance of your Autonomous JSON Database, some Oracle Graph features are restricted.

See Oracle Graph Limitations with Autonomous Database for a list of Oracle Graph features that are restricted.

Restrictions for Oracle Spatial

To ensure the security and the performance of your Autonomous JSON Database, some Oracle Spatial features are restricted.

See Oracle Spatial Limitations with Autonomous Database for a list of Oracle Spatial features that are restricted.

Restrictions for Oracle Application Express

Autonomous JSON Database supports Oracle Application Express. To ensure the security and the performance of Autonomous JSON Database, some Oracle Application Express features are restricted.

Restrictions for Oracle Flashback

Oracle Flashback Technology is a group of Oracle Database features that let you view past states of database objects or to return database objects to a previous state without using point-in-time media recovery.

To restore and recover your database to a point in time, see Restore and Recover your Autonomous JSON Database Database.

Oracle Flashback Feature Supported in Autonomous Database

DBMS_FLASHBACK

Yes except the procedure:

DBMS_FLASHBACK.TRANSACTION_BACKOUT

Flashback Data Archive

No

Flashback Drop

Yes

Flashback Query

Yes

Flashback Table

Yes

Flashback Transaction

No

Flashback Transaction Query

Yes

Flashback Version Query

Yes

See About Oracle Flashback Technology for information on using Flashback features.

Restrictions for Fast Application Notification (FAN)

Subscribing to Fast Application Notification (FAN) events is not supported with Autonomous Database and is not needed. The functionality provided by FAN is provided out of the box with Autonomous Database. You do not need to enable your application for FAN or subscribe to FAN events.

You can use Application Continuity to mask outages from your applications. See Using Application Continuity on Autonomous Database for more information.

Recommended Client Settings for Common Drivers

  • ODP.Net: The Oracle Data Provider for .NET (ODP.Net) unmanaged provider supports Application Continuity out of the box. When connecting an ODP.Net application to your Autonomous Database, do not explicitly set HA events, application continuity, or onsConfig; accept the default settings.

  • JDBC (thin) driver: When using the Universal Connection Pool (UCP), disable Fast Connection Failover. For example:

    PoolDataSource.setFastConnectionFailoverEnabled(false)
  • Oracle Call Interface (OCI): Do not configure ONS servers in oraaccess.xml:

    <ons>
       <servers> 
       <!—Do not enter any values --> 
       </servers> 
    </ons>

    Also, do not configure the <fan> section:

    <fan>  
    <!-- only possible values are "trace" or "error" -->  
        <subscription_failure_action>
       </subscription_failure_action>  
    </fan>

Restrictions for Oracle Database Real Application Security

Oracle Database Real Application Security is a database authorization model that: supports declarative security policies, enables end-to-end security for multitier applications, provides an integrated solution to secure database and application resources, and advances the security architecture of Oracle Database to meet existing and emerging demands of applications developed for the Internet.

See Introducing Oracle Database Real Application Security more information.

Real Application Security works the same on Autonomous Database as on an on-premise database except you need to perform the following ADMIN tasks before using Real Application Security on Autonomous Database:

  • To create Real Application Security users/roles, you need the PROVISION system privilege. As the ADMIN user run the following command to grant this privilege to a database user:

    SQL> EXEC XS_ADMIN_CLOUD_UTIL.GRANT_SYSTEM_PRIVILEGE('PROVISION','DB_USER');

    In this example, DB_USER is a database user.

    Running this command on Autonomous Database replaces the following on-premise database command (note the _CLOUD_ is not in the following package name):

    SQL> EXEC SYS.XS_ADMIN_UTIL.GRANT_SYSTEM_PRIVILEGE('PROVISION', 'DB_USER', XS_ADMIN_UTIL.PTYPE_XS);

    See General Procedures for Creating Application User Accounts for more information.

  • To create Real Application Security data controls, you need the ADMIN_ANY_SEC_POLICY privilege. As the ADMIN user run the following command to grant this privilege:

    EXEC XS_ADMIN_CLOUD_UTIL.GRANT_SYSTEM_PRIVILEGE('ADMIN_ANY_SEC_POLICY','DB_USER');

    In this example, DB_USER is a database user.

    Running this command on Autonomous Database replaces the following on-premise database command (note the _CLOUD_ is not in the following package name):

    SQL> EXEC SYS.XS_ADMIN_UTIL.GRANT_SYSTEM_PRIVILEGE('ADMIN_ANY_SEC_POLICY','DB_USER');

    See Creating Roles and Application Users for more information.

List of Restricted and Removed Oracle Features

Lists the Oracle Database features that are not available in Autonomous JSON Database. Additionally, database features designed for administration are not available.

List of Removed Oracle Features

  • Oracle Real Application Testing (Database Replay)

  • Oracle Real Application Security Administration Console (RASADM)

  • Oracle OLAP

  • Oracle R capabilities of Oracle Advanced Analytics

  • Oracle Industry Data Models

  • Oracle Database Lifecycle Management Pack

  • Oracle Data Masking and Subsetting Pack

  • Oracle Cloud Management Pack for Oracle Database

  • Oracle Multimedia

  • Oracle LogMiner

  • Oracle Sharding

  • Java in DB

  • Oracle Workspace Manager

Managing DML Performance and Compression for Data Warehouse Workloads

Autonomous Database with Data Warehouse workloads uses Hybrid Columnar Compression for all tables by default. This gives the best compression ratio and optimal performance for direct-path load operations like the loads done using the DBMS_CLOUD package. If you perform DML operations like UPDATE and MERGE on your tables these may cause the compression ratio for the affected rows to decrease leading to larger table sizes. These operations may also perform slower compared to the same operations on an uncompressed table.

For the best compression ratio and optimal performance Oracle recommends using bulk operations like direct-path loads and CREATE TABLE AS SELECT statements. But, if your workload requires frequent DML operations like UPDATE and MERGE on large parts of a table, you can create those tables as uncompressed tables to achieve better DML performance. For example, the following statement creates the table SALES as an uncompressed table:

CREATE TABLE sales (
    prod_id             NUMBER          NOT NULL,
    cust_id             NUMBER          NOT NULL,
    time_id             DATE            NOT NULL,
    channel_id          NUMBER          NOT NULL,
    promo_id            NUMBER          NOT NULL,
    quantity_sold       NUMBER(10,2)    NOT NULL,
    amount_sold         NUMBER(10,2)    NOT NULL)
NOCOMPRESS;

At any point in time you can use the ALTER TABLE MOVE statement to compress these tables without impacting queries accessing them. For example, the following statement compresses the table SALES using Hybrid Columnar Compression.

ALTER TABLE sales MOVE COLUMN STORE COMPRESS FOR QUERY HIGH;