Support for the Oracle database.
Oracle version 8 through current (11g at the time of this writing) are supported.
For information on connecting via specific drivers, see the documentation for that driver.
The dialect supports several create_engine() arguments which affect the behavior of the dialect regardless of driver in use.
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
)
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.
SQLAlchemy 0.6 uses the “native unicode” mode provided as of cx_oracle 5. cx_oracle 5.0.2 or greater is recommended for support of NCLOB. If not using cx_oracle 5, the NLS_LANG environment variable needs to be set in order for the oracle client library to use proper encoding, such as “AMERICAN_AMERICA.UTF8”.
Also note that Oracle supports unicode data through the NVARCHAR and NCLOB data types. When using the SQLAlchemy Unicode and UnicodeText types, these DDL types will be used within CREATE TABLE statements. Usage of VARCHAR2 and CLOB with unicode text still requires NLS_LANG to be set.
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/technology/oramag/oracle/06-sep/o56asktom.html .
There are two options which affect its behavior:
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.
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().
When Oracle 8 is detected, the dialect internally configures itself to the following behaviors:
When using reflection with Table objects, the dialect can optionally search for tables indicated by synonyms that reference DBLINK-ed tables by passing the flag oracle_resolve_synonyms=True as a keyword argument to the Table construct. If DBLINK is not in use this flag should be left off.
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, DATETIME, \
DOUBLE_PRECISION, FLOAT, INTERVAL, LONG, NCLOB, \
NUMBER, NVARCHAR, NVARCHAR2, RAW, TIMESTAMP, VARCHAR, \
VARCHAR2
Types which are specific to Oracle, or have Oracle-specific construction arguments, are as follows:
Bases: sqlalchemy.types.LargeBinary
Construct a LargeBinary type.
Parameters: | length – optional, a length for the column for use in DDL statements, for those BLOB types that accept a length (i.e. MySQL). It does not produce a small BINARY/VARBINARY type - use the BINARY/VARBINARY types specifically for those. 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. |
---|
Bases: sqlalchemy.types.Numeric
Bases: sqlalchemy.types.TypeEngine
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: |
|
---|
Bases: sqlalchemy.types.Text
Create a string-holding type.
Parameters: |
|
---|
Bases: sqlalchemy.types.Text
Create a string-holding type.
Parameters: |
|
---|
Bases: sqlalchemy.types._Binary
Support for the Oracle database via the cx_oracle driver.
The Oracle dialect uses the cx_oracle driver, available at http://cx-oracle.sourceforge.net/ . The dialect has several behaviors which are specifically tailored towards compatibility with this module. Version 5.0 or greater is strongly recommended, as SQLAlchemy makes extensive use of the cx_oracle output converters for numeric and string conversions.
Connecting with create_engine() uses the standard URL approach of oracle://user:pass@host:port/dbname[?key=value&key=value...]. If dbname is present, the host, port, and dbname tokens are converted to a TNS name using the cx_oracle makedsn() function. Otherwise, the host token is taken directly as a TNS name.
Additional arguments which may be specified either as query string arguments on the URL, or as keyword arguments to create_engine() are:
cx_oracle 5 fully supports Python unicode objects. SQLAlchemy will pass all unicode strings directly to cx_oracle, and additionally uses an output handler so that all string based result values are returned as unicode as well.
Note that this behavior is disabled when Oracle 8 is detected, as it has been observed that issues remain when passing Python unicodes to cx_oracle with Oracle 8.
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, and so that the linkage to a live cursor is not needed in scenarios like result.fetchmany() and result.fetchall(). This means that by default, LOB objects are fully fetched unconditionally by SQLAlchemy, and the linkage to a live cursor is broken.
To disable this processing, pass auto_convert_lobs=False to create_engine().
Two Phase transactions are implemented using XA transactions. Success has been reported with this feature but it should be regarded as experimental.
The SQLAlchemy dialect goes thorugh a lot of steps to ensure that decimal numbers are sent and received with full accuracy. An “outputtypehandler” callable is associated with each cx_oracle connection object which detects numeric types and receives them as string values, instead of receiving a Python float directly, which is then passed to the Python Decimal constructor. The Numeric and Float types under the cx_oracle dialect are aware of this behavior, and will coerce the Decimal to float if the asdecimal flag is False (default on Float, optional on Numeric).
The handler attempts to use the “precision” and “scale” attributes of the result set column to best determine if subsequent incoming values should be received as Decimal as opposed to int (in which case no processing is added). There are several scenarios where OCI does not provide unambiguous data as to the numeric type, including some situations where individual rows may return a combination of floating point and integer values. Certain values for “precision” and “scale” have been observed to determine this scenario. When it occurs, the outputtypehandler receives as string and then passes off to a processing function which detects, for each returned value, if a decimal point is present, and if so converts to Decimal, otherwise to int. The intention is that simple int-based statements like “SELECT my_seq.nextval() FROM DUAL” continue to return ints and not Decimal objects, and that any kind of floating point value is received as a string so that there is no floating point loss of precision.
The “decimal point is present” logic itself is also sensitive to locale. Under OCI, this is controlled by the NLS_LANG environment variable. Upon first connection, the dialect runs a test to determine the current “decimal” character, which can be a comma ”,” for european locales. From that point forward the outputtypehandler uses that character to represent a decimal point (this behavior is new in version 0.6.6). Note that cx_oracle 5.0.3 or greater is required when dealing with numerics with locale settings that don’t use a period ”.” as the decimal character.
Support for the Oracle database via the zxjdbc JDBC connector.
The official Oracle JDBC driver is at http://www.oracle.com/technology/software/tech/java/sqlj_jdbc/index.html.