collection of Sequence objects, list
of schema names. [ticket:2104]
+ - The limit/offset keywords to select() as well
+ as the value passed to select.limit()/offset()
+ will be coerced to integer. [ticket:2116]
+ (also in 0.6.7)
+
- schema
- The 'useexisting' flag on Table has been superceded
by a new pair of flags 'keep_existing' and
talking to cx_oracle. [ticket:2100] (Also
in 0.6.7)
+ - 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] (Also in 0.6.7)
+
- documentation
- Documented SQLite DATE/TIME/DATETIME types.
[ticket:2029] (also in 0.6.7)
* *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
-----------------------
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
-----------------
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)
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
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)
_order_by_clause = ClauseList()
_group_by_clause = ClauseList()
+ _limit = None
+ _offset = None
def __init__(self,
use_labels=False,
self._execution_options = \
self._execution_options.union({'autocommit'
: autocommit})
- self._limit = limit
- self._offset = offset
+ if limit is not None:
+ self._limit = util.asint(limit)
+ if offset is not None:
+ self._offset = util.asint(offset)
self._bind = bind
if order_by is not None:
"""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):
monkeypatch_proxied_specials, asbool, bool_or_str, coerce_kw_type,\
duck_type_collection, assert_arg_type, symbol, dictlike_iteritems,\
classproperty, set_creation_order, warn_exception, warn, NoneType,\
- constructor_copy, methods_equivalent, chop_traceback
+ constructor_copy, methods_equivalent, chop_traceback, asint
from deprecations import warn_deprecated, warn_pending_deprecation, \
deprecated, pending_deprecation
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
':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()
from test.lib.testing import eq_, assert_raises, assert_raises_message
-import datetime, re, operator
+import datetime, re, operator, decimal
from sqlalchemy import *
from sqlalchemy import exc, sql, util
from sqlalchemy.sql import table, column, label, compiler
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."""