Skip to content

Commit 51fea2e

Browse files
committed
- 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) - 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)
1 parent 708a25e commit 51fea2e

File tree

7 files changed

+121
-14
lines changed

7 files changed

+121
-14
lines changed

CHANGES

Lines changed: 11 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -58,6 +58,11 @@ CHANGES
5858
collection of Sequence objects, list
5959
of schema names. [ticket:2104]
6060

61+
- The limit/offset keywords to select() as well
62+
as the value passed to select.limit()/offset()
63+
will be coerced to integer. [ticket:2116]
64+
(also in 0.6.7)
65+
6166
- schema
6267
- The 'useexisting' flag on Table has been superceded
6368
by a new pair of flags 'keep_existing' and
@@ -101,6 +106,12 @@ CHANGES
101106
talking to cx_oracle. [ticket:2100] (Also
102107
in 0.6.7)
103108

109+
- Oracle dialect adds use_binds_for_limits=False
110+
create_engine() flag, will render the LIMIT/OFFSET
111+
values inline instead of as binds, reported to
112+
modify the execution plan used by Oracle.
113+
[ticket:2116] (Also in 0.6.7)
114+
104115
- documentation
105116
- Documented SQLite DATE/TIME/DATETIME types.
106117
[ticket:2029] (also in 0.6.7)

lib/sqlalchemy/dialects/oracle/base.py

Lines changed: 31 additions & 8 deletions
Original file line numberDiff line numberDiff line change
@@ -22,6 +22,8 @@
2222
2323
* *optimize_limits* - defaults to ``False``. see the section on LIMIT/OFFSET.
2424
25+
* *use_binds_for_limits* - defaults to ``True``. see the section on LIMIT/OFFSET.
26+
2527
Auto Increment Behavior
2628
-----------------------
2729
@@ -74,13 +76,27 @@
7476
LIMIT/OFFSET Support
7577
--------------------
7678
77-
Oracle has no support for the LIMIT or OFFSET keywords. Whereas previous versions of SQLAlchemy
78-
used the "ROW NUMBER OVER..." construct to simulate LIMIT/OFFSET, SQLAlchemy 0.5 now uses
79-
a wrapped subquery approach in conjunction with ROWNUM. The exact methodology is taken from
80-
http://www.oracle.com/technology/oramag/oracle/06-sep/o56asktom.html . Note that the
81-
"FIRST ROWS()" optimization keyword mentioned is not used by default, as the user community felt
82-
this was stepping into the bounds of optimization that is better left on the DBA side, but this
83-
prefix can be added by enabling the optimize_limits=True flag on create_engine().
79+
Oracle has no support for the LIMIT or OFFSET keywords. SQLAlchemy uses
80+
a wrapped subquery approach in conjunction with ROWNUM. The exact methodology
81+
is taken from
82+
http://www.oracle.com/technology/oramag/oracle/06-sep/o56asktom.html .
83+
84+
There are two options which affect its behavior:
85+
86+
* the "FIRST ROWS()" optimization keyword is not used by default. To enable the usage of this
87+
optimization directive, specify ``optimize_limits=True`` to :func:`.create_engine`.
88+
* the values passed for the limit/offset are sent as bound parameters. Some users have observed
89+
that Oracle produces a poor query plan when the values are sent as binds and not
90+
rendered literally. To render the limit/offset values literally within the SQL
91+
statement, specify ``use_binds_for_limits=False`` to :func:`.create_engine`.
92+
93+
Some users have reported better performance when the entirely different approach of a
94+
window query is used, i.e. ROW_NUMBER() OVER (ORDER BY), to provide LIMIT/OFFSET (note
95+
that the majority of users don't observe this). To suit this case the
96+
method used for LIMIT/OFFSET can be replaced entirely. See the recipe at
97+
http://www.sqlalchemy.org/trac/wiki/UsageRecipes/WindowFunctionsByDefault
98+
which installs a select compiler that overrides the generation of limit/offset with
99+
a window function.
84100
85101
ON UPDATE CASCADE
86102
-----------------
@@ -524,6 +540,8 @@ def visit_select(self, select, **kwargs):
524540
max_row = select._limit
525541
if select._offset is not None:
526542
max_row += select._offset
543+
if not self.dialect.use_binds_for_limits:
544+
max_row = sql.literal_column("%d" % max_row)
527545
limitselect.append_whereclause(
528546
sql.literal_column("ROWNUM")<=max_row)
529547

@@ -542,8 +560,11 @@ def visit_select(self, select, **kwargs):
542560
offsetselect._oracle_visit = True
543561
offsetselect._is_wrapper = True
544562

563+
offset_value = select._offset
564+
if not self.dialect.use_binds_for_limits:
565+
offset_value = sql.literal_column("%d" % offset_value)
545566
offsetselect.append_whereclause(
546-
sql.literal_column("ora_rn")>select._offset)
567+
sql.literal_column("ora_rn")>offset_value)
547568

548569
offsetselect.for_update = select.for_update
549570
select = offsetselect
@@ -635,10 +656,12 @@ class OracleDialect(default.DefaultDialect):
635656
def __init__(self,
636657
use_ansi=True,
637658
optimize_limits=False,
659+
use_binds_for_limits=True,
638660
**kwargs):
639661
default.DefaultDialect.__init__(self, **kwargs)
640662
self.use_ansi = use_ansi
641663
self.optimize_limits = optimize_limits
664+
self.use_binds_for_limits = use_binds_for_limits
642665

643666
def initialize(self, connection):
644667
super(OracleDialect, self).initialize(connection)

lib/sqlalchemy/sql/expression.py

Lines changed: 8 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -3972,6 +3972,8 @@ class _SelectBase(Executable, FromClause):
39723972

39733973
_order_by_clause = ClauseList()
39743974
_group_by_clause = ClauseList()
3975+
_limit = None
3976+
_offset = None
39753977

39763978
def __init__(self,
39773979
use_labels=False,
@@ -3991,8 +3993,10 @@ def __init__(self,
39913993
self._execution_options = \
39923994
self._execution_options.union({'autocommit'
39933995
: autocommit})
3994-
self._limit = limit
3995-
self._offset = offset
3996+
if limit is not None:
3997+
self._limit = util.asint(limit)
3998+
if offset is not None:
3999+
self._offset = util.asint(offset)
39964000
self._bind = bind
39974001

39984002
if order_by is not None:
@@ -4061,14 +4065,14 @@ def limit(self, limit):
40614065
"""return a new selectable with the given LIMIT criterion
40624066
applied."""
40634067

4064-
self._limit = limit
4068+
self._limit = util.asint(limit)
40654069

40664070
@_generative
40674071
def offset(self, offset):
40684072
"""return a new selectable with the given OFFSET criterion
40694073
applied."""
40704074

4071-
self._offset = offset
4075+
self._offset = util.asint(offset)
40724076

40734077
@_generative
40744078
def order_by(self, *clauses):

lib/sqlalchemy/util/__init__.py

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -25,7 +25,7 @@
2525
monkeypatch_proxied_specials, asbool, bool_or_str, coerce_kw_type,\
2626
duck_type_collection, assert_arg_type, symbol, dictlike_iteritems,\
2727
classproperty, set_creation_order, warn_exception, warn, NoneType,\
28-
constructor_copy, methods_equivalent, chop_traceback
28+
constructor_copy, methods_equivalent, chop_traceback, asint
2929

3030
from deprecations import warn_deprecated, warn_pending_deprecation, \
3131
deprecated, pending_deprecation

lib/sqlalchemy/util/langhelpers.py

Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -551,6 +551,14 @@ def bool_or_value(obj):
551551
return asbool(obj)
552552
return bool_or_value
553553

554+
def asint(value):
555+
"""Coerce to integer."""
556+
557+
if value is None:
558+
return value
559+
return int(value)
560+
561+
554562
def coerce_kw_type(kw, key, type_, flexi_bool=True):
555563
"""If 'key' is present in dict 'kw', coerce its value to type 'type\_' if
556564
necessary. If 'flexi_bool' is True, the string '0' is considered false

test/dialect/test_oracle.py

Lines changed: 43 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -132,6 +132,49 @@ def test_limit(self):
132132
':ROWNUM_1) WHERE ora_rn > :ora_rn_1 FOR '
133133
'UPDATE')
134134

135+
def test_use_binds_for_limits_disabled(self):
136+
t = table('sometable', column('col1'), column('col2'))
137+
dialect = oracle.OracleDialect(use_binds_for_limits = False)
138+
139+
self.assert_compile(select([t]).limit(10),
140+
"SELECT col1, col2 FROM (SELECT sometable.col1 AS col1, "
141+
"sometable.col2 AS col2 FROM sometable) WHERE ROWNUM <= 10",
142+
dialect=dialect)
143+
144+
self.assert_compile(select([t]).offset(10),
145+
"SELECT col1, col2 FROM (SELECT col1, col2, ROWNUM AS ora_rn "
146+
"FROM (SELECT sometable.col1 AS col1, sometable.col2 AS col2 "
147+
"FROM sometable)) WHERE ora_rn > 10",
148+
dialect=dialect)
149+
150+
self.assert_compile(select([t]).limit(10).offset(10),
151+
"SELECT col1, col2 FROM (SELECT col1, col2, ROWNUM AS ora_rn "
152+
"FROM (SELECT sometable.col1 AS col1, sometable.col2 AS col2 "
153+
"FROM sometable) WHERE ROWNUM <= 20) WHERE ora_rn > 10",
154+
dialect=dialect)
155+
156+
def test_use_binds_for_limits_enabled(self):
157+
t = table('sometable', column('col1'), column('col2'))
158+
dialect = oracle.OracleDialect(use_binds_for_limits = True)
159+
160+
self.assert_compile(select([t]).limit(10),
161+
"SELECT col1, col2 FROM (SELECT sometable.col1 AS col1, "
162+
"sometable.col2 AS col2 FROM sometable) WHERE ROWNUM "
163+
"<= :ROWNUM_1",
164+
dialect=dialect)
165+
166+
self.assert_compile(select([t]).offset(10),
167+
"SELECT col1, col2 FROM (SELECT col1, col2, ROWNUM AS ora_rn "
168+
"FROM (SELECT sometable.col1 AS col1, sometable.col2 AS col2 "
169+
"FROM sometable)) WHERE ora_rn > :ora_rn_1",
170+
dialect=dialect)
171+
172+
self.assert_compile(select([t]).limit(10).offset(10),
173+
"SELECT col1, col2 FROM (SELECT col1, col2, ROWNUM AS ora_rn "
174+
"FROM (SELECT sometable.col1 AS col1, sometable.col2 AS col2 "
175+
"FROM sometable) WHERE ROWNUM <= :ROWNUM_1) WHERE ora_rn > "
176+
":ora_rn_1",
177+
dialect=dialect)
135178

136179
def test_long_labels(self):
137180
dialect = default.DefaultDialect()

test/sql/test_compiler.py

Lines changed: 19 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,5 @@
11
from test.lib.testing import eq_, assert_raises, assert_raises_message
2-
import datetime, re, operator
2+
import datetime, re, operator, decimal
33
from sqlalchemy import *
44
from sqlalchemy import exc, sql, util
55
from sqlalchemy.sql import table, column, label, compiler
@@ -106,6 +106,24 @@ def test_invalid_col_argument(self):
106106
assert_raises(exc.ArgumentError, select, table1)
107107
assert_raises(exc.ArgumentError, select, table1.c.myid)
108108

109+
def test_int_limit_offset_coercion(self):
110+
for given, exp in [
111+
("5", 5),
112+
(5, 5),
113+
(5.2, 5),
114+
(decimal.Decimal("5"), 5),
115+
(None, None),
116+
]:
117+
eq_(select().limit(given)._limit, exp)
118+
eq_(select().offset(given)._offset, exp)
119+
eq_(select(limit=given)._limit, exp)
120+
eq_(select(offset=given)._offset, exp)
121+
122+
assert_raises(ValueError, select().limit, "foo")
123+
assert_raises(ValueError, select().offset, "foo")
124+
assert_raises(ValueError, select, offset="foo")
125+
assert_raises(ValueError, select, limit="foo")
126+
109127
def test_from_subquery(self):
110128
"""tests placing select statements in the column clause of another select, for the
111129
purposes of selecting from the exported columns of that select."""

0 commit comments

Comments
 (0)