From: Mike Bayer Date: Thu, 7 Jul 2022 16:07:39 +0000 (-0400) Subject: Use FETCH FIRST N ROWS / OFFSET for Oracle LIMIT/OFFSET X-Git-Tag: rel_2_0_0b1~163^2 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=5fc46b192b5005fa6962110a683abf1d296786d8;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git Use FETCH FIRST N ROWS / OFFSET for Oracle LIMIT/OFFSET Oracle will now use FETCH FIRST N ROWS / OFFSET syntax for limit/offset support by default for Oracle 12c and above. This syntax was already available when :meth:`_sql.Select.fetch` were used directly, it's now implied for :meth:`_sql.Select.limit` and :meth:`_sql.Select.offset` as well. I'm currently setting this up so that the new syntax renders in Oracle using POSTCOMPILE binds. I really have no indication if Oracle's SQL optimizer would be better with params here, so that it can cache the SQL plan, or if it expects hardcoded numbers for these. Since we had reports that the previous ROWNUM thing really needed hardcoded ints, let's guess for now that hardcoded ints would be preferable. it can be turned off with a single boolean if users report that they'd prefer real bound values. Fixes: #8221 Change-Id: I812ec24ffc947199866947b666d6ec6e6a690f22 --- diff --git a/doc/build/changelog/unreleased_20/8221.rst b/doc/build/changelog/unreleased_20/8221.rst new file mode 100644 index 0000000000..926acab9d8 --- /dev/null +++ b/doc/build/changelog/unreleased_20/8221.rst @@ -0,0 +1,10 @@ +.. change:: + :tags: usecase, oracle + :tickets: 8221 + + Oracle will now use FETCH FIRST N ROWS / OFFSET syntax for limit/offset + support by default for Oracle 12c and above. This syntax was already + available when :meth:`_sql.Select.fetch` were used directly, it's now + implied for :meth:`_sql.Select.limit` and :meth:`_sql.Select.offset` as + well. + diff --git a/lib/sqlalchemy/dialects/mssql/base.py b/lib/sqlalchemy/dialects/mssql/base.py index 65f37cfb5c..e33ae4dbb6 100644 --- a/lib/sqlalchemy/dialects/mssql/base.py +++ b/lib/sqlalchemy/dialects/mssql/base.py @@ -1994,9 +1994,6 @@ class MSSQLCompiler(compiler.SQLCompiler): ) ) - def fetch_clause(self, cs, **kwargs): - return "" - def limit_clause(self, cs, **kwargs): return "" @@ -2028,21 +2025,13 @@ class MSSQLCompiler(compiler.SQLCompiler): if self.dialect._supports_offset_fetch and not self._use_top(select): self._check_can_use_fetch_limit(select) - text = "" - - if select._offset_clause is not None: - offset_str = self.process(select._offset_clause, **kw) - else: - offset_str = "0" - text += "\n OFFSET %s ROWS" % offset_str - - limit = self._get_limit_or_fetch(select) + return self.fetch_clause( + select, + fetch_clause=self._get_limit_or_fetch(select), + require_offset=True, + **kw, + ) - if limit is not None: - text += "\n FETCH FIRST %s ROWS ONLY" % self.process( - limit, **kw - ) - return text else: return "" diff --git a/lib/sqlalchemy/dialects/oracle/base.py b/lib/sqlalchemy/dialects/oracle/base.py index 9957417b46..c06da6ffea 100644 --- a/lib/sqlalchemy/dialects/oracle/base.py +++ b/lib/sqlalchemy/dialects/oracle/base.py @@ -260,23 +260,38 @@ impact of this change has been mitigated. 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 @@ -296,10 +311,6 @@ notes apply: :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 @@ -1001,6 +1012,33 @@ class OracleCompiler(compiler.SQLCompiler): 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 @@ -1017,6 +1055,7 @@ class OracleCompiler(compiler.SQLCompiler): # 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 @@ -1375,6 +1414,8 @@ class OracleDialect(default.DefaultDialect): supports_alter = True max_identifier_length = 128 + _supports_offset_fetch = True + insert_returning = True update_returning = True delete_returning = True @@ -1435,6 +1476,7 @@ class OracleDialect(default.DefaultDialect): use_binds_for_limits=None, use_nchar_for_unicode=False, exclude_tablespaces=("SYSTEM", "SYSAUX"), + enable_offset_fetch=True, **kwargs, ): default.DefaultDialect.__init__(self, **kwargs) @@ -1442,6 +1484,9 @@ class OracleDialect(default.DefaultDialect): 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) @@ -1458,6 +1503,9 @@ class OracleDialect(default.DefaultDialect): 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 diff --git a/lib/sqlalchemy/sql/compiler.py b/lib/sqlalchemy/sql/compiler.py index 87d031cc26..08b876e698 100644 --- a/lib/sqlalchemy/sql/compiler.py +++ b/lib/sqlalchemy/sql/compiler.py @@ -4266,19 +4266,44 @@ class SQLCompiler(Compiled): text += " OFFSET " + self.process(select._offset_clause, **kw) return text - def fetch_clause(self, select, **kw): + def fetch_clause( + self, + select, + fetch_clause=None, + require_offset=False, + use_literal_execute_for_simple_int=False, + **kw, + ): + if fetch_clause is None: + fetch_clause = select._fetch_clause + fetch_clause_options = select._fetch_clause_options + else: + fetch_clause_options = {"percent": False, "with_ties": False} + text = "" + if select._offset_clause is not None: - text += "\n OFFSET %s ROWS" % self.process( - select._offset_clause, **kw - ) - if select._fetch_clause is not None: + offset_clause = select._offset_clause + if ( + use_literal_execute_for_simple_int + and select._simple_int_clause(offset_clause) + ): + offset_clause = offset_clause.render_literal_execute() + offset_str = self.process(offset_clause, **kw) + text += "\n OFFSET %s ROWS" % offset_str + elif require_offset: + text += "\n OFFSET 0 ROWS" + + if fetch_clause is not None: + if ( + use_literal_execute_for_simple_int + and select._simple_int_clause(fetch_clause) + ): + fetch_clause = fetch_clause.render_literal_execute() text += "\n FETCH FIRST %s%s ROWS %s" % ( - self.process(select._fetch_clause, **kw), - " PERCENT" if select._fetch_clause_options["percent"] else "", - "WITH TIES" - if select._fetch_clause_options["with_ties"] - else "ONLY", + self.process(fetch_clause, **kw), + " PERCENT" if fetch_clause_options["percent"] else "", + "WITH TIES" if fetch_clause_options["with_ties"] else "ONLY", ) return text diff --git a/test/dialect/oracle/test_compiler.py b/test/dialect/oracle/test_compiler.py index ecf43a2cff..45a83ed77a 100644 --- a/test/dialect/oracle/test_compiler.py +++ b/test/dialect/oracle/test_compiler.py @@ -47,6 +47,12 @@ from sqlalchemy.testing.schema import Table 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") @@ -159,7 +165,7 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): "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()) @@ -182,6 +188,24 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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. @@ -195,6 +219,25 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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 " @@ -204,7 +247,7 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): "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) @@ -220,7 +263,34 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): "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): @@ -228,6 +298,33 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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 " @@ -242,6 +339,7 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): "anon_2 " "WHERE ora_rn > __[POSTCOMPILE_param_2]) anon_1", checkparams={"param_1": 10, "param_2": 20}, + dialect=dialect, ) self.assert_compile( @@ -257,8 +355,9 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): "__[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]) @@ -266,6 +365,22 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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 " @@ -277,12 +392,13 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): "__[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) @@ -296,7 +412,7 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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) @@ -309,12 +425,26 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): "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, @@ -333,6 +463,23 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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) @@ -350,7 +497,7 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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 @@ -510,7 +657,9 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): "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( @@ -526,7 +675,9 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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( @@ -541,7 +692,25 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): "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( @@ -563,7 +732,9 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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( @@ -584,7 +755,9 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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( @@ -607,23 +780,25 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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), @@ -634,13 +809,15 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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), @@ -652,13 +829,15 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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), @@ -672,13 +851,15 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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), @@ -689,13 +870,15 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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), @@ -708,13 +891,15 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): 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), @@ -932,7 +1117,7 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): "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): diff --git a/test/dialect/oracle/test_dialect.py b/test/dialect/oracle/test_dialect.py index 98eb76c184..e3101840af 100644 --- a/test/dialect/oracle/test_dialect.py +++ b/test/dialect/oracle/test_dialect.py @@ -880,21 +880,22 @@ class ExecuteTest(fixtures.TestBase): ) # here, we can't use ORDER BY. - eq_( - connection.execute( - t.select().with_for_update().limit(2) - ).fetchall(), - [(1, 1), (2, 7)], - ) + # as of #8221, this fails also. limit w/o order by is useless + # in any case. + stmt = t.select().with_for_update().limit(2) + if testing.against("oracle>=12"): + with expect_raises_message(exc.DatabaseError, "ORA-02014"): + connection.execute(stmt).fetchall() + else: + eq_( + connection.execute(stmt).fetchall(), + [(1, 1), (2, 7)], + ) # here, its impossible. But we'd prefer it to raise ORA-02014 # instead of issuing a syntax error. - assert_raises_message( - exc.DatabaseError, - "ORA-02014", - connection.execute, - t.select().with_for_update().limit(2).offset(3), - ) + with expect_raises_message(exc.DatabaseError, "ORA-02014"): + connection.execute(t.select().with_for_update().limit(2).offset(3)) class UnicodeSchemaTest(fixtures.TestBase): diff --git a/test/orm/test_lockmode.py b/test/orm/test_lockmode.py index b296f22409..2e03c3e87c 100644 --- a/test/orm/test_lockmode.py +++ b/test/orm/test_lockmode.py @@ -330,6 +330,8 @@ class CompileTest(_fixtures.FixtureTest, AssertsCompiledSQL): ) def test_for_update_on_inner_w_joinedload_no_render_oracle(self): + from sqlalchemy.dialects import oracle + User = self.classes.User sess = fixture_session() self.assert_compile( @@ -349,5 +351,5 @@ class CompileTest(_fixtures.FixtureTest, AssertsCompiledSQL): "__[POSTCOMPILE_param_1]) anon_1 " "LEFT OUTER JOIN addresses addresses_1 " "ON anon_1.users_id = addresses_1.user_id FOR UPDATE", - dialect="oracle", + dialect=oracle.dialect(enable_offset_fetch=False), ) diff --git a/test/requirements.py b/test/requirements.py index 17c11fc5d8..5838cf8249 100644 --- a/test/requirements.py +++ b/test/requirements.py @@ -704,10 +704,22 @@ class DefaultRequirements(SuiteRequirements): E.g. (SELECT id, ...) UNION (SELECT id, ...) ORDER BY id - Fails on SQL Server + Fails on SQL Server and oracle. + + Previously on Oracle, prior to #8221, the ROW_NUMBER subquerying + applied to queries allowed the test at + suite/test_select.py -> + CompoundSelectTest.test_limit_offset_selectable_in_unions + to pass, because of the implicit subquerying thus creating a query + that was more in line with the syntax + illustrated at + https://stackoverflow.com/a/6036814/34549. However, Oracle doesn't + support the above (SELECT ..) UNION (SELECT ..) ORDER BY syntax + at all. So those tests are now not supported w/ Oracle as of + #8221. """ - return fails_if("mssql") + return fails_if(["mssql", "oracle>=12"]) @property def parens_in_union_contained_select_w_limit_offset(self):