From: Mike Bayer Date: Fri, 11 Feb 2011 02:57:44 +0000 (-0500) Subject: - Added over() function, method to FunctionElement X-Git-Tag: rel_0_7b1~14 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=020d6ef8f017d4411b403c18d93f913d6b01fd62;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git - Added over() function, method to FunctionElement classes, produces the _Over() construct which in turn generates "window functions", i.e. " OVER (PARTITION BY , ORDER BY )". [ticket:1844] --- diff --git a/CHANGES b/CHANGES index 0e87855fb5..0371cc87dc 100644 --- a/CHANGES +++ b/CHANGES @@ -123,6 +123,13 @@ CHANGES as DISTINCT ON (). [ticket:1069] - sql + - Added over() function, method to FunctionElement + classes, produces the _Over() construct which + in turn generates "window functions", i.e. + " OVER (PARTITION BY , + ORDER BY )". + [ticket:1844] + - LIMIT/OFFSET clauses now use bind parameters [ticket:805] diff --git a/doc/build/core/expression_api.rst b/doc/build/core/expression_api.rst index a977e86a5e..12fab1ba48 100644 --- a/doc/build/core/expression_api.rst +++ b/doc/build/core/expression_api.rst @@ -71,6 +71,8 @@ The expression package uses functions to construct SQL expressions. The return .. autofunction:: outerjoin +.. autofunction:: over + .. autofunction:: select .. autofunction:: subquery @@ -104,6 +106,10 @@ Classes :members: :show-inheritance: +.. autoclass:: ClauseList + :members: + :show-inheritance: + .. autoclass:: ColumnClause :members: :show-inheritance: diff --git a/doc/build/core/tutorial.rst b/doc/build/core/tutorial.rst index 543d57ae25..b52990b6db 100644 --- a/doc/build/core/tutorial.rst +++ b/doc/build/core/tutorial.rst @@ -425,7 +425,6 @@ As you can see, the ``==`` operator is producing an object that is very much lik Operators ========== - Since we've stumbled upon SQLAlchemy's operator paradigm, let's go through some of its capabilities. We've seen how to equate two columns to each other: .. sourcecode:: pycon+sql @@ -843,8 +842,7 @@ Bind parameters of the same name can also be used multiple times, where only a s Functions --------- - -SQL functions are created using the ``func`` keyword, which generates functions using attribute access: +SQL functions are created using the :attr:`~.expression.func` keyword, which generates functions using attribute access: .. sourcecode:: pycon+sql @@ -913,6 +911,19 @@ If we wanted to use our ``calculate`` statement twice with different bind parame See also :attr:`sqlalchemy.sql.expression.func`. +Window Functions +----------------- + +Any :class:`.FunctionElement`, including functions generated by :attr:`~.expression.func`, can be turned into a "window function", that is +an OVER clause, using the :meth:`~.FunctionElement.over` method: + +.. sourcecode:: pycon+sql + + >>> s = select([users.c.id, func.row_number().over(order_by=users.c.name)]) + >>> print s # doctest: +NORMALIZE_WHITESPACE + SELECT users.id, row_number() OVER (ORDER BY users.name) AS anon_1 + FROM users + Unions and Other Set Operations ------------------------------- diff --git a/lib/sqlalchemy/__init__.py b/lib/sqlalchemy/__init__.py index 239b2b363c..d54afa41c4 100644 --- a/lib/sqlalchemy/__init__.py +++ b/lib/sqlalchemy/__init__.py @@ -39,6 +39,7 @@ from sqlalchemy.sql import ( or_, outerjoin, outparam, + over, select, subquery, text, diff --git a/lib/sqlalchemy/engine/base.py b/lib/sqlalchemy/engine/base.py index cf6c6ad49f..ae29ac40b4 100644 --- a/lib/sqlalchemy/engine/base.py +++ b/lib/sqlalchemy/engine/base.py @@ -791,6 +791,14 @@ class Connectable(object): raise NotImplementedError() def execute(self, object, *multiparams, **params): + """Executes the given construct and returns a :class:`.ResultProxy`.""" + raise NotImplementedError() + + def scalar(self, object, *multiparams, **params): + """Executes and returns the first column of the first row. + + The underlying cursor is closed after execution. + """ raise NotImplementedError() def _execute_clauseelement(self, elem, multiparams=None, params=None): diff --git a/lib/sqlalchemy/sql/__init__.py b/lib/sqlalchemy/sql/__init__.py index 80aa769284..c591e6802e 100644 --- a/lib/sqlalchemy/sql/__init__.py +++ b/lib/sqlalchemy/sql/__init__.py @@ -48,6 +48,7 @@ from sqlalchemy.sql.expression import ( or_, outerjoin, outparam, + over, select, subquery, table, diff --git a/lib/sqlalchemy/sql/compiler.py b/lib/sqlalchemy/sql/compiler.py index 1ab0ba4054..781072dd03 100644 --- a/lib/sqlalchemy/sql/compiler.py +++ b/lib/sqlalchemy/sql/compiler.py @@ -446,12 +446,14 @@ class SQLCompiler(engine.Compiled): if clause.value is not None: x += clause.value._compiler_dispatch(self, **kwargs) + " " for cond, result in clause.whens: - x += "WHEN " + cond._compiler_dispatch(self, **kwargs) + \ - " THEN " + \ - result._compiler_dispatch(self, **kwargs) + " " + x += "WHEN " + cond._compiler_dispatch( + self, **kwargs + ) + " THEN " + result._compiler_dispatch( + self, **kwargs) + " " if clause.else_ is not None: - x += "ELSE " + clause.else_._compiler_dispatch(self, **kwargs) + \ - " " + x += "ELSE " + clause.else_._compiler_dispatch( + self, **kwargs + ) + " " x += "END" return x @@ -460,6 +462,19 @@ class SQLCompiler(engine.Compiled): (cast.clause._compiler_dispatch(self, **kwargs), cast.typeclause._compiler_dispatch(self, **kwargs)) + def visit_over(self, over, **kwargs): + x ="%s OVER (" % over.func._compiler_dispatch(self, **kwargs) + if over.partition_by is not None: + x += "PARTITION BY %s" % \ + over.partition_by._compiler_dispatch(self, **kwargs) + if over.order_by is not None: + x += ", " + if over.order_by is not None: + x += "ORDER BY %s" % \ + over.order_by._compiler_dispatch(self, **kwargs) + x += ")" + return x + def visit_extract(self, extract, **kwargs): field = self.extract_map.get(extract.field, extract.field) return "EXTRACT(%s FROM %s)" % (field, diff --git a/lib/sqlalchemy/sql/expression.py b/lib/sqlalchemy/sql/expression.py index 4287216a42..2a23d146b5 100644 --- a/lib/sqlalchemy/sql/expression.py +++ b/lib/sqlalchemy/sql/expression.py @@ -47,7 +47,7 @@ __all__ = [ 'except_', 'except_all', 'exists', 'extract', 'func', 'modifier', 'collate', 'insert', 'intersect', 'intersect_all', 'join', 'label', 'literal', 'literal_column', 'not_', 'null', 'nullsfirst', 'nullslast', - 'or_', 'outparam', 'outerjoin', 'select', 'subquery', 'table', 'text', + 'or_', 'outparam', 'outerjoin', 'over', 'select', 'subquery', 'table', 'text', 'tuple_', 'type_coerce', 'union', 'union_all', 'update', ] PARSE_AUTOCOMMIT = util.symbol('PARSE_AUTOCOMMIT') @@ -1000,6 +1000,36 @@ def text(text, bind=None, *args, **kwargs): """ return _TextClause(text, bind=bind, *args, **kwargs) +def over(func, partition_by=None, order_by=None): + """Produce an OVER clause against a function. + + Used against aggregate or so-called "window" functions, + for database backends that support window functions. + + E.g.:: + + from sqlalchemy import over + over(func.row_number(), order_by='x') + + Would produce "ROW_NUMBER() OVER(ORDER BY x)". + + :param func: a :class:`.FunctionElement` construct, typically + generated by :attr:`~.expression.func`. + :param partition_by: a column element or string, or a list + of such, that will be used as the PARTITION BY clause + of the OVER construct. + :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. + + This function is also available from the :attr:`~.expression.func` + construct itself via the :meth:`.FunctionElement.over` method. + + New in 0.7. + + """ + return _Over(func, partition_by=partition_by, order_by=order_by) + def null(): """Return a :class:`_Null` object, which compiles to ``NULL`` in a sql statement. @@ -1050,7 +1080,7 @@ func = _FunctionGenerator() >>> print func.count(1) count(:param_1) - Any name can be given to `func`. If the function name is unknown to + Any name can be given to ``func``. If the function name is unknown to SQLAlchemy, it will be rendered exactly as is. For common SQL functions which SQLAlchemy is aware of, the name may be interpreted as a *generic function* which will be compiled appropriately to the target database:: @@ -1062,7 +1092,7 @@ func = _FunctionGenerator() >>> print func.stats.yield_curve(5, 10) stats.yield_curve(:yield_curve_1, :yield_curve_2) - + SQLAlchemy can be made aware of the return type of functions to enable type-specific lexical and result-based behavior. For example, to ensure that a string-based function returns a Unicode value and is similarly @@ -1073,6 +1103,12 @@ func = _FunctionGenerator() ... func.my_string(u'there', type_=Unicode) my_string(:my_string_1) || :my_string_2 || my_string(:my_string_3) + The object returned by a ``func`` call is an instance of :class:`.Function`. + This object meets the "column" interface, including comparison and labeling + functions. The object can also be passed the :meth:`~.Connectable.execute` + method of a :class:`.Connection` or :class:`.Engine`, where it will be + wrapped inside of a SELECT statement first. + Functions which are interpreted as "generic" functions know how to calculate their return type automatically. For a listing of known generic functions, see :ref:`generic_functions`. @@ -2972,6 +3008,8 @@ class FunctionElement(Executable, ColumnElement, FromClause): """Base for SQL function-oriented constructs.""" def __init__(self, *clauses, **kwargs): + """Construct a :class:`.FunctionElement`. + """ args = [_literal_as_binds(c, self.name) for c in clauses] self.clause_expr = ClauseList( operator=operators.comma_op, @@ -2980,12 +3018,43 @@ class FunctionElement(Executable, ColumnElement, FromClause): @property def columns(self): + """Fulfill the 'columns' contrct of :class:`.ColumnElement`. + + Returns a single-element list consisting of this object. + + """ return [self] @util.memoized_property def clauses(self): + """Return the underlying :class:`.ClauseList` which contains + the arguments for this :class:`.FunctionElement`. + + """ return self.clause_expr.element + def over(self, partition_by=None, order_by=None): + """Produce an OVER clause against this function. + + Used against aggregate or so-called "window" functions, + for database backends that support window functions. + + The expression:: + + func.row_number().over(order_by='x') + + is shorthand for:: + + from sqlalchemy import over + over(func.row_number(), order_by='x') + + See :func:`~.expression.over` for a full description. + + New in 0.7. + + """ + return over(self, partition_by=partition_by, order_by=order_by) + @property def _from_objects(self): return self.clauses._from_objects @@ -2999,15 +3068,45 @@ class FunctionElement(Executable, ColumnElement, FromClause): util.reset_memoized(self, 'clauses') def select(self): + """Produce a :func:`~.expression.select` construct + against this :class:`FunctionElement`. + + This is shorthand for:: + + s = select([function_element]) + + """ s = select([self]) if self._execution_options: s = s.execution_options(**self._execution_options) return s def scalar(self): + """Execute this :class:`.FunctionElement` against an embedded + 'bind' and return a scalar value. + + This first calls :meth:`~.FunctionElement.select` to + produce a SELECT construct. + + Note that :class:`.FunctionElement` can be passed to + the :meth:`.Connectable.scalar` method of :class:`.Connection` + or :class:`.Engine`. + + """ return self.select().execute().scalar() def execute(self): + """Execute this :class:`.FunctionElement` against an embedded + 'bind'. + + This first calls :meth:`~.FunctionElement.select` to + produce a SELECT construct. + + Note that :class:`.FunctionElement` can be passed to + the :meth:`.Connectable.execute` method of :class:`.Connection` + or :class:`.Engine`. + + """ return self.select().execute() def _bind_param(self, operator, obj): @@ -3016,11 +3115,22 @@ class FunctionElement(Executable, ColumnElement, FromClause): class Function(FunctionElement): - """Describe a named SQL function.""" + """Describe a named SQL function. + + See the superclass :class:`.FunctionElement` for a description + of public methods. + + """ __visit_name__ = 'function' def __init__(self, name, *clauses, **kw): + """Construct a :class:`.Function`. + + The :attr:`.func` construct is normally used to construct + new :class:`.Function` instances. + + """ self.packagenames = kw.pop('packagenames', None) or [] self.name = name self._bind = kw.get('bind', None) @@ -3555,6 +3665,52 @@ class _FromGrouping(FromClause): def __setstate__(self, state): self.element = state['element'] +class _Over(ColumnElement): + """Represent an OVER clause. + + This is a special operator against a so-called + "window" function, as well as any aggregate function, + which produces results relative to the result set + itself. It's supported only by certain database + backends. + + """ + __visit_name__ = 'over' + + order_by = None + partition_by = None + + def __init__(self, func, partition_by=None, order_by=None): + self.func = func + if order_by is not None: + self.order_by = ClauseList(*util.to_list(order_by)) + if partition_by is not None: + self.partition_by = ClauseList(*util.to_list(partition_by)) + + @util.memoized_property + def type(self): + return self.func.type + + def get_children(self, **kwargs): + return [c for c in + (self.func, self.partition_by, self.order_by) + if c is not None] + + def _copy_internals(self, clone=_clone): + self.func = clone(self.func) + if self.partition_by is not None: + self.partition_by = clone(self.partition_by) + if self.order_by is not None: + self.order_by = clone(self.order_by) + + @property + def _from_objects(self): + return itertools.chain( + *[c._from_objects for c in + (self.func, self.partition_by, self.order_by) + if c is not None] + ) + class _Label(ColumnElement): """Represents a column label (AS). diff --git a/test/lib/requires.py b/test/lib/requires.py index 610caa9f57..e3f044868b 100644 --- a/test/lib/requires.py +++ b/test/lib/requires.py @@ -210,6 +210,13 @@ def offset(fn): fails_on('sybase', 'no support for OFFSET or equivalent'), ) +def window_functions(fn): + return _chain_decorators_on( + fn, + only_on(('postgresql', 'mssql', 'oracle'), + "Backend does not support window functions"), + ) + def returning(fn): return _chain_decorators_on( fn, diff --git a/test/sql/test_compiler.py b/test/sql/test_compiler.py index 5a6d46b1b4..4ede563204 100644 --- a/test/sql/test_compiler.py +++ b/test/sql/test_compiler.py @@ -2040,6 +2040,79 @@ class SelectTest(TestBase, AssertsCompiledSQL): 'CAST(NULL AS INTEGER)', dialect=sqlite.dialect()) + def test_over(self): + self.assert_compile( + func.row_number().over( + order_by=[table1.c.name, table1.c.description] + ), + "row_number() OVER (ORDER BY mytable.name, mytable.description)" + ) + self.assert_compile( + func.row_number().over( + partition_by=[table1.c.name, table1.c.description] + ), + "row_number() OVER (PARTITION BY mytable.name, " + "mytable.description)" + ) + self.assert_compile( + func.row_number().over( + partition_by=[table1.c.name], + order_by=[table1.c.description] + ), + "row_number() OVER (PARTITION BY mytable.name, " + "ORDER BY mytable.description)" + ) + self.assert_compile( + func.row_number().over( + partition_by=table1.c.name, + order_by=table1.c.description + ), + "row_number() OVER (PARTITION BY mytable.name, " + "ORDER BY mytable.description)" + ) + + self.assert_compile( + select([func.row_number().over( + order_by=table1.c.description + ).label('foo')]), + "SELECT row_number() OVER (ORDER BY mytable.description) " + "AS foo FROM mytable" + ) + + # test from_obj generation. + # from func: + self.assert_compile( + select([ + func.max(table1.c.name).over( + partition_by=['foo'] + ) + ]), + "SELECT max(mytable.name) OVER (PARTITION BY foo) " + "AS anon_1 FROM mytable" + ) + # from partition_by + self.assert_compile( + select([ + func.row_number().over( + partition_by=[table1.c.name] + ) + ]), + "SELECT row_number() OVER (PARTITION BY mytable.name) " + "AS anon_1 FROM mytable" + ) + # from order_by + self.assert_compile( + select([ + func.row_number().over( + order_by=table1.c.name + ) + ]), + "SELECT row_number() OVER (ORDER BY mytable.name) " + "AS anon_1 FROM mytable" + ) + + + def test_date_between(self): import datetime table = Table('dt', metadata, diff --git a/test/sql/test_generative.py b/test/sql/test_generative.py index 627736370d..f132cbb2d7 100644 --- a/test/sql/test_generative.py +++ b/test/sql/test_generative.py @@ -316,6 +316,11 @@ class ClauseTest(TestBase, AssertsCompiledSQL): expr2 = CloningVisitor().traverse(expr) assert str(expr) == str(expr2) + def test_over(self): + expr = func.row_number().over(order_by=t1.c.col1) + expr2 = CloningVisitor().traverse(expr) + assert str(expr) == str(expr2) + def test_adapt_union(self): u = union(t1.select().where(t1.c.col1==4), t1.select().where(t1.c.col1==5)).alias() diff --git a/test/sql/test_query.py b/test/sql/test_query.py index 359084cd81..1adb00aea1 100644 --- a/test/sql/test_query.py +++ b/test/sql/test_query.py @@ -1764,5 +1764,14 @@ class OperatorTest(TestBase): [(2,),(1,)] ) + @testing.requires.window_functions + def test_over(self): + eq_( + select([ + flds.c.intcol, func.row_number().over(order_by=flds.c.strcol) + ]).execute().fetchall(), + [(13, 1L), (5, 2L)] + ) +