From: Mike Bayer Date: Fri, 24 Oct 2008 15:58:17 +0000 (+0000) Subject: - fixed some oracle unit tests in test/sql/ X-Git-Tag: rel_0_5rc3~49 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=3bbf8037f8408b590d64624b7ce71963053f555c;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git - fixed some oracle unit tests in test/sql/ - wrote a docstring for oracle dialect, needs formatting perhaps - made FIRST_ROWS optimization optional based on optimize_limits=True, [ticket:536] --- diff --git a/CHANGES b/CHANGES index f934b716d1..41fa821a02 100644 --- a/CHANGES +++ b/CHANGES @@ -52,6 +52,14 @@ CHANGES against self. More portable, but breaks with stored procedures that aren't pure functions. +- oracle + - Removed FIRST_ROWS() optimize flag when using LIMIT/OFFSET, + can be reenabled with optimize_limits=True create_engine() + flag. [ticket:536] + + - Wrote a docstring for Oracle dialect. Apparently that + Ohloh "few source code comments" label is starting to sting + :). 0.5.0rc2 ======== - orm diff --git a/lib/sqlalchemy/databases/oracle.py b/lib/sqlalchemy/databases/oracle.py index 3f2540ac08..7be33d269f 100644 --- a/lib/sqlalchemy/databases/oracle.py +++ b/lib/sqlalchemy/databases/oracle.py @@ -3,7 +3,119 @@ # # This module is part of SQLAlchemy and is released under # the MIT License: http://www.opensource.org/licenses/mit-license.php +"""Support for the Oracle database. +Oracle version 8 through current (11g at the time of this writing) are supported. + +Driver + +The Oracle dialect uses the cx_oracle driver, available at +http://python.net/crew/atuining/cx_Oracle/ . The dialect has several behaviors +which are specifically tailored towards compatibility with this module. + +Connecting + +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() include: + + mode - This is given the string value of SYSDBA or SYSOPER, or alternatively an + integer value. This value is only available as a URL query string argument. + + allow_twophase - enable two-phase transactions. This feature is not yet supported. + + threaded - defaults to True with SQLAlchemy, enable multithreaded access to + cx_oracle connections. + + use_ansi - defaults to True, use ANSI JOIN constructs (see the section on Oracle 8). + + auto_convert_lobs - defaults to True, see the section on LOB objects. + + auto_setinputsizes - the cx_oracle.setinputsizes() call is issued for all bind parameters. + This is required for LOB datatypes but can be disabled to reduce overhead. + + optimize_limits - defaults to False, 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 + ) + +LOB Objects + +cx_oracle presents some challenges when fetching LOB objects. A LOB object in a result set +is presented by cx_oracle as a cx_oracle.LOB object which has a read() method. By default, +SQLAlchemy converts these LOB objects into Python strings. This is for two reasons. First, +the LOB object requires an active cursor association, meaning if you were to fetch many rows +at once such that cx_oracle had to go back to the database and fetch a new batch of rows, +the LOB objects in the already-fetched rows are now unreadable and will raise an error. +SQLA "pre-reads" all LOBs so that their data is fetched before further rows are read. +The size of a "batch of rows" is controlled by the cursor.arraysize value, which SQLAlchemy +defaults to 50 (cx_oracle normally defaults this to one). + +Secondly, the LOB object is not a standard DBAPI return value so SQLAlchemy seeks to +"normalize" the results to look more like other DBAPIs. + +The conversion of LOB objects by this dialect is unique in SQLAlchemy in that it takes place +for all statement executions, even plain string-based statements for which SQLA has no awareness +of result typing. This is so that calls like fetchmany() and fetchall() can work in all cases +without raising cursor errors. The conversion of LOB in all cases, as well as the "prefetch" +of LOB objects, can be disabled using auto_convert_lobs=False. However, OracleBinary type +objects will still issue the conversion of LOBs upon access - use a string-based or otherwise +untyped select() construct, or a custom Binary type, to retrieve LOB objects directly in this case. +A future release may include a flag on OracleBinary to further disable LOB conversion at that level. + +LIMIT/OFFSET Support + +Oracle has no support for the LIMIT or OFFSET keywords. Whereas previous versions of SQLAlchemy +used the "ROW NUMBER OVER..." construct to simulate LIMIT/OFFSET, SQLAlchemy 0.5 now 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 . Note that the +"FIRST ROWS()" optimization keyword mentioned is not used by default, as the user community felt +this was stepping into the bounds of optimization that is better left on the DBA side, but this +prefix can be added by enabling the optimize_limits=True flag on create_engine(). + +Two Phase Transaction Support + +Two Phase transactions are partially implemented using XA transactions but at the time of this +writing have not been successfully tested. The author of cx_oracle also stated that he's never +seen them work so this may be a cx_oracle issue. + +Oracle 8 Compatibility + +When using Oracle 8, a "use_ansi=False" flag is available which converts all +JOIN phrases into the WHERE clause, and in the case of LEFT OUTER JOIN +makes use of Oracle's (+) operator. + +Synonym/DBLINK Reflection + +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. + +""" import datetime, random, re @@ -247,12 +359,13 @@ class OracleDialect(default.DefaultDialect): supports_pk_autoincrement = False default_paramstyle = 'named' - def __init__(self, use_ansi=True, auto_setinputsizes=True, auto_convert_lobs=True, threaded=True, allow_twophase=True, arraysize=50, **kwargs): + def __init__(self, use_ansi=True, auto_setinputsizes=True, auto_convert_lobs=True, threaded=True, allow_twophase=True, optimize_limits=False, arraysize=50, **kwargs): default.DefaultDialect.__init__(self, **kwargs) self.use_ansi = use_ansi self.threaded = threaded self.arraysize = arraysize self.allow_twophase = allow_twophase + self.optimize_limits = optimize_limits self.supports_timestamp = self.dbapi is None or hasattr(self.dbapi, 'TIMESTAMP' ) self.auto_setinputsizes = auto_setinputsizes self.auto_convert_lobs = auto_convert_lobs @@ -689,7 +802,7 @@ class OracleCompiler(compiler.DefaultCompiler): # Wrap the middle select and add the hint limitselect = sql.select([c for c in select.c]) - if select._limit: + if select._limit and self.dialect.optimize_limits: limitselect = limitselect.prefix_with("/*+ FIRST_ROWS(%d) */" % select._limit) limitselect._oracle_visit = True diff --git a/test/dialect/oracle.py b/test/dialect/oracle.py index 952df29012..10cc94193d 100644 --- a/test/dialect/oracle.py +++ b/test/dialect/oracle.py @@ -60,7 +60,7 @@ class CompileTest(TestBase, AssertsCompiledSQL): s = select([t]).limit(10).offset(20) - self.assert_compile(s, "SELECT col1, col2 FROM (SELECT /*+ FIRST_ROWS(10) */ col1, col2, ROWNUM AS ora_rn " + self.assert_compile(s, "SELECT col1, col2 FROM (SELECT col1, col2, ROWNUM AS ora_rn " "FROM (SELECT sometable.col1 AS col1, sometable.col2 AS col2 " "FROM sometable) WHERE ROWNUM <= :ROWNUM_1) WHERE ora_rn > :ora_rn_1" ) @@ -72,14 +72,14 @@ class CompileTest(TestBase, AssertsCompiledSQL): s = select([s.c.col1, s.c.col2]) - self.assert_compile(s, "SELECT col1, col2 FROM (SELECT col1, col2 FROM (SELECT /*+ FIRST_ROWS(10) */ col1, col2, ROWNUM AS ora_rn FROM (SELECT sometable.col1 AS col1, sometable.col2 AS col2 FROM sometable) WHERE ROWNUM <= :ROWNUM_1) WHERE ora_rn > :ora_rn_1)") + self.assert_compile(s, "SELECT col1, col2 FROM (SELECT col1, col2 FROM (SELECT col1, col2, ROWNUM AS ora_rn FROM (SELECT sometable.col1 AS col1, sometable.col2 AS col2 FROM sometable) WHERE ROWNUM <= :ROWNUM_1) WHERE ora_rn > :ora_rn_1)") # testing this twice to ensure oracle doesn't modify the original statement - self.assert_compile(s, "SELECT col1, col2 FROM (SELECT col1, col2 FROM (SELECT /*+ FIRST_ROWS(10) */ col1, col2, ROWNUM AS ora_rn FROM (SELECT sometable.col1 AS col1, sometable.col2 AS col2 FROM sometable) WHERE ROWNUM <= :ROWNUM_1) WHERE ora_rn > :ora_rn_1)") + self.assert_compile(s, "SELECT col1, col2 FROM (SELECT col1, col2 FROM (SELECT col1, col2, ROWNUM AS ora_rn FROM (SELECT sometable.col1 AS col1, sometable.col2 AS col2 FROM sometable) WHERE ROWNUM <= :ROWNUM_1) WHERE ora_rn > :ora_rn_1)") s = select([t]).limit(10).offset(20).order_by(t.c.col2) - self.assert_compile(s, "SELECT col1, col2 FROM (SELECT /*+ FIRST_ROWS(10) */ col1, col2, ROWNUM " + self.assert_compile(s, "SELECT col1, col2 FROM (SELECT col1, col2, ROWNUM " "AS ora_rn FROM (SELECT sometable.col1 AS col1, sometable.col2 AS col2 FROM sometable " "ORDER BY sometable.col2) WHERE ROWNUM <= :ROWNUM_1) WHERE ora_rn > :ora_rn_1") @@ -132,7 +132,7 @@ AND mytable.myid = myothertable.otherid(+)", self.assert_compile(query.select().order_by(table1.c.name).limit(10).offset(5), "SELECT myid, name, description, otherid, othername, userid, " - "otherstuff FROM (SELECT /*+ FIRST_ROWS(10) */ myid, name, description, " + "otherstuff FROM (SELECT myid, name, description, " "otherid, othername, userid, otherstuff, ROWNUM AS ora_rn FROM (SELECT " "mytable.myid AS myid, mytable.name AS name, mytable.description AS description, " "myothertable.otherid AS otherid, myothertable.othername AS othername, " diff --git a/test/sql/defaults.py b/test/sql/defaults.py index 169d60c670..de939f08d6 100644 --- a/test/sql/defaults.py +++ b/test/sql/defaults.py @@ -261,7 +261,7 @@ class DefaultTest(testing.TestBase): t.insert().execute() ctexec = sa.select([currenttime.label('now')], bind=testing.db).scalar() - l = t.select().execute() + l = t.select().order_by(t.c.col1).execute() today = datetime.date.today() eq_(l.fetchall(), [ (x, 'imthedefault', f, ts, ts, ctexec, True, False, @@ -475,6 +475,7 @@ class PKIncrementTest(_base.TablesTest): class EmptyInsertTest(testing.TestBase): @testing.exclude('sqlite', '<', (3, 3, 8), 'no empty insert support') + @testing.fails_on('oracle') def test_empty_insert(self): metadata = MetaData(testing.db) t1 = Table('t1', metadata, diff --git a/test/sql/query.py b/test/sql/query.py index 4decf3b687..3118aef646 100644 --- a/test/sql/query.py +++ b/test/sql/query.py @@ -200,7 +200,7 @@ class QueryTest(TestBase): self.assert_(not (rp != equal)) self.assert_(not (equal != equal)) - @testing.fails_on('mssql') + @testing.fails_on('mssql', 'oracle') def test_or_and_as_columns(self): true, false = literal(True), literal(False)