From: Elkin Date: Wed, 5 Feb 2020 14:51:14 +0000 (-0500) Subject: MSSQL 2014 OFFSET/FETCH syntax support X-Git-Tag: rel_1_4_0b1~531^2 X-Git-Url: http://git.ipfire.org/gitweb.cgi?a=commitdiff_plain;h=ab1799a2a1951fe8f188b6395fde04a233a3ac0d;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git MSSQL 2014 OFFSET/FETCH syntax support SQL Server OFFSET and FETCH keywords are now used for limit/offset, rather than using a window function, for SQL Server versions 11 and higher. TOP is still used for a query that features only LIMIT. Pull request courtesy Elkin. Fixes: #5084 Closes: #5125 Pull-request: https://github.com/sqlalchemy/sqlalchemy/pull/5125 Pull-request-sha: a45b7f73090d2053e3a7020d4e3d7fabb0c5627d Change-Id: Id6a01ba30caac87d7d3d92c3903cdfd77fbcee5e --- diff --git a/doc/build/changelog/unreleased_14/5084.rst b/doc/build/changelog/unreleased_14/5084.rst new file mode 100644 index 0000000000..97b44aeb68 --- /dev/null +++ b/doc/build/changelog/unreleased_14/5084.rst @@ -0,0 +1,8 @@ +.. change:: + :tags: change, mssql + :tickets: 5084 + + SQL Server OFFSET and FETCH keywords are now used for limit/offset, rather + than using a window function, for SQL Server versions 11 and higher. TOP is + still used for a query that features only LIMIT. Pull request courtesy + Elkin. diff --git a/lib/sqlalchemy/dialects/mssql/base.py b/lib/sqlalchemy/dialects/mssql/base.py index 94f6a3303a..609a60f7ce 100644 --- a/lib/sqlalchemy/dialects/mssql/base.py +++ b/lib/sqlalchemy/dialects/mssql/base.py @@ -1635,8 +1635,45 @@ class MSSQLCompiler(compiler.SQLCompiler): return text def limit_clause(self, select, **kw): - # Limit in mssql is after the select keyword - return "" + """ MSSQL 2012 supports OFFSET/FETCH operators + Use it instead subquery with row_number + + """ + + if self.dialect._supports_offset_fetch and ( + ( + not select._simple_int_limit + and select._limit_clause is not None + ) + or ( + select._offset_clause is not None + and not select._simple_int_offset + or select._offset + ) + ): + # OFFSET are FETCH are options of the ORDER BY clause + if not select._order_by_clause.clauses: + raise exc.CompileError( + "MSSQL requires an order_by when " + "using an OFFSET or a non-simple " + "LIMIT clause" + ) + + 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 + + if select._limit_clause is not None: + text += "\n FETCH NEXT %s ROWS ONLY " % self.process( + select._limit_clause, **kw + ) + return text + else: + return "" def visit_try_cast(self, element, **kw): return "TRY_CAST (%s AS %s)" % ( @@ -1647,9 +1684,10 @@ class MSSQLCompiler(compiler.SQLCompiler): def visit_select(self, select, **kwargs): """Look for ``LIMIT`` and OFFSET in a select statement, and if so tries to wrap it in a subquery with ``row_number()`` criterion. + MSSQL 2012 and above are excluded """ - if ( + if not self.dialect._supports_offset_fetch and ( (not select._simple_int_limit and select._limit_clause is not None) or ( select._offset_clause is not None @@ -2288,6 +2326,7 @@ class MSDialect(default.DefaultDialect): non_native_boolean_check_constraint = False supports_unicode_binds = True postfetch_lastrowid = True + _supports_offset_fetch = False server_version_info = () @@ -2436,6 +2475,9 @@ class MSDialect(default.DefaultDialect): self.server_version_info >= MS_2012_VERSION ) + self._supports_offset_fetch = ( + self.server_version_info and self.server_version_info[0] >= 11) + def _get_default_schema_name(self, connection): if self.server_version_info < MS_2005_VERSION: return self.schema_name diff --git a/test/dialect/mssql/test_compiler.py b/test/dialect/mssql/test_compiler.py index bb5199b00d..07ceb5bf5b 100644 --- a/test/dialect/mssql/test_compiler.py +++ b/test/dialect/mssql/test_compiler.py @@ -844,6 +844,29 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): assert t.c.x in set(c._create_result_map()["x"][1]) assert t.c.y in set(c._create_result_map()["y"][1]) + def test_limit_offset_using_offset_fetch(self): + t = table("t", column("x", Integer), column("y", Integer)) + dialect_2012 = mssql.base.MSDialect() + dialect_2012._supports_offset_fetch = True + + s = select([t]).where(t.c.x == 5).order_by(t.c.y).limit(10).offset(20) + + self.assert_compile( + s, + "SELECT t.x, t.y " + "FROM t " + "WHERE t.x = :x_1 ORDER BY t.y " + "OFFSET :param_1 ROWS " + "FETCH NEXT :param_2 ROWS ONLY ", + checkparams={"param_1": 20, "param_2": 10, "x_1": 5}, + dialect=dialect_2012 + ) + + c = s.compile(dialect=dialect_2012) + eq_(len(c._result_columns), 2) + assert t.c.x in set(c._create_result_map()["x"][1]) + assert t.c.y in set(c._create_result_map()["y"][1]) + def test_limit_offset_w_ambiguous_cols(self): t = table("t", column("x", Integer), column("y", Integer)) diff --git a/test/sql/test_query.py b/test/sql/test_query.py index 9e56b6489f..ce57260b7c 100644 --- a/test/sql/test_query.py +++ b/test/sql/test_query.py @@ -1013,7 +1013,6 @@ class LimitTest(fixtures.TestBase): self.assert_(r[0] != r[1] and r[1] != r[2], repr(r)) @testing.requires.offset - @testing.fails_on("mssql", "FIXME: unknown") def test_select_distinct_offset(self): """Test the interaction between distinct and offset"""