Oracle

Support for the Oracle database.

The following table summarizes current support levels for database release versions.

DBAPI Support

The following dialect/DBAPI options are available. Please refer to individual DBAPI sections for connect information.

Connect Arguments

The dialect supports several create_engine() arguments which affect the behavior of the dialect regardless of driver in use.

  • use_ansi - Use ANSI JOIN constructs (see the section on Oracle 8). Defaults to True. If False, Oracle-8 compatible constructs are used for joins.

  • optimize_limits - defaults to False. see the section on LIMIT/OFFSET.

  • use_binds_for_limits - defaults to True. see the section on LIMIT/OFFSET.

Auto Increment Behavior

SQLAlchemy Table objects which include integer primary keys are usually assumed to have “autoincrementing” behavior, meaning they can generate their own primary key values upon INSERT. Since Oracle has no “autoincrement” feature, SQLAlchemy relies upon sequences to produce these values. With the Oracle dialect, a sequence must always be explicitly specified to enable autoincrement. This is divergent with the majority of documentation examples which assume the usage of an autoincrement-capable database. To specify sequences, use the sqlalchemy.schema.Sequence object which is passed to a Column construct:

t = Table('mytable', metadata,
      Column('id', Integer, Sequence('id_seq'), primary_key=True),
      Column(...), ...
)

This step is also required when using table reflection, i.e. autoload=True:

t = Table('mytable', metadata,
      Column('id', Integer, Sequence('id_seq'), primary_key=True),
      autoload=True
)

Identifier Casing

In Oracle, the data dictionary represents all case insensitive identifier names using UPPERCASE text. SQLAlchemy on the other hand considers an all-lower case identifier name to be case insensitive. The Oracle dialect converts all case insensitive identifiers to and from those two formats during schema level communication, such as reflection of tables and indexes. Using an UPPERCASE name on the SQLAlchemy side indicates a case sensitive identifier, and SQLAlchemy will quote the name - this will cause mismatches against data dictionary data received from Oracle, so unless identifier names have been truly created as case sensitive (i.e. using quoted names), all lowercase names should be used on the SQLAlchemy side.

LIMIT/OFFSET Support

Oracle has no support for the LIMIT or OFFSET keywords. SQLAlchemy uses a wrapped subquery approach in conjunction with ROWNUM. The exact methodology is taken from http://www.oracle.com/technetwork/issue-archive/2006/06-sep/o56asktom-086197.html .

There are two options which affect its behavior:

  • the “FIRST ROWS()” optimization keyword is not used by default. To enable the usage of this optimization directive, specify optimize_limits=True to create_engine().

  • the values passed for the limit/offset are sent as bound parameters. Some users have observed that Oracle produces a poor query plan when the values are sent as binds and not rendered literally. To render the limit/offset values literally within the SQL statement, specify use_binds_for_limits=False to create_engine().

Some users have reported better performance when the entirely different approach of a window query is used, i.e. ROW_NUMBER() OVER (ORDER BY), to provide LIMIT/OFFSET (note that the majority of users don’t observe this). To suit this case the method used for LIMIT/OFFSET can be replaced entirely. See the recipe at http://www.sqlalchemy.org/trac/wiki/UsageRecipes/WindowFunctionsByDefault which installs a select compiler that overrides the generation of limit/offset with a window function.

RETURNING Support

The Oracle database supports a limited form of RETURNING, in order to retrieve result sets of matched rows from INSERT, UPDATE and DELETE statements. Oracle’s RETURNING..INTO syntax only supports one row being returned, as it relies upon OUT parameters in order to function. In addition, supported DBAPIs have further limitations (see RETURNING Support).

SQLAlchemy’s “implicit returning” feature, which employs RETURNING within an INSERT and sometimes an UPDATE statement in order to fetch newly generated primary key values and other SQL defaults and expressions, is normally enabled on the Oracle backend. By default, “implicit returning” typically only fetches the value of a single nextval(some_seq) expression embedded into an INSERT in order to increment a sequence within an INSERT statement and get the value back at the same time. To disable this feature across the board, specify implicit_returning=False to create_engine():

engine = create_engine("oracle://scott:tiger@dsn",
                       implicit_returning=False)

Implicit returning can also be disabled on a table-by-table basis as a table option:

# Core Table
my_table = Table("my_table", metadata, ..., implicit_returning=False)


# declarative
class MyClass(Base):
    __tablename__ = 'my_table'
    __table_args__ = {"implicit_returning": False}

See also

RETURNING Support - additional cx_oracle-specific restrictions on implicit returning.

ON UPDATE CASCADE

Oracle doesn’t have native ON UPDATE CASCADE functionality. A trigger based solution is available at http://asktom.oracle.com/tkyte/update_cascade/index.html .

When using the SQLAlchemy ORM, the ORM has limited ability to manually issue cascading updates - specify ForeignKey objects using the “deferrable=True, initially=’deferred’” keyword arguments, and specify “passive_updates=False” on each relationship().

Oracle 8 Compatibility

When Oracle 8 is detected, the dialect internally configures itself to the following behaviors:

  • the use_ansi flag is set to False. This has the effect of converting all JOIN phrases into the WHERE clause, and in the case of LEFT OUTER JOIN makes use of Oracle’s (+) operator.

  • the NVARCHAR2 and NCLOB datatypes are no longer generated as DDL when the Unicode is used - VARCHAR2 and CLOB are issued instead. This because these types don’t seem to work correctly on Oracle 8 even though they are available. The NVARCHAR and NCLOB types will always generate NVARCHAR2 and NCLOB.

  • the “native unicode” mode is disabled when using cx_oracle, i.e. SQLAlchemy encodes all Python unicode objects to “string” before passing in as bind parameters.

Constraint Reflection

The Oracle dialect can return information about foreign key, unique, and CHECK constraints, as well as indexes on tables.

Raw information regarding these constraints can be acquired using Inspector.get_foreign_keys(), Inspector.get_unique_constraints(), Inspector.get_check_constraints(), and Inspector.get_indexes().

Changed in version 1.2: The Oracle dialect can now reflect UNIQUE and CHECK constraints.

When using reflection at the Table level, the Table will also include these constraints.

Note the following caveats:

  • When using the Inspector.get_check_constraints() method, Oracle builds a special “IS NOT NULL” constraint for columns that specify “NOT NULL”. This constraint is not returned by default; to include the “IS NOT NULL” constraints, pass the flag include_all=True:

    from sqlalchemy import create_engine, inspect
    
    engine = create_engine("oracle+cx_oracle://s:t@dsn")
    inspector = inspect(engine)
    all_check_constraints = inspector.get_check_constraints(
        "some_table", include_all=True)
  • in most cases, when reflecting a Table, a UNIQUE constraint will not be available as a UniqueConstraint object, as Oracle mirrors unique constraints with a UNIQUE index in most cases (the exception seems to be when two or more unique constraints represent the same columns); the Table will instead represent these using Index with the unique=True flag set.

  • Oracle creates an implicit index for the primary key of a table; this index is excluded from all index results.

  • the list of columns reflected for an index will not include column names that start with SYS_NC.

Table names with SYSTEM/SYSAUX tablespaces

The Inspector.get_table_names() and Inspector.get_temp_table_names() methods each return a list of table names for the current engine. These methods are also part of the reflection which occurs within an operation such as MetaData.reflect(). By default, these operations exclude the SYSTEM and SYSAUX tablespaces from the operation. In order to change this, the default list of tablespaces excluded can be changed at the engine level using the exclude_tablespaces parameter:

# exclude SYSAUX and SOME_TABLESPACE, but not SYSTEM
e = create_engine(
  "oracle://scott:tiger@xe",
  exclude_tablespaces=["SYSAUX", "SOME_TABLESPACE"])

New in version 1.1.

DateTime Compatibility

Oracle has no datatype known as DATETIME, it instead has only DATE, which can actually store a date and time value. For this reason, the Oracle dialect provides a type DATE which is a subclass of DateTime. This type has no special behavior, and is only present as a “marker” for this type; additionally, when a database column is reflected and the type is reported as DATE, the time-supporting DATE type is used.

Changed in version 0.9.4: Added DATE to subclass DateTime. This is a change as previous versions would reflect a DATE column as DATE, which subclasses Date. The only significance here is for schemes that are examining the type of column for use in special Python translations or for migrating schemas to other database backends.

Oracle Table Options

The CREATE TABLE phrase supports the following options with Oracle in conjunction with the Table construct:

  • ON COMMIT:

    Table(
        "some_table", metadata, ...,
        prefixes=['GLOBAL TEMPORARY'], oracle_on_commit='PRESERVE ROWS')

New in version 1.0.0.

  • COMPRESS:

     Table('mytable', metadata, Column('data', String(32)),
         oracle_compress=True)
    
     Table('mytable', metadata, Column('data', String(32)),
         oracle_compress=6)
    
    The ``oracle_compress`` parameter accepts either an integer compression
    level, or ``True`` to use the default compression level.

New in version 1.0.0.

Oracle Specific Index Options

Bitmap Indexes

You can specify the oracle_bitmap parameter to create a bitmap index instead of a B-tree index:

Index('my_index', my_table.c.data, oracle_bitmap=True)

Bitmap indexes cannot be unique and cannot be compressed. SQLAlchemy will not check for such limitations, only the database will.

New in version 1.0.0.

Index compression

Oracle has a more efficient storage mode for indexes containing lots of repeated values. Use the oracle_compress parameter to turn on key compression:

Index('my_index', my_table.c.data, oracle_compress=True)

Index('my_index', my_table.c.data1, my_table.c.data2, unique=True,
       oracle_compress=1)

The oracle_compress parameter accepts either an integer specifying the number of prefix columns to compress, or True to use the default (all columns for non-unique indexes, all but the last column for unique indexes).

New in version 1.0.0.

Oracle Data Types

As with all SQLAlchemy dialects, all UPPERCASE types that are known to be valid with Oracle are importable from the top level dialect, whether they originate from sqlalchemy.types or from the local dialect:

from sqlalchemy.dialects.oracle import \
            BFILE, BLOB, CHAR, CLOB, DATE, \
            DOUBLE_PRECISION, FLOAT, INTERVAL, LONG, NCLOB, NCHAR, \
            NUMBER, NVARCHAR, NVARCHAR2, RAW, TIMESTAMP, VARCHAR, \
            VARCHAR2

New in version 1.2.19: Added NCHAR to the list of datatypes exported by the Oracle dialect.

Types which are specific to Oracle, or have Oracle-specific construction arguments, are as follows:

Object Name Description

BFILE

DATE

Provide the oracle DATE type.

DOUBLE_PRECISION

INTERVAL

LONG

NCLOB

NUMBER

RAW

class sqlalchemy.dialects.oracle.BFILE(length=None)

Members

__init__()

method sqlalchemy.dialects.oracle.BFILE.__init__(length=None)

inherited from the sqlalchemy.types.LargeBinary.__init__ method of LargeBinary

Construct a LargeBinary type.

Parameters:

length – optional, a length for the column for use in DDL statements, for those binary types that accept a length, such as the MySQL BLOB type.

class sqlalchemy.dialects.oracle.DATE(timezone=False)

Provide the oracle DATE type.

This type has no special Python behavior, except that it subclasses DateTime; this is to suit the fact that the Oracle DATE type supports a time value.

New in version 0.9.4.

Members

__init__()

method sqlalchemy.dialects.oracle.DATE.__init__(timezone=False)

inherited from the sqlalchemy.types.DateTime.__init__ method of DateTime

Construct a new DateTime.

Parameters:

timezone – boolean. Indicates that the datetime type should enable timezone support, if available on the base date/time-holding type only. It is recommended to make use of the TIMESTAMP datatype directly when using this flag, as some databases include separate generic date/time-holding types distinct from the timezone-capable TIMESTAMP datatype, such as Oracle.

class sqlalchemy.dialects.oracle.DOUBLE_PRECISION(precision=None, asdecimal=False, decimal_return_scale=None, **kwargs)

Members

__init__()

method sqlalchemy.dialects.oracle.DOUBLE_PRECISION.__init__(precision=None, asdecimal=False, decimal_return_scale=None, **kwargs)

inherited from the sqlalchemy.types.Float.__init__ method of Float

Construct a Float.

Parameters:
  • precision – the numeric precision for use in DDL CREATE TABLE.

  • asdecimal – the same flag as that of Numeric, but defaults to False. Note that setting this flag to True results in floating point conversion.

  • decimal_return_scale

    Default scale to use when converting from floats to Python decimals. Floating point values will typically be much longer due to decimal inaccuracy, and most floating point database types don’t have a notion of “scale”, so by default the float type looks for the first ten decimal places when converting. Specifying this value will override that length. Note that the MySQL float types, which do include “scale”, will use “scale” as the default for decimal_return_scale, if not otherwise specified.

    New in version 0.9.0.

  • **kwargs

    Deprecated since version 0.9: Additional keyword arguments are ignored by the base Float type, and keyword arguments will no longer be accepted in a future release. For database specific floats that support additional arguments, see that dialect’s documentation for details, such as sqlalchemy.dialects.mysql.FLOAT.

class sqlalchemy.dialects.oracle.INTERVAL(day_precision=None, second_precision=None)

Members

__init__()

method sqlalchemy.dialects.oracle.INTERVAL.__init__(day_precision=None, second_precision=None)

Construct an INTERVAL.

Note that only DAY TO SECOND intervals are currently supported. This is due to a lack of support for YEAR TO MONTH intervals within available DBAPIs (cx_oracle and zxjdbc).

Parameters:
  • day_precision – the day precision value. this is the number of digits to store for the day field. Defaults to “2”

  • second_precision – the second precision value. this is the number of digits to store for the fractional seconds field. Defaults to “6”.

class sqlalchemy.dialects.oracle.NCLOB(length=None, collation=None, convert_unicode=False, unicode_error=None, _warn_on_bytestring=False)

Members

__init__()

method sqlalchemy.dialects.oracle.NCLOB.__init__(length=None, collation=None, convert_unicode=False, unicode_error=None, _warn_on_bytestring=False)

inherited from the sqlalchemy.types.String.__init__ method of String

Create a string-holding type.

Parameters:
  • length – optional, a length for the column for use in DDL and CAST expressions. May be safely omitted if no CREATE TABLE will be issued. Certain databases may require a length for use in DDL, and will raise an exception when the CREATE TABLE DDL is issued if a VARCHAR with no length is included. Whether the value is interpreted as bytes or characters is database specific.

  • collation

    Optional, a column-level collation for use in DDL and CAST expressions. Renders using the COLLATE keyword supported by SQLite, MySQL, and PostgreSQL. E.g.:

    >>> from sqlalchemy import cast, select, String
    >>> print select([cast('some string', String(collation='utf8'))])
    SELECT CAST(:param_1 AS VARCHAR COLLATE utf8) AS anon_1

  • convert_unicode

    When set to True, the String type will assume that input is to be passed as Python Unicode objects under Python 2, and results returned as Python Unicode objects. In the rare circumstance that the DBAPI does not support Python unicode under Python 2, SQLAlchemy will use its own encoder/decoder functionality on strings, referring to the value of the create_engine.encoding parameter parameter passed to create_engine() as the encoding.

    For the extremely rare case that Python Unicode is to be encoded/decoded by SQLAlchemy on a backend that does natively support Python Unicode, the string value "force" can be passed here which will cause SQLAlchemy’s encode/decode services to be used unconditionally.

    Note

    SQLAlchemy’s unicode-conversion flags and features only apply to Python 2; in Python 3, all string objects are Unicode objects. For this reason, as well as the fact that virtually all modern DBAPIs now support Unicode natively even under Python 2, the String.convert_unicode flag is inherently a legacy feature.

    Note

    In the vast majority of cases, the Unicode or UnicodeText datatypes should be used for a Column that expects to store non-ascii data. These datatypes will ensure that the correct types are used on the database side as well as set up the correct Unicode behaviors under Python 2.

    See also

    create_engine.convert_unicode - Engine-wide parameter

  • unicode_error – Optional, a method to use to handle Unicode conversion errors. Behaves like the errors keyword argument to the standard library’s string.decode() functions. This flag requires that String.convert_unicode is set to "force" - otherwise, SQLAlchemy is not guaranteed to handle the task of unicode conversion. Note that this flag adds significant performance overhead to row-fetching operations for backends that already return unicode objects natively (which most DBAPIs do). This flag should only be used as a last resort for reading strings from a column with varied or corrupted encodings.

class sqlalchemy.dialects.oracle.NUMBER(precision=None, scale=None, asdecimal=None)
class sqlalchemy.dialects.oracle.LONG(length=None, collation=None, convert_unicode=False, unicode_error=None, _warn_on_bytestring=False)

Members

__init__()

method sqlalchemy.dialects.oracle.LONG.__init__(length=None, collation=None, convert_unicode=False, unicode_error=None, _warn_on_bytestring=False)

inherited from the sqlalchemy.types.String.__init__ method of String

Create a string-holding type.

Parameters:
  • length – optional, a length for the column for use in DDL and CAST expressions. May be safely omitted if no CREATE TABLE will be issued. Certain databases may require a length for use in DDL, and will raise an exception when the CREATE TABLE DDL is issued if a VARCHAR with no length is included. Whether the value is interpreted as bytes or characters is database specific.

  • collation

    Optional, a column-level collation for use in DDL and CAST expressions. Renders using the COLLATE keyword supported by SQLite, MySQL, and PostgreSQL. E.g.:

    >>> from sqlalchemy import cast, select, String
    >>> print select([cast('some string', String(collation='utf8'))])
    SELECT CAST(:param_1 AS VARCHAR COLLATE utf8) AS anon_1

  • convert_unicode

    When set to True, the String type will assume that input is to be passed as Python Unicode objects under Python 2, and results returned as Python Unicode objects. In the rare circumstance that the DBAPI does not support Python unicode under Python 2, SQLAlchemy will use its own encoder/decoder functionality on strings, referring to the value of the create_engine.encoding parameter parameter passed to create_engine() as the encoding.

    For the extremely rare case that Python Unicode is to be encoded/decoded by SQLAlchemy on a backend that does natively support Python Unicode, the string value "force" can be passed here which will cause SQLAlchemy’s encode/decode services to be used unconditionally.

    Note

    SQLAlchemy’s unicode-conversion flags and features only apply to Python 2; in Python 3, all string objects are Unicode objects. For this reason, as well as the fact that virtually all modern DBAPIs now support Unicode natively even under Python 2, the String.convert_unicode flag is inherently a legacy feature.

    Note

    In the vast majority of cases, the Unicode or UnicodeText datatypes should be used for a Column that expects to store non-ascii data. These datatypes will ensure that the correct types are used on the database side as well as set up the correct Unicode behaviors under Python 2.

    See also

    create_engine.convert_unicode - Engine-wide parameter

  • unicode_error – Optional, a method to use to handle Unicode conversion errors. Behaves like the errors keyword argument to the standard library’s string.decode() functions. This flag requires that String.convert_unicode is set to "force" - otherwise, SQLAlchemy is not guaranteed to handle the task of unicode conversion. Note that this flag adds significant performance overhead to row-fetching operations for backends that already return unicode objects natively (which most DBAPIs do). This flag should only be used as a last resort for reading strings from a column with varied or corrupted encodings.

class sqlalchemy.dialects.oracle.RAW(length=None)

Class signature

class sqlalchemy.dialects.oracle.RAW (sqlalchemy.types._Binary)

cx_Oracle

Support for the Oracle database via the cx-Oracle driver.

DBAPI

Documentation and download information (if applicable) for cx-Oracle is available at: https://oracle.github.io/python-cx_Oracle/

Connecting

Connect String:

oracle+cx_oracle://user:pass@host:port/dbname[?key=value&key=value...]

Additional Connect Arguments

When connecting with the dbname URL token present, the hostname, port, and dbname tokens are converted to a TNS name using the cx_Oracle.makedsn() function. The URL below:

e = create_engine("oracle+cx_oracle://user:pass@hostname/dbname")

Will be used to create the DSN as follows:

>>> import cx_Oracle
>>> cx_Oracle.makedsn("hostname", 1521, sid="dbname")
'(DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=hostname)(PORT=1521))(CONNECT_DATA=(SID=dbname)))'

The service_name parameter, also consumed by cx_Oracle.makedsn(), may be specified in the URL query string, e.g. ?service_name=my_service.

If dbname is not present, then the value of hostname in the URL is used directly as the DSN passed to cx_Oracle.connect().

Additional connection arguments may be sent to the cx_Oracle.connect() function using the create_engine.connect_args dictionary. Any cx_Oracle parameter value and/or constant may be passed, such as:

import cx_Oracle
e = create_engine(
    "oracle+cx_oracle://user:pass@dsn",
    connect_args={
        "mode": cx_Oracle.SYSDBA,
        "events": True
    }
)

There are also options that are consumed by the SQLAlchemy cx_oracle dialect itself. These options are always passed directly to create_engine(), such as:

e = create_engine(
    "oracle+cx_oracle://user:pass@dsn", coerce_to_unicode=False)

The parameters accepted by the cx_oracle dialect are as follows:

  • arraysize - set the cx_oracle.arraysize value on cursors, defaulted to 50. This setting is significant with cx_Oracle as the contents of LOB objects are only readable within a “live” row (e.g. within a batch of 50 rows).

  • auto_convert_lobs - defaults to True; See LOB Objects.

  • coerce_to_unicode - see Unicode for detail.

  • coerce_to_decimal - see Precision Numerics for detail.

  • threaded - this parameter is passed as the value of “threaded” to cx_Oracle.connect() and defaults to True, which is the opposite of cx_Oracle’s default. This parameter is deprecated and will default to False in version 1.3 of SQLAlchemy.

Unicode

The cx_Oracle DBAPI as of version 5 fully supports unicode, and has the ability to return string results as Python unicode objects natively.

When used in Python 3, cx_Oracle returns all strings as Python unicode objects (that is, plain str in Python 3). In Python 2, it will return as Python unicode those column values that are of type NVARCHAR or NCLOB. For column values that are of type VARCHAR or other non-unicode string types, it will return values as Python strings (e.g. bytestrings).

The cx_Oracle SQLAlchemy dialect presents several different options for the use case of receiving VARCHAR column values as Python unicode objects under Python 2:

  • When using Core expression objects as well as the ORM, SQLAlchemy’s unicode-decoding services are available, which are established by using either the Unicode datatype or by using the String datatype with String.convert_unicode set to True.

  • When using raw SQL strings, typing behavior can be added for unicode conversion using the text() construct:

    from sqlalchemy import text, Unicode
    result = conn.execute(
        text("select username from user").columns(username=Unicode))
  • Otherwise, when using raw SQL strings sent directly to an .execute() method without any Core typing behavior added, the flag coerce_to_unicode=True flag can be passed to create_engine() which will add an unconditional unicode processor to cx_Oracle for all string values:

    engine = create_engine("oracle+cx_oracle://dsn", coerce_to_unicode=True)

    The above approach will add significant latency to result-set fetches of plain string values.

Sending String Values as Unicode or Non-Unicode

As of SQLAlchemy 1.2.2, the cx_Oracle dialect unconditionally calls setinputsizes() for bound values that are passed as Python unicode objects. In Python 3, all string values are Unicode; for cx_Oracle, this corresponds to cx_Oracle.NCHAR being passed to setinputsizes() for that parameter. In some edge cases, such as passing format specifiers for the trunc() function, Oracle does not accept these as NCHAR:

from sqlalchemy import func

conn.execute(
    func.trunc(func.sysdate(), 'dd')
)

In these cases, an error as follows may be raised:

ORA-01899: bad precision specifier

When this error is encountered, it may be necessary to pass the string value with an explicit non-unicode type:

from sqlalchemy import func
from sqlalchemy import literal
from sqlalchemy import String

conn.execute(
    func.trunc(func.sysdate(), literal('dd', String))
)

For full control over this setinputsizes() behavior, see the section Fine grained control over cx_Oracle data binding performance with setinputsizes

Fine grained control over cx_Oracle data binding performance with setinputsizes

The cx_Oracle DBAPI has a deep and fundamental reliance upon the usage of the DBAPI setinputsizes() call. The purpose of this call is to establish the datatypes that are bound to a SQL statement for Python values being passed as parameters. While virtually no other DBAPI assigns any use to the setinputsizes() call, the cx_Oracle DBAPI relies upon it heavily in its interactions with the Oracle client interface, and in some scenarios it is not possible for SQLAlchemy to know exactly how data should be bound, as some settings can cause profoundly different performance characteristics, while altering the type coercion behavior at the same time.

Users of the cx_Oracle dialect are strongly encouraged to read through cx_Oracle’s list of built-in datatype symbols at http://cx-oracle.readthedocs.io/en/latest/module.html#types. Note that in some cases, significant performance degradation can occur when using these types vs. not, in particular when specifying cx_Oracle.CLOB.

On the SQLAlchemy side, the DialectEvents.do_setinputsizes() event can be used both for runtime visibility (e.g. logging) of the setinputsizes step as well as to fully control how setinputsizes() is used on a per-statement basis.

New in version 1.2.9: Added DialectEvents.setinputsizes()

Example 1 - logging all setinputsizes calls

The following example illustrates how to log the intermediary values from a SQLAlchemy perspective before they are converted to the raw setinputsizes() parameter dictionary. The keys of the dictionary are BindParameter objects which have a .key and a .type attribute:

from sqlalchemy import create_engine, event

engine = create_engine("oracle+cx_oracle://scott:tiger@host/xe")

@event.listens_for(engine, "do_setinputsizes")
def _log_setinputsizes(inputsizes, cursor, statement, parameters, context):
    for bindparam, dbapitype in inputsizes.items():
            log.info(
                "Bound parameter name: %s  SQLAlchemy type: %r  "
                "DBAPI object: %s",
                bindparam.key, bindparam.type, dbapitype)

Example 2 - remove all bindings to CLOB

The CLOB datatype in cx_Oracle incurs a significant performance overhead, however is set by default for the Text type within the SQLAlchemy 1.2 series. This setting can be modified as follows:

from sqlalchemy import create_engine, event
from cx_Oracle import CLOB

engine = create_engine("oracle+cx_oracle://scott:tiger@host/xe")

@event.listens_for(engine, "do_setinputsizes")
def _remove_clob(inputsizes, cursor, statement, parameters, context):
    for bindparam, dbapitype in list(inputsizes.items()):
        if dbapitype is CLOB:
            del inputsizes[bindparam]

RETURNING Support

The cx_Oracle dialect implements RETURNING using OUT parameters. The dialect supports RETURNING fully, however cx_Oracle 6 is recommended for complete support.

LOB Objects

cx_oracle returns oracle LOBs using the cx_oracle.LOB object. SQLAlchemy converts these to strings so that the interface of the Binary type is consistent with that of other backends, which takes place within a cx_Oracle outputtypehandler.

cx_Oracle prior to version 6 would require that LOB objects be read before a new batch of rows would be read, as determined by the cursor.arraysize. As of the 6 series, this limitation has been lifted. Nevertheless, because SQLAlchemy pre-reads these LOBs up front, this issue is avoided in any case.

To disable the auto “read()” feature of the dialect, the flag auto_convert_lobs=False may be passed to create_engine(). Under the cx_Oracle 5 series, having this flag turned off means there is the chance of reading from a stale LOB object if not read as it is fetched. With cx_Oracle 6, this issue is resolved.

Changed in version 1.2: the LOB handling system has been greatly simplified internally to make use of outputtypehandlers, and no longer makes use of alternate “buffered” result set objects.

Two Phase Transactions Not Supported

Two phase transactions are not supported under cx_Oracle due to poor driver support. As of cx_Oracle 6.0b1, the interface for two phase transactions has been changed to be more of a direct pass-through to the underlying OCI layer with less automation. The additional logic to support this system is not implemented in SQLAlchemy.

Precision Numerics

SQLAlchemy’s numeric types can handle receiving and returning values as Python Decimal objects or float objects. When a Numeric object, or a subclass such as Float, DOUBLE_PRECISION etc. is in use, the Numeric.asdecimal flag determines if values should be coerced to Decimal upon return, or returned as float objects. To make matters more complicated under Oracle, Oracle’s NUMBER type can also represent integer values if the “scale” is zero, so the Oracle-specific NUMBER type takes this into account as well.

The cx_Oracle dialect makes extensive use of connection- and cursor-level “outputtypehandler” callables in order to coerce numeric values as requested. These callables are specific to the specific flavor of Numeric in use, as well as if no SQLAlchemy typing objects are present. There are observed scenarios where Oracle may sends incomplete or ambiguous information about the numeric types being returned, such as a query where the numeric types are buried under multiple levels of subquery. The type handlers do their best to make the right decision in all cases, deferring to the underlying cx_Oracle DBAPI for all those cases where the driver can make the best decision.

When no typing objects are present, as when executing plain SQL strings, a default “outputtypehandler” is present which will generally return numeric values which specify precision and scale as Python Decimal objects. To disable this coercion to decimal for performance reasons, pass the flag coerce_to_decimal=False to create_engine():

engine = create_engine("oracle+cx_oracle://dsn", coerce_to_decimal=False)

The coerce_to_decimal flag only impacts the results of plain string SQL staements that are not otherwise associated with a Numeric SQLAlchemy type (or a subclass of such).

Changed in version 1.2: The numeric handling system for cx_Oracle has been reworked to take advantage of newer cx_Oracle features as well as better integration of outputtypehandlers.

zxjdbc

Support for the Oracle database via the zxJDBC for Jython driver.

Note

Jython is not supported by current versions of SQLAlchemy. The zxjdbc dialect should be considered as experimental.

DBAPI

Drivers for this database are available at: http://www.oracle.com/technetwork/database/features/jdbc/index-091264.html

Connecting

Connect String:

oracle+zxjdbc://user:pass@host/dbname