LIMIT/OFFSET/FETCH Support
--------------------------
-Methods like :meth:`_sql.Select.limit` and :meth:`_sql.Select.offset` currently
-use an emulated approach for LIMIT / OFFSET based on window functions, which
-involves creation of a subquery using ``ROW_NUMBER`` that is prone to
-performance issues as well as SQL construction issues for complex statements.
-However, this approach is supported by all Oracle versions. See notes below.
-
-When using Oracle 12c and above, use the :meth:`_sql.Select.fetch` method
-instead; this will render the more modern
-``FETCH FIRST N ROW / OFFSET N ROWS`` syntax.
+Methods like :meth:`_sql.Select.limit` and :meth:`_sql.Select.offset` make
+use of ``FETCH FIRST N ROW / OFFSET N ROWS`` syntax assuming
+Oracle 12c or above, and assuming the SELECT statement is not embedded within
+a compound statement like UNION. This syntax is also available directly by using
+the :meth:`_sql.Select.fetch` method.
+
+.. versionchanged:: 2.0 the Oracle dialect now uses
+ ``FETCH FIRST N ROW / OFFSET N ROWS`` for all
+ :meth:`_sql.Select.limit` and :meth:`_sql.Select.offset` usage including
+ within the ORM and legacy :class:`_orm.Query`. To force the legacy
+ behavior using window functions, specify the ``enable_offset_fetch=False``
+ dialect parameter to :func:`_sa.create_engine`.
+
+The use of ``FETCH FIRST / OFFSET`` may be disabled on any Oracle version
+by passing ``enable_offset_fetch=False`` to :func:`_sa.create_engine`, which
+will force the use of "legacy" mode that makes use of window functions.
+This mode is also selected automatically when using a version of Oracle
+prior to 12c.
+
+When using legacy mode, or when a :class:`.Select` statement
+with limit/offset is embedded in a compound statement, an emulated approach for
+LIMIT / OFFSET based on window functions is used, which involves creation of a
+subquery using ``ROW_NUMBER`` that is prone to performance issues as well as
+SQL construction issues for complex statements. However, this approach is
+supported by all Oracle versions. See notes below.
Notes on LIMIT / OFFSET emulation (when fetch() method cannot be used)
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
-If using :meth:`_sql.Select.limit` and :meth:`_sql.Select.offset`,
-or with the ORM the :meth:`_orm.Query.limit` and :meth:`_orm.Query.offset` methods,
-and the :meth:`_sql.Select.fetch` method **cannot** be used instead, the following
-notes apply:
+If using :meth:`_sql.Select.limit` and :meth:`_sql.Select.offset`, or with the
+ORM the :meth:`_orm.Query.limit` and :meth:`_orm.Query.offset` methods on an
+Oracle version prior to 12c, the following notes apply:
* SQLAlchemy currently makes use of ROWNUM to achieve
LIMIT/OFFSET; the exact methodology is taken from
:ref:`change_4808`.
-* A future release may use ``FETCH FIRST N ROW / OFFSET N ROWS`` automatically
- when :meth:`_sql.Select.limit`, :meth:`_sql.Select.offset`, :meth:`_orm.Query.limit`,
- :meth:`_orm.Query.offset` are used.
-
.. _oracle_returning:
RETURNING Support
return "RETURNING " + ", ".join(columns) + " INTO " + ", ".join(binds)
+ def _row_limit_clause(self, select, **kw):
+ """ORacle 12c supports OFFSET/FETCH operators
+ Use it instead subquery with row_number
+
+ """
+
+ if (
+ select._fetch_clause is not None
+ or not self.dialect._supports_offset_fetch
+ ):
+ return super()._row_limit_clause(
+ select, use_literal_execute_for_simple_int=True, **kw
+ )
+ else:
+ return self.fetch_clause(
+ select,
+ fetch_clause=self._get_limit_or_fetch(select),
+ use_literal_execute_for_simple_int=True,
+ **kw,
+ )
+
+ def _get_limit_or_fetch(self, select):
+ if select._fetch_clause is None:
+ return select._limit_clause
+ else:
+ return select._fetch_clause
+
def translate_select_structure(self, select_stmt, **kwargs):
select = select_stmt
# if fetch is used this is not needed
if (
select._has_row_limiting_clause
+ and not self.dialect._supports_offset_fetch
and select._fetch_clause is None
):
limit_clause = select._limit_clause
supports_alter = True
max_identifier_length = 128
+ _supports_offset_fetch = True
+
insert_returning = True
update_returning = True
delete_returning = True
use_binds_for_limits=None,
use_nchar_for_unicode=False,
exclude_tablespaces=("SYSTEM", "SYSAUX"),
+ enable_offset_fetch=True,
**kwargs,
):
default.DefaultDialect.__init__(self, **kwargs)
self.use_ansi = use_ansi
self.optimize_limits = optimize_limits
self.exclude_tablespaces = exclude_tablespaces
+ self.enable_offset_fetch = (
+ self._supports_offset_fetch
+ ) = enable_offset_fetch
def initialize(self, connection):
super(OracleDialect, self).initialize(connection)
self.use_ansi = False
self.supports_identity_columns = self.server_version_info >= (12,)
+ self._supports_offset_fetch = (
+ self.enable_offset_fetch and self.server_version_info >= (12,)
+ )
def _get_effective_compat_server_version_info(self, connection):
# dialect does not need compat levels below 12.2, so don't query
class CompileTest(fixtures.TestBase, AssertsCompiledSQL):
__dialect__ = "oracle"
+ @testing.fixture
+ def legacy_oracle_limitoffset(self):
+ self.__dialect__ = oracle.OracleDialect(enable_offset_fetch=False)
+ yield
+ del self.__dialect__
+
def test_true_false(self):
self.assert_compile(sql.false(), "0")
self.assert_compile(sql.true(), "1")
"GROUP BY included_parts.sub_part",
)
- def test_limit_one(self):
+ def test_limit_one_legacy(self, legacy_oracle_limitoffset):
t = table("sometable", column("col1"), column("col2"))
s = select(t)
c = s.compile(dialect=oracle.OracleDialect())
eq_(len(c._result_columns), 2)
assert t.c.col1 in set(c._create_result_map()["col1"][1])
+ def test_limit_one(self):
+ t = table("sometable", column("col1"), column("col2"))
+ s = select(t)
+ c = s.compile(dialect=oracle.OracleDialect())
+ assert t.c.col1 in set(c._create_result_map()["col1"][1])
+ s = select(t).limit(10).offset(20)
+ self.assert_compile(
+ s,
+ "SELECT sometable.col1, sometable.col2 FROM sometable "
+ "OFFSET __[POSTCOMPILE_param_1] ROWS "
+ "FETCH FIRST __[POSTCOMPILE_param_2] ROWS ONLY",
+ checkparams={"param_1": 20, "param_2": 10},
+ )
+
+ c = s.compile(dialect=oracle.OracleDialect())
+ eq_(len(c._result_columns), 2)
+ assert t.c.col1 in set(c._create_result_map()["col1"][1])
+
def test_limit_one_literal_binds(self):
"""test for #6863.
compile_kwargs={"literal_binds": True},
)
+ eq_ignore_whitespace(
+ str(c),
+ "SELECT sometable.col1, sometable.col2 FROM sometable "
+ "OFFSET 20 ROWS FETCH FIRST 10 ROWS ONLY",
+ )
+
+ def test_limit_one_literal_binds_legacy(self, legacy_oracle_limitoffset):
+ """test for #6863.
+
+ the bug does not appear to have affected Oracle's case.
+
+ """
+ t = table("sometable", column("col1"), column("col2"))
+ s = select(t).limit(10).offset(20)
+ c = s.compile(
+ dialect=oracle.OracleDialect(enable_offset_fetch=False),
+ compile_kwargs={"literal_binds": True},
+ )
+
eq_ignore_whitespace(
str(c),
"SELECT anon_1.col1, anon_1.col2 FROM "
"WHERE ROWNUM <= 10 + 20) anon_1 WHERE ora_rn > 20",
)
- def test_limit_one_firstrows(self):
+ def test_limit_one_firstrows_legacy(self):
t = table("sometable", column("col1"), column("col2"))
s = select(t)
s = select(t).limit(10).offset(20)
"WHERE ora_rn > "
"__[POSTCOMPILE_param_2]",
checkparams={"param_1": 10, "param_2": 20},
- dialect=oracle.OracleDialect(optimize_limits=True),
+ dialect=oracle.OracleDialect(
+ optimize_limits=True, enable_offset_fetch=False
+ ),
+ )
+
+ def test_simple_fetch(self):
+ # as of #8221, all FETCH / ROWS ONLY is using postcompile params;
+ # this is in the spirit of the ROWNUM approach where users reported
+ # that bound parameters caused performance degradation
+ t = table("sometable", column("col1"), column("col2"))
+ s = select(t)
+ s = select(t).fetch(10)
+ self.assert_compile(
+ s,
+ "SELECT sometable.col1, sometable.col2 FROM sometable "
+ "FETCH FIRST __[POSTCOMPILE_param_1] ROWS ONLY",
+ checkparams={"param_1": 10},
+ )
+
+ def test_simple_fetch_offset(self):
+ t = table("sometable", column("col1"), column("col2"))
+ s = select(t).fetch(10).offset(20)
+ self.assert_compile(
+ s,
+ "SELECT sometable.col1, sometable.col2 FROM sometable "
+ "OFFSET __[POSTCOMPILE_param_1] ROWS "
+ "FETCH FIRST __[POSTCOMPILE_param_2] ROWS ONLY",
+ checkparams={"param_1": 20, "param_2": 10},
)
def test_limit_two(self):
s = select(t).limit(10).offset(20).subquery()
s2 = select(s.c.col1, s.c.col2)
+ self.assert_compile(
+ s2,
+ "SELECT anon_1.col1, anon_1.col2 FROM (SELECT sometable.col1 AS "
+ "col1, sometable.col2 AS col2 FROM sometable OFFSET "
+ "__[POSTCOMPILE_param_1] ROWS FETCH FIRST "
+ "__[POSTCOMPILE_param_2] ROWS ONLY) anon_1",
+ checkparams={"param_1": 20, "param_2": 10},
+ )
+
+ self.assert_compile(
+ s2,
+ "SELECT anon_1.col1, anon_1.col2 FROM (SELECT sometable.col1 AS "
+ "col1, sometable.col2 AS col2 FROM sometable OFFSET 20 "
+ "ROWS FETCH FIRST 10 ROWS ONLY) anon_1",
+ render_postcompile=True,
+ )
+ c = s2.compile(dialect=oracle.OracleDialect())
+ eq_(len(c._result_columns), 2)
+ assert s.c.col1 in set(c._create_result_map()["col1"][1])
+
+ def test_limit_two_legacy(self):
+ t = table("sometable", column("col1"), column("col2"))
+ s = select(t).limit(10).offset(20).subquery()
+
+ s2 = select(s.c.col1, s.c.col2)
+
+ dialect = oracle.OracleDialect(enable_offset_fetch=False)
self.assert_compile(
s2,
"SELECT anon_1.col1, anon_1.col2 FROM "
"anon_2 "
"WHERE ora_rn > __[POSTCOMPILE_param_2]) anon_1",
checkparams={"param_1": 10, "param_2": 20},
+ dialect=dialect,
)
self.assert_compile(
"__[POSTCOMPILE_param_2]) "
"anon_2 "
"WHERE ora_rn > __[POSTCOMPILE_param_2]) anon_1",
+ dialect=dialect,
)
- c = s2.compile(dialect=oracle.OracleDialect())
+ c = s2.compile(dialect=dialect)
eq_(len(c._result_columns), 2)
assert s.c.col1 in set(c._create_result_map()["col1"][1])
t = table("sometable", column("col1"), column("col2"))
s = select(t).limit(10).offset(20).order_by(t.c.col2)
+ self.assert_compile(
+ s,
+ "SELECT sometable.col1, sometable.col2 FROM sometable "
+ "ORDER BY sometable.col2 OFFSET __[POSTCOMPILE_param_1] "
+ "ROWS FETCH FIRST __[POSTCOMPILE_param_2] ROWS ONLY",
+ checkparams={"param_1": 20, "param_2": 10},
+ )
+ c = s.compile(dialect=oracle.OracleDialect())
+ eq_(len(c._result_columns), 2)
+ assert t.c.col1 in set(c._create_result_map()["col1"][1])
+
+ def test_limit_three_legacy(self):
+ t = table("sometable", column("col1"), column("col2"))
+
+ s = select(t).limit(10).offset(20).order_by(t.c.col2)
+ dialect = oracle.OracleDialect(enable_offset_fetch=False)
self.assert_compile(
s,
"SELECT anon_1.col1, anon_1.col2 FROM "
"__[POSTCOMPILE_param_1] + __[POSTCOMPILE_param_2]) anon_1 "
"WHERE ora_rn > __[POSTCOMPILE_param_2]",
checkparams={"param_1": 10, "param_2": 20},
+ dialect=dialect,
)
- c = s.compile(dialect=oracle.OracleDialect())
+ c = s.compile(dialect=dialect)
eq_(len(c._result_columns), 2)
assert t.c.col1 in set(c._create_result_map()["col1"][1])
- def test_limit_four(self):
+ def test_limit_four_legacy(self, legacy_oracle_limitoffset):
t = table("sometable", column("col1"), column("col2"))
s = select(t).with_for_update().limit(10).order_by(t.c.col2)
checkparams={"param_1": 10},
)
- def test_limit_four_firstrows(self):
+ def test_limit_four_firstrows_legacy(self):
t = table("sometable", column("col1"), column("col2"))
s = select(t).with_for_update().limit(10).order_by(t.c.col2)
"sometable.col2) anon_1 WHERE ROWNUM <= __[POSTCOMPILE_param_1] "
"FOR UPDATE",
checkparams={"param_1": 10},
- dialect=oracle.OracleDialect(optimize_limits=True),
+ dialect=oracle.OracleDialect(
+ optimize_limits=True, enable_offset_fetch=False
+ ),
)
def test_limit_five(self):
t = table("sometable", column("col1"), column("col2"))
+ s = select(t).with_for_update().limit(10).offset(20).order_by(t.c.col2)
+ self.assert_compile(
+ s,
+ "SELECT sometable.col1, sometable.col2 FROM sometable "
+ "ORDER BY sometable.col2 OFFSET __[POSTCOMPILE_param_1] ROWS "
+ "FETCH FIRST __[POSTCOMPILE_param_2] ROWS ONLY FOR UPDATE",
+ checkparams={"param_1": 20, "param_2": 10},
+ )
+
+ def test_limit_five_legacy(self, legacy_oracle_limitoffset):
+ t = table("sometable", column("col1"), column("col2"))
+
s = select(t).with_for_update().limit(10).offset(20).order_by(t.c.col2)
self.assert_compile(
s,
def test_limit_six(self):
t = table("sometable", column("col1"), column("col2"))
+ s = (
+ select(t)
+ .limit(10)
+ .offset(literal(10) + literal(20))
+ .order_by(t.c.col2)
+ )
+ self.assert_compile(
+ s,
+ "SELECT sometable.col1, sometable.col2 FROM sometable "
+ "ORDER BY sometable.col2 OFFSET :param_1 + :param_2 "
+ "ROWS FETCH FIRST __[POSTCOMPILE_param_3] ROWS ONLY",
+ checkparams={"param_1": 10, "param_2": 20, "param_3": 10},
+ )
+
+ def test_limit_six_legacy(self, legacy_oracle_limitoffset):
+ t = table("sometable", column("col1"), column("col2"))
+
s = (
select(t)
.limit(10)
checkparams={"param_1": 10, "param_2": 10, "param_3": 20},
)
- def test_limit_special_quoting(self):
+ def test_limit_special_quoting_legacy(self, legacy_oracle_limitoffset):
"""Oracle-specific test for #4730.
Even though this issue is generic, test the originally reported Oracle
"FROM mytable WHERE mytable.myid = :myid_1 FOR UPDATE OF table1",
)
- def test_for_update_of_w_limit_adaption_col_present(self):
+ def test_for_update_of_w_limit_col_present_legacy(
+ self, legacy_oracle_limitoffset
+ ):
table1 = table("mytable", column("myid"), column("name"))
self.assert_compile(
checkparams={"param_1": 10, "myid_1": 7},
)
- def test_for_update_of_w_limit_adaption_col_unpresent(self):
+ def test_for_update_of_w_limit_col_unpresent_legacy(
+ self, legacy_oracle_limitoffset
+ ):
table1 = table("mytable", column("myid"), column("name"))
self.assert_compile(
"FOR UPDATE OF anon_1.name NOWAIT",
)
- def test_for_update_of_w_limit_offset_adaption_col_present(self):
+ def test_for_update_of_w_limit_offset_col_present(self):
+ table1 = table("mytable", column("myid"), column("name"))
+
+ self.assert_compile(
+ select(table1.c.myid, table1.c.name)
+ .where(table1.c.myid == 7)
+ .with_for_update(nowait=True, of=table1.c.name)
+ .limit(10)
+ .offset(50),
+ "SELECT mytable.myid, mytable.name FROM mytable "
+ "WHERE mytable.myid = :myid_1 OFFSET __[POSTCOMPILE_param_1] "
+ "ROWS FETCH FIRST __[POSTCOMPILE_param_2] ROWS ONLY "
+ "FOR UPDATE OF mytable.name NOWAIT",
+ checkparams={"param_1": 50, "param_2": 10, "myid_1": 7},
+ )
+
+ def test_for_update_of_w_limit_offset_col_present_legacy(
+ self, legacy_oracle_limitoffset
+ ):
table1 = table("mytable", column("myid"), column("name"))
self.assert_compile(
checkparams={"param_1": 10, "param_2": 50, "myid_1": 7},
)
- def test_for_update_of_w_limit_offset_adaption_col_unpresent(self):
+ def test_for_update_of_w_limit_offset_col_unpresent_legacy(
+ self, legacy_oracle_limitoffset
+ ):
table1 = table("mytable", column("myid"), column("name"))
self.assert_compile(
checkparams={"param_1": 10, "param_2": 50, "myid_1": 7},
)
- def test_for_update_of_w_limit_offset_adaption_partial_col_unpresent(self):
+ def test_for_update_of_w_limit_offset_partial_col_unpresent_legacy(
+ self, legacy_oracle_limitoffset
+ ):
table1 = table("mytable", column("myid"), column("foo"), column("bar"))
self.assert_compile(
checkparams={"param_1": 10, "param_2": 50, "myid_1": 7},
)
- def test_limit_preserves_typing_information(self):
+ def test_limit_preserves_typing_information_legacy(self):
class MyType(TypeDecorator):
impl = Integer
cache_ok = True
stmt = select(type_coerce(column("x"), MyType).label("foo")).limit(1)
- dialect = oracle.dialect()
+ dialect = oracle.dialect(enable_offset_fetch=False)
compiled = stmt.compile(dialect=dialect)
assert isinstance(compiled._create_result_map()["foo"][-2], MyType)
- def test_use_binds_for_limits_disabled_one(self):
+ def test_use_binds_for_limits_disabled_one_legacy(self):
t = table("sometable", column("col1"), column("col2"))
with testing.expect_deprecated(
"The ``use_binds_for_limits`` Oracle dialect parameter is "
"deprecated."
):
- dialect = oracle.OracleDialect(use_binds_for_limits=False)
+ dialect = oracle.OracleDialect(
+ use_binds_for_limits=False, enable_offset_fetch=False
+ )
self.assert_compile(
select(t).limit(10),
dialect=dialect,
)
- def test_use_binds_for_limits_disabled_two(self):
+ def test_use_binds_for_limits_disabled_two_legacy(self):
t = table("sometable", column("col1"), column("col2"))
with testing.expect_deprecated(
"The ``use_binds_for_limits`` Oracle dialect parameter is "
"deprecated."
):
- dialect = oracle.OracleDialect(use_binds_for_limits=False)
+ dialect = oracle.OracleDialect(
+ use_binds_for_limits=False, enable_offset_fetch=False
+ )
self.assert_compile(
select(t).offset(10),
dialect=dialect,
)
- def test_use_binds_for_limits_disabled_three(self):
+ def test_use_binds_for_limits_disabled_three_legacy(self):
t = table("sometable", column("col1"), column("col2"))
with testing.expect_deprecated(
"The ``use_binds_for_limits`` Oracle dialect parameter is "
"deprecated."
):
- dialect = oracle.OracleDialect(use_binds_for_limits=False)
+ dialect = oracle.OracleDialect(
+ use_binds_for_limits=False, enable_offset_fetch=False
+ )
self.assert_compile(
select(t).limit(10).offset(10),
dialect=dialect,
)
- def test_use_binds_for_limits_enabled_one(self):
+ def test_use_binds_for_limits_enabled_one_legacy(self):
t = table("sometable", column("col1"), column("col2"))
with testing.expect_deprecated(
"The ``use_binds_for_limits`` Oracle dialect parameter is "
"deprecated."
):
- dialect = oracle.OracleDialect(use_binds_for_limits=True)
+ dialect = oracle.OracleDialect(
+ use_binds_for_limits=True, enable_offset_fetch=False
+ )
self.assert_compile(
select(t).limit(10),
dialect=dialect,
)
- def test_use_binds_for_limits_enabled_two(self):
+ def test_use_binds_for_limits_enabled_two_legacy(self):
t = table("sometable", column("col1"), column("col2"))
with testing.expect_deprecated(
"The ``use_binds_for_limits`` Oracle dialect parameter is "
"deprecated."
):
- dialect = oracle.OracleDialect(use_binds_for_limits=True)
+ dialect = oracle.OracleDialect(
+ use_binds_for_limits=True, enable_offset_fetch=False
+ )
self.assert_compile(
select(t).offset(10),
dialect=dialect,
)
- def test_use_binds_for_limits_enabled_three(self):
+ def test_use_binds_for_limits_enabled_three_legacy(self):
t = table("sometable", column("col1"), column("col2"))
with testing.expect_deprecated(
"The ``use_binds_for_limits`` Oracle dialect parameter is "
"deprecated."
):
- dialect = oracle.OracleDialect(use_binds_for_limits=True)
+ dialect = oracle.OracleDialect(
+ use_binds_for_limits=True, enable_offset_fetch=False
+ )
self.assert_compile(
select(t).limit(10).offset(10),
"anon_1 "
"WHERE ora_rn > __[POSTCOMPILE_param_2]",
checkparams={"param_1": 10, "param_2": 5},
- dialect=oracle.dialect(use_ansi=False),
+ dialect=oracle.dialect(use_ansi=False, enable_offset_fetch=False),
)
def test_outer_join_six(self):