SQL functions which are known to SQLAlchemy with regards to database-specific
rendering, return types and argument behavior. Generic functions are invoked
like all SQL functions, using the func
attribute:
select([func.count()]).select_from(sometable)
Note that any name not known to func
generates the function name as is
- there is no restriction on what SQL functions can be called, known or
unknown to SQLAlchemy, built-in or user defined. The section here only
describes those functions where SQLAlchemy already knows what argument and
return types are in use.
SQL function API, factories, and built-in functions.
sqlalchemy.sql.functions.
AnsiFunction
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
identifier
= 'AnsiFunction'¶name
= 'AnsiFunction'¶sqlalchemy.sql.functions.
Function
(name, *clauses, **kw)¶Bases: sqlalchemy.sql.functions.FunctionElement
Describe a named SQL function.
The Function
object is typically generated from the
func
generation object.
Parameters: |
|
---|
See also
func
- namespace which produces registered or ad-hoc
Function
instances.
GenericFunction
- allows creation of registered function
types.
sqlalchemy.sql.functions.
FunctionAsBinary
(fn, left_index, right_index)¶Bases: sqlalchemy.sql.expression.BinaryExpression
left
¶right
¶sqlalchemy.sql.functions.
FunctionElement
(*clauses, **kwargs)¶Bases: sqlalchemy.sql.expression.Executable
, sqlalchemy.sql.expression.ColumnElement
, sqlalchemy.sql.expression.FromClause
Base for SQL function-oriented constructs.
See also
Functions - in the Core tutorial
Function
- named SQL function.
func
- namespace which produces registered or ad-hoc
Function
instances.
GenericFunction
- allows creation of registered function
types.
__init__
(*clauses, **kwargs)¶Construct a FunctionElement
.
Parameters: |
---|
alias
(name=None, flat=False)¶Produce a Alias
construct against this
FunctionElement
.
This construct wraps the function in a named alias which is suitable for the FROM clause, in the style accepted for example by PostgreSQL.
e.g.:
from sqlalchemy.sql import column
stmt = select([column('data_view')]).\
select_from(SomeTable).\
select_from(func.unnest(SomeTable.data).alias('data_view')
)
Would produce:
SELECT data_view
FROM sometable, unnest(sometable.data) AS data_view
New in version 0.9.8: The FunctionElement.alias()
method
is now supported. Previously, this method’s behavior was
undefined and did not behave consistently across versions.
as_comparison
(left_index, right_index)¶Interpret this expression as a boolean comparison between two values.
A hypothetical SQL function “is_equal()” which compares to values for equality would be written in the Core expression language as:
expr = func.is_equal("a", "b")
If “is_equal()” above is comparing “a” and “b” for equality, the
FunctionElement.as_comparison()
method would be invoked as:
expr = func.is_equal("a", "b").as_comparison(1, 2)
Where above, the integer value “1” refers to the first argument of the “is_equal()” function and the integer value “2” refers to the second.
This would create a BinaryExpression
that is equivalent to:
BinaryExpression("a", "b", operator=op.eq)
However, at the SQL level it would still render as “is_equal(‘a’, ‘b’)”.
The ORM, when it loads a related object or collection, needs to be able
to manipulate the “left” and “right” sides of the ON clause of a JOIN
expression. The purpose of this method is to provide a SQL function
construct that can also supply this information to the ORM, when used
with the relationship.primaryjoin
parameter. The return
value is a containment object called FunctionAsBinary
.
An ORM example is as follows:
class Venue(Base):
__tablename__ = 'venue'
id = Column(Integer, primary_key=True)
name = Column(String)
descendants = relationship(
"Venue",
primaryjoin=func.instr(
remote(foreign(name)), name + "/"
).as_comparison(1, 2) == 1,
viewonly=True,
order_by=name
)
Above, the “Venue” class can load descendant “Venue” objects by determining if the name of the parent Venue is contained within the start of the hypothetical descendant value’s name, e.g. “parent1” would match up to “parent1/child1”, but not to “parent2/child1”.
Possible use cases include the “materialized path” example given above, as well as making use of special SQL functions such as geometric functions to create join conditions.
Parameters: |
---|
New in version 1.3.
clauses
¶Return the underlying ClauseList
which contains
the arguments for this FunctionElement
.
columns
¶The set of columns exported by this FunctionElement
.
Function objects currently have no result column names built in; this method returns a single-element column collection with an anonymously named column.
An interim approach to providing named columns for a function
as a FROM clause is to build a select()
with the
desired columns:
from sqlalchemy.sql import column
stmt = select([column('x'), column('y')]). select_from(func.myfunction())
execute
()¶Execute this FunctionElement
against an embedded
‘bind’.
This first calls select()
to
produce a SELECT construct.
Note that FunctionElement
can be passed to
the Connectable.execute()
method of Connection
or Engine
.
filter
(*criterion)¶Produce a FILTER clause against this function.
Used against aggregate and window functions, for database backends that support the “FILTER” clause.
The expression:
func.count(1).filter(True)
is shorthand for:
from sqlalchemy import funcfilter
funcfilter(func.count(1), True)
New in version 1.0.0.
get_children
(**kwargs)¶Return immediate child elements of this ClauseElement
.
This is used for visit traversal.
**kwargs may contain flags that change the collection that is returned, for example to return a subset of items in order to cut down on larger traversals, or to return child items from a different context (such as schema-level collections instead of clause-level).
over
(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, 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 over()
for a full description.
packagenames
= ()¶scalar
()¶Execute this FunctionElement
against an embedded
‘bind’ and return a scalar value.
This first calls select()
to
produce a SELECT construct.
Note that FunctionElement
can be passed to
the Connectable.scalar()
method of Connection
or Engine
.
select
()¶Produce a select()
construct
against this FunctionElement
.
This is shorthand for:
s = select([function_element])
self_group
(against=None)¶Apply a ‘grouping’ to this ClauseElement
.
This method is overridden by subclasses to return a
“grouping” construct, i.e. parenthesis. In particular
it’s used by “binary” expressions to provide a grouping
around themselves when placed into a larger expression,
as well as by select()
constructs when placed into
the FROM clause of another select()
. (Note that
subqueries should be normally created using the
Select.alias()
method, as many platforms require
nested SELECT statements to be named).
As expressions are composed together, the application of
self_group()
is automatic - end-user code should never
need to use this method directly. Note that SQLAlchemy’s
clause constructs take operator precedence into account -
so parenthesis might not be needed, for example, in
an expression like x OR (y AND z)
- AND takes precedence
over OR.
The base self_group()
method of ClauseElement
just returns self.
within_group
(*order_by)¶Produce a WITHIN GROUP (ORDER BY expr) clause against this function.
Used against so-called “ordered set aggregate” and “hypothetical
set aggregate” functions, including percentile_cont
,
rank
, dense_rank
, etc.
See within_group()
for a full description.
New in version 1.1.
within_group_type
(within_group)¶For types that define their return type as based on the criteria
within a WITHIN GROUP (ORDER BY) expression, called by the
WithinGroup
construct.
Returns None by default, in which case the function’s normal .type
is used.
sqlalchemy.sql.functions.
GenericFunction
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.Function
Define a ‘generic’ function.
A generic function is a pre-established Function
class that is instantiated automatically when called
by name from the func
attribute. Note that
calling any name from func
has the effect that
a new Function
instance is created automatically,
given that name. The primary use case for defining
a GenericFunction
class is so that a function
of a particular name may be given a fixed return type.
It can also include custom argument parsing schemes as well
as additional methods.
Subclasses of GenericFunction
are automatically
registered under the name of the class. For
example, a user-defined function as_utc()
would
be available immediately:
from sqlalchemy.sql.functions import GenericFunction
from sqlalchemy.types import DateTime
class as_utc(GenericFunction):
type = DateTime
print select([func.as_utc()])
User-defined generic functions can be organized into
packages by specifying the “package” attribute when defining
GenericFunction
. Third party libraries
containing many functions may want to use this in order
to avoid name conflicts with other systems. For example,
if our as_utc()
function were part of a package
“time”:
class as_utc(GenericFunction):
type = DateTime
package = "time"
The above function would be available from func
using the package name time
:
print select([func.time.as_utc()])
A final option is to allow the function to be accessed
from one name in func
but to render as a different name.
The identifier
attribute will override the name used to
access the function as loaded from func
, but will retain
the usage of name
as the rendered name:
class GeoBuffer(GenericFunction):
type = Geometry
package = "geo"
name = "ST_Buffer"
identifier = "buffer"
The above function will render as follows:
>>> print func.geo.buffer()
ST_Buffer()
coerce_arguments
= True¶identifier
= 'GenericFunction'¶name
= 'GenericFunction'¶sqlalchemy.sql.functions.
OrderedSetAgg
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
Define a function where the return type is based on the sort
expression type as defined by the expression passed to the
FunctionElement.within_group()
method.
array_for_multi_clause
= False¶identifier
= 'OrderedSetAgg'¶name
= 'OrderedSetAgg'¶within_group_type
(within_group)¶For types that define their return type as based on the criteria
within a WITHIN GROUP (ORDER BY) expression, called by the
WithinGroup
construct.
Returns None by default, in which case the function’s normal .type
is used.
sqlalchemy.sql.functions.
ReturnTypeFromArgs
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
Define a function whose return type is the same as its arguments.
identifier
= 'ReturnTypeFromArgs'¶name
= 'ReturnTypeFromArgs'¶sqlalchemy.sql.functions.
array_agg
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
support for the ARRAY_AGG function.
The func.array_agg(expr)
construct returns an expression of
type types.ARRAY
.
e.g.:
stmt = select([func.array_agg(table.c.values)[2:5]])
New in version 1.1.
See also
postgresql.array_agg()
- PostgreSQL-specific version that
returns postgresql.ARRAY
, which has PG-specific operators
added.
identifier
= 'array_agg'¶name
= 'array_agg'¶type
¶alias of sqlalchemy.sql.sqltypes.ARRAY
sqlalchemy.sql.functions.
char_length
(arg, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
identifier
= 'char_length'¶name
= 'char_length'¶type
¶alias of sqlalchemy.sql.sqltypes.Integer
sqlalchemy.sql.functions.
coalesce
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.ReturnTypeFromArgs
identifier
= 'coalesce'¶name
= 'coalesce'¶sqlalchemy.sql.functions.
concat
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
identifier
= 'concat'¶name
= 'concat'¶type
¶alias of sqlalchemy.sql.sqltypes.String
sqlalchemy.sql.functions.
count
(expression=None, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
The ANSI COUNT aggregate function. With no arguments, emits COUNT *.
E.g.:
from sqlalchemy import func
from sqlalchemy import select
from sqlalchemy import table, column
my_table = table('some_table', column('id'))
stmt = select([func.count()]).select_from(my_table)
Executing stmt
would emit:
SELECT count(*) AS count_1
FROM some_table
identifier
= 'count'¶name
= 'count'¶type
¶alias of sqlalchemy.sql.sqltypes.Integer
sqlalchemy.sql.functions.
cube
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
Implement the CUBE
grouping operation.
This function is used as part of the GROUP BY of a statement,
e.g. Select.group_by()
:
stmt = select(
[func.sum(table.c.value), table.c.col_1, table.c.col_2]
).group_by(func.cube(table.c.col_1, table.c.col_2))
New in version 1.2.
identifier
= 'cube'¶name
= 'cube'¶sqlalchemy.sql.functions.
cume_dist
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
Implement the cume_dist
hypothetical-set aggregate function.
This function must be used with the FunctionElement.within_group()
modifier to supply a sort expression to operate upon.
The return type of this function is Numeric
.
New in version 1.1.
identifier
= 'cume_dist'¶name
= 'cume_dist'¶type
= Numeric()¶sqlalchemy.sql.functions.
current_date
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.AnsiFunction
identifier
= 'current_date'¶name
= 'current_date'¶type
¶alias of sqlalchemy.sql.sqltypes.Date
sqlalchemy.sql.functions.
current_time
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.AnsiFunction
identifier
= 'current_time'¶name
= 'current_time'¶type
¶alias of sqlalchemy.sql.sqltypes.Time
sqlalchemy.sql.functions.
current_timestamp
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.AnsiFunction
identifier
= 'current_timestamp'¶name
= 'current_timestamp'¶type
¶alias of sqlalchemy.sql.sqltypes.DateTime
sqlalchemy.sql.functions.
current_user
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.AnsiFunction
identifier
= 'current_user'¶name
= 'current_user'¶type
¶alias of sqlalchemy.sql.sqltypes.String
sqlalchemy.sql.functions.
dense_rank
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
Implement the dense_rank
hypothetical-set aggregate function.
This function must be used with the FunctionElement.within_group()
modifier to supply a sort expression to operate upon.
The return type of this function is Integer
.
New in version 1.1.
identifier
= 'dense_rank'¶name
= 'dense_rank'¶type
= Integer()¶sqlalchemy.sql.functions.
grouping_sets
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
Implement the GROUPING SETS
grouping operation.
This function is used as part of the GROUP BY of a statement,
e.g. Select.group_by()
:
stmt = select(
[func.sum(table.c.value), table.c.col_1, table.c.col_2]
).group_by(func.grouping_sets(table.c.col_1, table.c.col_2))
In order to group by multiple sets, use the tuple_()
construct:
from sqlalchemy import tuple_
stmt = select(
[
func.sum(table.c.value),
table.c.col_1, table.c.col_2,
table.c.col_3]
).group_by(
func.grouping_sets(
tuple_(table.c.col_1, table.c.col_2),
tuple_(table.c.value, table.c.col_3),
)
)
New in version 1.2.
identifier
= 'grouping_sets'¶name
= 'grouping_sets'¶sqlalchemy.sql.functions.
localtime
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.AnsiFunction
identifier
= 'localtime'¶name
= 'localtime'¶type
¶alias of sqlalchemy.sql.sqltypes.DateTime
sqlalchemy.sql.functions.
localtimestamp
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.AnsiFunction
identifier
= 'localtimestamp'¶name
= 'localtimestamp'¶type
¶alias of sqlalchemy.sql.sqltypes.DateTime
sqlalchemy.sql.functions.
max
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.ReturnTypeFromArgs
identifier
= 'max'¶name
= 'max'¶sqlalchemy.sql.functions.
min
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.ReturnTypeFromArgs
identifier
= 'min'¶name
= 'min'¶sqlalchemy.sql.functions.
mode
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.OrderedSetAgg
implement the mode
ordered-set aggregate function.
This function must be used with the FunctionElement.within_group()
modifier to supply a sort expression to operate upon.
The return type of this function is the same as the sort expression.
New in version 1.1.
identifier
= 'mode'¶name
= 'mode'¶sqlalchemy.sql.functions.
next_value
(seq, **kw)¶Bases: sqlalchemy.sql.functions.GenericFunction
Represent the ‘next value’, given a Sequence
as its single argument.
Compiles into the appropriate function on each backend, or will raise NotImplementedError if used on a backend that does not provide support for sequences.
identifier
= 'next_value'¶name
= 'next_value'¶type
= Integer()¶sqlalchemy.sql.functions.
now
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
identifier
= 'now'¶name
= 'now'¶type
¶alias of sqlalchemy.sql.sqltypes.DateTime
sqlalchemy.sql.functions.
percent_rank
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
Implement the percent_rank
hypothetical-set aggregate function.
This function must be used with the FunctionElement.within_group()
modifier to supply a sort expression to operate upon.
The return type of this function is Numeric
.
New in version 1.1.
identifier
= 'percent_rank'¶name
= 'percent_rank'¶type
= Numeric()¶sqlalchemy.sql.functions.
percentile_cont
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.OrderedSetAgg
implement the percentile_cont
ordered-set aggregate function.
This function must be used with the FunctionElement.within_group()
modifier to supply a sort expression to operate upon.
The return type of this function is the same as the sort expression,
or if the arguments are an array, an types.ARRAY
of the sort
expression’s type.
New in version 1.1.
array_for_multi_clause
= True¶identifier
= 'percentile_cont'¶name
= 'percentile_cont'¶sqlalchemy.sql.functions.
percentile_disc
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.OrderedSetAgg
implement the percentile_disc
ordered-set aggregate function.
This function must be used with the FunctionElement.within_group()
modifier to supply a sort expression to operate upon.
The return type of this function is the same as the sort expression,
or if the arguments are an array, an types.ARRAY
of the sort
expression’s type.
New in version 1.1.
array_for_multi_clause
= True¶identifier
= 'percentile_disc'¶name
= 'percentile_disc'¶sqlalchemy.sql.functions.
random
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
identifier
= 'random'¶name
= 'random'¶sqlalchemy.sql.functions.
rank
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
Implement the rank
hypothetical-set aggregate function.
This function must be used with the FunctionElement.within_group()
modifier to supply a sort expression to operate upon.
The return type of this function is Integer
.
New in version 1.1.
identifier
= 'rank'¶name
= 'rank'¶type
= Integer()¶sqlalchemy.sql.functions.
register_function
(identifier, fn, package='_default')¶Associate a callable with a particular func. name.
This is normally called by _GenericMeta, but is also
available by itself so that a non-Function construct
can be associated with the func
accessor (i.e.
CAST, EXTRACT).
sqlalchemy.sql.functions.
rollup
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.GenericFunction
Implement the ROLLUP
grouping operation.
This function is used as part of the GROUP BY of a statement,
e.g. Select.group_by()
:
stmt = select(
[func.sum(table.c.value), table.c.col_1, table.c.col_2]
).group_by(func.rollup(table.c.col_1, table.c.col_2))
New in version 1.2.
identifier
= 'rollup'¶name
= 'rollup'¶sqlalchemy.sql.functions.
session_user
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.AnsiFunction
identifier
= 'session_user'¶name
= 'session_user'¶type
¶alias of sqlalchemy.sql.sqltypes.String
sqlalchemy.sql.functions.
sum
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.ReturnTypeFromArgs
identifier
= 'sum'¶name
= 'sum'¶sqlalchemy.sql.functions.
sysdate
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.AnsiFunction
identifier
= 'sysdate'¶name
= 'sysdate'¶type
¶alias of sqlalchemy.sql.sqltypes.DateTime
sqlalchemy.sql.functions.
user
(*args, **kwargs)¶Bases: sqlalchemy.sql.functions.AnsiFunction
identifier
= 'user'¶name
= 'user'¶type
¶alias of sqlalchemy.sql.sqltypes.String