]> git.ipfire.org Git - thirdparty/sqlalchemy/sqlalchemy.git/commitdiff
Support range specification in window function
authorPhillip Cloud <cpcloud@gmail.com>
Mon, 2 May 2016 02:26:10 +0000 (22:26 -0400)
committerMike Bayer <mike_mp@zzzcomputing.com>
Tue, 7 Jun 2016 19:17:22 +0000 (15:17 -0400)
Fixes: #3049
Co-authored-by: Mike Bayer <mike_mp@zzzcomputing.com>
Change-Id: Ie572095c3e25f70a1e72e1af6858e5edd89fd25e
Pull-request: https://github.com/zzzeek/sqlalchemy/pull/264

doc/build/changelog/changelog_11.rst
doc/build/changelog/migration_11.rst
doc/build/core/tutorial.rst
lib/sqlalchemy/sql/compiler.py
lib/sqlalchemy/sql/elements.py
lib/sqlalchemy/sql/functions.py
test/sql/test_compiler.py

index 297be5d2d20677ecbcd572b92343ab5da7a4fa84..5dee9867accdb5a57fd63324f1bec4333dc0f628 100644 (file)
 .. changelog::
     :version: 1.1.0b1
 
+    .. change::
+        :tags: feature, sql
+        :tickets: 3049
+
+        Added support for ranges in window functions, using the
+        :paramref:`.expression.over.range_` and
+        :paramref:`.expression.over.rows` parameters.
+
+        .. seealso::
+
+            :ref:`change_3049`
+
     .. change::
         :tags: feature, orm
 
index d9f48fcb1dbdbcea790ca3941cac969ed3c33a2e..8c138f090659a6c42b0e04bd4a2674b4b5eb56b4 100644 (file)
@@ -1005,6 +1005,35 @@ statement::
 
 :ticket:`2551`
 
+.. _change_3049:
+
+Support for RANGE and ROWS specification within window functions
+----------------------------------------------------------------
+
+New :paramref:`.expression.over.range_` and :paramref:`.expression.over.rows` parameters allow
+RANGE and ROWS expressions for window functions::
+
+    >>> from sqlalchemy import func
+
+    >>> print func.row_number().over(order_by='x', range_=(-5, 10))
+    row_number() OVER (ORDER BY x RANGE BETWEEN :param_1 PRECEDING AND :param_2 FOLLOWING)
+
+    >>> print func.row_number().over(order_by='x', rows=(None, 0))
+    row_number() OVER (ORDER BY x ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW)
+
+    >>> print func.row_number().over(order_by='x', range_=(-2, None))
+    row_number() OVER (ORDER BY x RANGE BETWEEN :param_1 PRECEDING AND UNBOUNDED FOLLOWING)
+
+:paramref:`.expression.over.range_` and :paramref:`.expression.over.rows` are specified as
+2-tuples and indicate negative and positive values for specific ranges,
+0 for "CURRENT ROW", and None for UNBOUNDED.
+
+.. seealso::
+
+    :ref:`window_functions`
+
+:ticket:`3049`
+
 .. _change_2857:
 
 Support for the SQL LATERAL keyword
index 043b537fc34dbe56520356f9fcffcce1cd2e3743..15aab52e74aed6675587431ce5936f47d76ff817 100644 (file)
@@ -1409,14 +1409,14 @@ of our selectable:
 
     :data:`.func`
 
+.. _window_functions:
+
 Window Functions
 -----------------
 
 Any :class:`.FunctionElement`, including functions generated by
 :data:`~.expression.func`, can be turned into a "window function", that is an
-OVER clause, using the :meth:`.FunctionElement.over` method:
-
-.. sourcecode:: pycon+sql
+OVER clause, using the :meth:`.FunctionElement.over` method::
 
     >>> s = select([
     ...         users.c.id,
@@ -1426,6 +1426,29 @@ OVER clause, using the :meth:`.FunctionElement.over` method:
     SELECT users.id, row_number() OVER (ORDER BY users.name) AS anon_1
     FROM users
 
+:meth:`.FunctionElement.over` also supports range specifciation using
+either the :paramref:`.expression.over.rows` or
+:paramref:`.expression.over.range` parameters::
+
+    >>> s = select([
+    ...         users.c.id,
+    ...         func.row_number().over(
+    ...                 order_by=users.c.name,
+    ...                 rows=(-2, None))
+    ...     ])
+    >>> print(s)
+    SELECT users.id, row_number() OVER
+    (ORDER BY users.name ROWS BETWEEN :param_1 PRECEDING AND UNBOUNDED FOLLOWING) AS anon_1
+    FROM users
+
+:paramref:`.expression.over.rows` and :paramref:`.expression.over.range` each
+accept a two-tuple which contains a combination of negative and positive
+integers for ranges, zero to indicate "CURRENT ROW" and ``None`` to
+indicate "UNBOUNDED".  See the examples at :func:`.over` for more detail.
+
+.. versionadded:: 1.1 support for "rows" and "range" specification for
+   window functions
+
 .. seealso::
 
     :func:`.over`
index 144f2aa473b76bda632b33d7fd10c1ccedc946f7..6d9ab9039f1e1175d24de76ee61f3ada9098e272 100644 (file)
@@ -810,16 +810,41 @@ class SQLCompiler(Compiled):
             (cast.clause._compiler_dispatch(self, **kwargs),
              cast.typeclause._compiler_dispatch(self, **kwargs))
 
+    def _format_frame_clause(self, range_, **kw):
+        return '%s AND %s' % (
+            "UNBOUNDED PRECEDING"
+            if range_[0] is elements.RANGE_UNBOUNDED
+            else "CURRENT ROW" if range_[0] is elements.RANGE_CURRENT
+            else "%s PRECEDING" % (self.process(range_[0], **kw), ),
+
+            "UNBOUNDED FOLLOWING"
+            if range_[1] is elements.RANGE_UNBOUNDED
+            else "CURRENT ROW" if range_[1] is elements.RANGE_CURRENT
+            else "%s FOLLOWING" % (self.process(range_[1], **kw), )
+        )
+
     def visit_over(self, over, **kwargs):
+        if over.range_:
+            range_ = "RANGE BETWEEN %s" % self._format_frame_clause(
+                over.range_, **kwargs)
+        elif over.rows:
+            range_ = "ROWS BETWEEN %s" % self._format_frame_clause(
+                over.rows, **kwargs)
+        else:
+            range_ = None
+
         return "%s OVER (%s)" % (
             over.element._compiler_dispatch(self, **kwargs),
-            ' '.join(
-                '%s BY %s' % (word, clause._compiler_dispatch(self, **kwargs))
+            ' '.join([
+                '%s BY %s' % (
+                    word, clause._compiler_dispatch(self, **kwargs)
+                )
                 for word, clause in (
                     ('PARTITION', over.partition_by),
                     ('ORDER', over.order_by)
                 )
                 if clause is not None and len(clause)
+            ] + ([range_] if range_ else [])
             )
         )
 
index e0367f967b416dfc93ffc6550c3233fdde528b52..e277b28a4cd0ac3299b1e558785088ddcac0825e 100644 (file)
@@ -3058,6 +3058,10 @@ class Grouping(ColumnElement):
             self.element.compare(other.element)
 
 
+RANGE_UNBOUNDED = util.symbol("RANGE_UNBOUNDED")
+RANGE_CURRENT = util.symbol("RANGE_CURRENT")
+
+
 class Over(ColumnElement):
     """Represent an OVER clause.
 
@@ -3073,7 +3077,9 @@ class Over(ColumnElement):
     order_by = None
     partition_by = None
 
-    def __init__(self, element, partition_by=None, order_by=None):
+    def __init__(
+            self, element, partition_by=None,
+            order_by=None, range_=None, rows=None):
         """Produce an :class:`.Over` object against a function.
 
         Used against aggregate or so-called "window" functions,
@@ -3082,9 +3088,41 @@ class Over(ColumnElement):
         :func:`~.expression.over` is usually called using
         the :meth:`.FunctionElement.over` method, e.g.::
 
-            func.row_number().over(order_by='x')
+            func.row_number().over(order_by=mytable.c.some_column)
+
+        Would produce::
+
+            ROW_NUMBER() OVER(ORDER BY some_column)
+
+        Ranges are also possible using the :paramref:`.expression.over.range_`
+        and :paramref:`.expression.over.rows` parameters.  These
+        mutually-exclusive parameters each accept a 2-tuple, which contains
+        a combination of integers and None::
+
+            func.row_number().over(order_by=my_table.c.some_column, range_=(None, 0))
+
+        The above would produce::
+
+            ROW_NUMBER() OVER(ORDER BY some_column RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW)
+
+        A value of None indicates "unbounded", a
+        value of zero indicates "current row", and negative / positive
+        integers indicate "preceding" and "following":
+
+        * RANGE BETWEEN 5 PRECEDING AND 10 FOLLOWING::
+
+            func.row_number().over(order_by='x', range_=(-5, 10))
+
+        * ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW::
+
+            func.row_number().over(order_by='x', rows=(None, 0))
+
+        * RANGE BETWEEN 2 PRECEDING AND UNBOUNDED FOLLOWING::
+
+            func.row_number().over(order_by='x', range_=(-2, None))
+
+        .. versionadded:: 1.1 support for RANGE / ROWS within a window
 
-        Would produce ``ROW_NUMBER() OVER(ORDER BY x)``.
 
         :param element: a :class:`.FunctionElement`, :class:`.WithinGroup`,
          or other compatible construct.
@@ -3094,12 +3132,21 @@ class Over(ColumnElement):
         :param order_by: a column element or string, or a list
          of such, that will be used as the ORDER BY clause
          of the OVER construct.
+        :param range_: optional range clause for the window.  This is a
+         tuple value which can contain integer values or None, and will
+         render a RANGE BETWEEN PRECEDING / FOLLOWING clause
+
+         .. versionadded:: 1.1
+
+        :param rows: optional rows clause for the window.  This is a tuple
+         value which can contain integer values or None, and will render
+         a ROWS BETWEEN PRECEDING / FOLLOWING clause.
+
+         .. versionadded:: 1.1
 
         This function is also available from the :data:`~.expression.func`
         construct itself via the :meth:`.FunctionElement.over` method.
 
-        .. versionadded:: 0.7
-
         .. seealso::
 
             :data:`.expression.func`
@@ -3117,6 +3164,61 @@ class Over(ColumnElement):
                 *util.to_list(partition_by),
                 _literal_as_text=_literal_as_label_reference)
 
+        if range_:
+            self.range_ = self._interpret_range(range_)
+            if rows:
+                raise exc.ArgumentError(
+                    "'range_' and 'rows' are mutually exclusive")
+            else:
+                self.rows = None
+        elif rows:
+            self.rows = self._interpret_range(rows)
+            self.range_ = None
+        else:
+            self.rows = self.range_ = None
+
+    def _interpret_range(self, range_):
+        if not isinstance(range_, tuple) or len(range_) != 2:
+            raise exc.ArgumentError("2-tuple expected for range/rows")
+
+        if range_[0] is None:
+            preceding = RANGE_UNBOUNDED
+        else:
+            try:
+                preceding = int(range_[0])
+            except ValueError:
+                raise exc.ArgumentError(
+                    "Integer or None expected for preceding value")
+            else:
+                if preceding > 0:
+                    raise exc.ArgumentError(
+                        "Preceding value must be a "
+                        "negative integer, zero, or None")
+                elif preceding < 0:
+                    preceding = literal(abs(preceding))
+                else:
+                    preceding = RANGE_CURRENT
+
+        if range_[1] is None:
+            following = RANGE_UNBOUNDED
+        else:
+            try:
+                following = int(range_[1])
+            except ValueError:
+                raise exc.ArgumentError(
+                    "Integer or None expected for following value")
+            else:
+                if following < 0:
+                    raise exc.ArgumentError(
+                        "Following value must be a positive "
+                        "integer, zero, or None")
+                elif following > 0:
+                    following = literal(following)
+                else:
+                    following = RANGE_CURRENT
+
+        return preceding, following
+
     @property
     def func(self):
         """the element referred to by this :class:`.Over`
index e369f5a615380016bf691dc8a39f36c8915a518b..5c977cd505318b5d0ff4f4056eb9f03a6e40f4a3 100644 (file)
@@ -94,7 +94,7 @@ class FunctionElement(Executable, ColumnElement, FromClause):
         """
         return self.clause_expr.element
 
-    def over(self, partition_by=None, order_by=None):
+    def over(self, partition_by=None, order_by=None, rows=None, range_=None):
         """Produce an OVER clause against this function.
 
         Used against aggregate or so-called "window" functions,
@@ -114,7 +114,13 @@ class FunctionElement(Executable, ColumnElement, FromClause):
         .. versionadded:: 0.7
 
         """
-        return Over(self, partition_by=partition_by, order_by=order_by)
+        return Over(
+            self,
+            partition_by=partition_by,
+            order_by=order_by,
+            rows=rows,
+            range_=range_
+        )
 
     def within_group(self, *order_by):
         """Produce a WITHIN GROUP (ORDER BY expr) clause against this function.
index dae178d31d26d0309c98a6402dec1c22eb5a1e85..ca3468710f75538d5e72daf7953d4149a85133df 100644 (file)
@@ -2329,6 +2329,73 @@ class SelectTest(fixtures.TestBase, AssertsCompiledSQL):
             "(ORDER BY mytable.myid + :myid_1) AS anon_1 FROM mytable"
         )
 
+    def test_over_framespec(self):
+
+        expr = table1.c.myid
+        self.assert_compile(
+            select([func.row_number().over(order_by=expr, rows=(0, None))]),
+            "SELECT row_number() OVER "
+            "(ORDER BY mytable.myid ROWS BETWEEN CURRENT "
+            "ROW AND UNBOUNDED FOLLOWING)"
+            " AS anon_1 FROM mytable"
+        )
+
+        self.assert_compile(
+            select([func.row_number().over(order_by=expr, rows=(None, None))]),
+            "SELECT row_number() OVER "
+            "(ORDER BY mytable.myid ROWS BETWEEN UNBOUNDED "
+            "PRECEDING AND UNBOUNDED FOLLOWING)"
+            " AS anon_1 FROM mytable"
+        )
+
+        self.assert_compile(
+            select([func.row_number().over(order_by=expr, range_=(None, 0))]),
+            "SELECT row_number() OVER "
+            "(ORDER BY mytable.myid RANGE BETWEEN "
+            "UNBOUNDED PRECEDING AND CURRENT ROW)"
+            " AS anon_1 FROM mytable"
+        )
+
+        self.assert_compile(
+            select([func.row_number().over(order_by=expr, range_=(-5, 10))]),
+            "SELECT row_number() OVER "
+            "(ORDER BY mytable.myid RANGE BETWEEN "
+            ":param_1 PRECEDING AND :param_2 FOLLOWING)"
+            " AS anon_1 FROM mytable",
+            {'param_1': 5, 'param_2': 10}
+        )
+
+    def test_over_invalid_framespecs(self):
+        assert_raises_message(
+            exc.ArgumentError,
+            "Preceding value must be a negative integer, zero, or None",
+            func.row_number().over, range_=(5, 10)
+        )
+
+        assert_raises_message(
+            exc.ArgumentError,
+            "Following value must be a positive integer, zero, or None",
+            func.row_number().over, range_=(-5, -8)
+        )
+
+        assert_raises_message(
+            exc.ArgumentError,
+            "Integer or None expected for preceding value",
+            func.row_number().over, range_=("foo", 8)
+        )
+
+        assert_raises_message(
+            exc.ArgumentError,
+            "Integer or None expected for following value",
+            func.row_number().over, range_=(-5, "foo")
+        )
+
+        assert_raises_message(
+            exc.ArgumentError,
+            "'range_' and 'rows' are mutually exclusive",
+            func.row_number().over, range_=(-5, 8), rows=(-2, 5)
+        )
+
     def test_date_between(self):
         import datetime
         table = Table('dt', metadata,