From: Mike Bayer Date: Thu, 7 Apr 2011 17:47:43 +0000 (-0400) Subject: - The limit/offset keywords to select() as well X-Git-Tag: rel_0_6_7~6 X-Git-Url: http://git.ipfire.org/gitweb.cgi?a=commitdiff_plain;h=f5893458a1781b84edff390ba5220ed1c6393f32;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git - The limit/offset keywords to select() as well as the value passed to select.limit()/offset() will be coerced to integer. [ticket:2116] - Oracle dialect adds use_binds_for_limits=False create_engine() flag, will render the LIMIT/OFFSET values inline instead of as binds, reported to modify the execution plan used by Oracle. [ticket:2116] --- diff --git a/CHANGES b/CHANGES index 0ef914d1fa..45a586f7d9 100644 --- a/CHANGES +++ b/CHANGES @@ -66,6 +66,10 @@ CHANGES - Added accessors to ResultProxy "returns_rows", "is_insert" [ticket:2089] + - The limit/offset keywords to select() as well + as the value passed to select.limit()/offset() + will be coerced to integer. [ticket:2116] + - engine - Fixed bug in QueuePool, SingletonThreadPool whereby connections that were discarded via overflow or periodic @@ -119,6 +123,12 @@ CHANGES now properly translate bind parameter keys when talking to cx_oracle. [ticket:2100] + - Oracle dialect adds use_binds_for_limits=False + create_engine() flag, will render the LIMIT/OFFSET + values inline instead of as binds, reported to + modify the execution plan used by Oracle. + [ticket:2116] + - ext - The horizontal_shard ShardedSession class accepts the common Session argument "query_cls" as a constructor argument, diff --git a/lib/sqlalchemy/dialects/oracle/base.py b/lib/sqlalchemy/dialects/oracle/base.py index c487d66ce6..9db4e99233 100644 --- a/lib/sqlalchemy/dialects/oracle/base.py +++ b/lib/sqlalchemy/dialects/oracle/base.py @@ -22,6 +22,8 @@ affect the behavior of the dialect regardless of driver in use. * *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 ----------------------- @@ -74,13 +76,27 @@ requires NLS_LANG to be set. 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(). +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: + +* the "FIRST ROWS()" optimization keyword is not used by default. To enable the usage of this + optimization directive, specify ``optimize_limits=True`` to :func:`.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 :func:`.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. ON UPDATE CASCADE ----------------- @@ -523,6 +539,8 @@ class OracleCompiler(compiler.SQLCompiler): max_row = select._limit if select._offset is not None: max_row += select._offset + if not self.dialect.use_binds_for_limits: + max_row = sql.literal_column("%d" % max_row) limitselect.append_whereclause( sql.literal_column("ROWNUM")<=max_row) @@ -541,8 +559,11 @@ class OracleCompiler(compiler.SQLCompiler): offsetselect._oracle_visit = True offsetselect._is_wrapper = True + offset_value = select._offset + if not self.dialect.use_binds_for_limits: + offset_value = sql.literal_column("%d" % offset_value) offsetselect.append_whereclause( - sql.literal_column("ora_rn")>select._offset) + sql.literal_column("ora_rn")>offset_value) offsetselect.for_update = select.for_update select = offsetselect @@ -634,10 +655,12 @@ class OracleDialect(default.DefaultDialect): def __init__(self, use_ansi=True, optimize_limits=False, + use_binds_for_limits=True, **kwargs): default.DefaultDialect.__init__(self, **kwargs) self.use_ansi = use_ansi self.optimize_limits = optimize_limits + self.use_binds_for_limits = use_binds_for_limits def initialize(self, connection): super(OracleDialect, self).initialize(connection) diff --git a/lib/sqlalchemy/sql/expression.py b/lib/sqlalchemy/sql/expression.py index 2efbc3546c..cb7cfa10b6 100644 --- a/lib/sqlalchemy/sql/expression.py +++ b/lib/sqlalchemy/sql/expression.py @@ -3692,8 +3692,8 @@ class _SelectBaseMixin(Executable): self._execution_options = \ self._execution_options.union({'autocommit' : autocommit}) - self._limit = limit - self._offset = offset + self._limit = util.asint(limit) + self._offset = util.asint(offset) self._bind = bind self._order_by_clause = ClauseList(*util.to_list(order_by) or []) @@ -3760,14 +3760,14 @@ class _SelectBaseMixin(Executable): """return a new selectable with the given LIMIT criterion applied.""" - self._limit = limit + self._limit = util.asint(limit) @_generative def offset(self, offset): """return a new selectable with the given OFFSET criterion applied.""" - self._offset = offset + self._offset = util.asint(offset) @_generative def order_by(self, *clauses): diff --git a/lib/sqlalchemy/util.py b/lib/sqlalchemy/util.py index c5e24fa003..6b6f14be0e 100644 --- a/lib/sqlalchemy/util.py +++ b/lib/sqlalchemy/util.py @@ -596,6 +596,13 @@ def bool_or_str(*text): return asbool(obj) return bool_or_value +def asint(value): + """Coerce to integer.""" + + if value is None: + return value + return int(value) + def coerce_kw_type(kw, key, type_, flexi_bool=True): """If 'key' is present in dict 'kw', coerce its value to type 'type\_' if necessary. If 'flexi_bool' is True, the string '0' is considered false diff --git a/test/dialect/test_oracle.py b/test/dialect/test_oracle.py index 29bb58b505..163364633a 100644 --- a/test/dialect/test_oracle.py +++ b/test/dialect/test_oracle.py @@ -132,6 +132,49 @@ class CompileTest(TestBase, AssertsCompiledSQL): ':ROWNUM_1) WHERE ora_rn > :ora_rn_1 FOR ' 'UPDATE') + def test_use_binds_for_limits_disabled(self): + t = table('sometable', column('col1'), column('col2')) + dialect = oracle.OracleDialect(use_binds_for_limits = False) + + self.assert_compile(select([t]).limit(10), + "SELECT col1, col2 FROM (SELECT sometable.col1 AS col1, " + "sometable.col2 AS col2 FROM sometable) WHERE ROWNUM <= 10", + dialect=dialect) + + self.assert_compile(select([t]).offset(10), + "SELECT col1, col2 FROM (SELECT col1, col2, ROWNUM AS ora_rn " + "FROM (SELECT sometable.col1 AS col1, sometable.col2 AS col2 " + "FROM sometable)) WHERE ora_rn > 10", + dialect=dialect) + + self.assert_compile(select([t]).limit(10).offset(10), + "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 <= 20) WHERE ora_rn > 10", + dialect=dialect) + + def test_use_binds_for_limits_enabled(self): + t = table('sometable', column('col1'), column('col2')) + dialect = oracle.OracleDialect(use_binds_for_limits = True) + + self.assert_compile(select([t]).limit(10), + "SELECT col1, col2 FROM (SELECT sometable.col1 AS col1, " + "sometable.col2 AS col2 FROM sometable) WHERE ROWNUM " + "<= :ROWNUM_1", + dialect=dialect) + + self.assert_compile(select([t]).offset(10), + "SELECT col1, col2 FROM (SELECT col1, col2, ROWNUM AS ora_rn " + "FROM (SELECT sometable.col1 AS col1, sometable.col2 AS col2 " + "FROM sometable)) WHERE ora_rn > :ora_rn_1", + dialect=dialect) + + self.assert_compile(select([t]).limit(10).offset(10), + "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", + dialect=dialect) def test_long_labels(self): dialect = default.DefaultDialect() diff --git a/test/sql/test_compiler.py b/test/sql/test_compiler.py index e4f631130d..4e98e4be0b 100644 --- a/test/sql/test_compiler.py +++ b/test/sql/test_compiler.py @@ -7,6 +7,7 @@ from sqlalchemy.sql.expression import ClauseList from sqlalchemy.engine import default from sqlalchemy.databases import * from sqlalchemy.test import * +import decimal table1 = table('mytable', column('myid', Integer), @@ -90,6 +91,24 @@ class SelectTest(TestBase, AssertsCompiledSQL): assert_raises(exc.ArgumentError, select, table1) assert_raises(exc.ArgumentError, select, table1.c.myid) + def test_int_limit_offset_coercion(self): + for given, exp in [ + ("5", 5), + (5, 5), + (5.2, 5), + (decimal.Decimal("5"), 5), + (None, None), + ]: + eq_(select().limit(given)._limit, exp) + eq_(select().offset(given)._offset, exp) + eq_(select(limit=given)._limit, exp) + eq_(select(offset=given)._offset, exp) + + assert_raises(ValueError, select().limit, "foo") + assert_raises(ValueError, select().offset, "foo") + assert_raises(ValueError, select, offset="foo") + assert_raises(ValueError, select, limit="foo") + def test_from_subquery(self): """tests placing select statements in the column clause of another select, for the purposes of selecting from the exported columns of that select."""