SQL and Generic Functions

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.

Object Name Description

AnsiFunction

array_agg

support for the ARRAY_AGG function.

char_length

coalesce

concat

count

The ANSI COUNT aggregate function. With no arguments, emits COUNT *.

cube

Implement the CUBE grouping operation.

cume_dist

Implement the cume_dist hypothetical-set aggregate function.

current_date

current_time

current_timestamp

current_user

dense_rank

Implement the dense_rank hypothetical-set aggregate function.

Function

Describe a named SQL function.

FunctionElement

Base for SQL function-oriented constructs.

GenericFunction

Define a ‘generic’ function.

grouping_sets

Implement the GROUPING SETS grouping operation.

localtime

localtimestamp

max

min

mode

implement the mode ordered-set aggregate function.

next_value

Represent the ‘next value’, given a Sequence as its single argument.

now

OrderedSetAgg

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.

percent_rank

Implement the percent_rank hypothetical-set aggregate function.

percentile_cont

implement the percentile_cont ordered-set aggregate function.

percentile_disc

implement the percentile_disc ordered-set aggregate function.

random

rank

Implement the rank hypothetical-set aggregate function.

register_function(identifier, fn[, package])

Associate a callable with a particular func. name.

ReturnTypeFromArgs

Define a function whose return type is the same as its arguments.

rollup

Implement the ROLLUP grouping operation.

session_user

sum

sysdate

user

class sqlalchemy.sql.functions.AnsiFunction(**kwargs)

Members

identifier, name

attribute sqlalchemy.sql.functions.AnsiFunction.identifier = 'AnsiFunction'
attribute sqlalchemy.sql.functions.AnsiFunction.name = 'AnsiFunction'
class sqlalchemy.sql.functions.Function(name, *clauses, **kw)

Describe a named SQL function.

See the superclass FunctionElement for a description of public methods.

See also

func - namespace which produces registered or ad-hoc Function instances.

GenericFunction - allows creation of registered function types.

Members

__init__()

method sqlalchemy.sql.functions.Function.__init__(name, *clauses, **kw)

Construct a Function.

The func construct is normally used to construct new Function instances.

class sqlalchemy.sql.functions.FunctionElement(*clauses, **kwargs)

Base for SQL function-oriented constructs.

See also

Function - named SQL function.

func - namespace which produces registered or ad-hoc Function instances.

GenericFunction - allows creation of registered function types.

method sqlalchemy.sql.functions.FunctionElement.__init__(*clauses, **kwargs)

Construct a FunctionElement.

method sqlalchemy.sql.functions.FunctionElement.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.

attribute sqlalchemy.sql.functions.FunctionElement.clauses

Return the underlying ClauseList which contains the arguments for this FunctionElement.

attribute sqlalchemy.sql.functions.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())
method sqlalchemy.sql.functions.FunctionElement.execute()

Execute this FunctionElement against an embedded ‘bind’.

This first calls FunctionElement.select() to produce a SELECT construct.

Note that FunctionElement can be passed to the Connectable.execute() method of Connection or Engine.

method sqlalchemy.sql.functions.FunctionElement.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.

method sqlalchemy.sql.functions.FunctionElement.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).

method sqlalchemy.sql.functions.FunctionElement.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.

attribute sqlalchemy.sql.functions.FunctionElement.packagenames = ()
method sqlalchemy.sql.functions.FunctionElement.scalar()

Execute this FunctionElement against an embedded ‘bind’ and return a scalar value.

This first calls FunctionElement.select() to produce a SELECT construct.

Note that FunctionElement can be passed to the Connectable.scalar() method of Connection or Engine.

method sqlalchemy.sql.functions.FunctionElement.select()

Produce a select() construct against this FunctionElement.

This is shorthand for:

s = select([function_element])
method sqlalchemy.sql.functions.FunctionElement.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.

method sqlalchemy.sql.functions.FunctionElement.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.

method sqlalchemy.sql.functions.FunctionElement.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.

class sqlalchemy.sql.functions.GenericFunction(*args, **kwargs)

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()
attribute sqlalchemy.sql.functions.GenericFunction.coerce_arguments = True
attribute sqlalchemy.sql.functions.GenericFunction.identifier = 'GenericFunction'
attribute sqlalchemy.sql.functions.GenericFunction.name = 'GenericFunction'
class sqlalchemy.sql.functions.OrderedSetAgg(*args, **kwargs)

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.

attribute sqlalchemy.sql.functions.OrderedSetAgg.array_for_multi_clause = False
attribute sqlalchemy.sql.functions.OrderedSetAgg.identifier = 'OrderedSetAgg'
attribute sqlalchemy.sql.functions.OrderedSetAgg.name = 'OrderedSetAgg'
method sqlalchemy.sql.functions.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.

class sqlalchemy.sql.functions.ReturnTypeFromArgs(*args, **kwargs)

Define a function whose return type is the same as its arguments.

Members

identifier, name

attribute sqlalchemy.sql.functions.ReturnTypeFromArgs.identifier = 'ReturnTypeFromArgs'
attribute sqlalchemy.sql.functions.ReturnTypeFromArgs.name = 'ReturnTypeFromArgs'
class sqlalchemy.sql.functions.array_agg(*args, **kwargs)

support for the ARRAY_AGG function.

The func.array_agg(expr) construct returns an expression of type ARRAY.

e.g.:

stmt = select([func.array_agg(table.c.values)[2:5]])

New in version 1.1.

See also

array_agg() - PostgreSQL-specific version that returns ARRAY, which has PG-specific operators added.

Members

identifier, name, type

attribute sqlalchemy.sql.functions.array_agg.identifier = 'array_agg'
attribute sqlalchemy.sql.functions.array_agg.name = 'array_agg'
attribute sqlalchemy.sql.functions.array_agg.type

alias of ARRAY

class sqlalchemy.sql.functions.char_length(arg, **kwargs)

Members

identifier, name, type

attribute sqlalchemy.sql.functions.char_length.identifier = 'char_length'
attribute sqlalchemy.sql.functions.char_length.name = 'char_length'
attribute sqlalchemy.sql.functions.char_length.type

alias of Integer

class sqlalchemy.sql.functions.coalesce(*args, **kwargs)

Members

identifier, name

attribute sqlalchemy.sql.functions.coalesce.identifier = 'coalesce'
attribute sqlalchemy.sql.functions.coalesce.name = 'coalesce'
class sqlalchemy.sql.functions.concat(*args, **kwargs)

Members

identifier, name, type

attribute sqlalchemy.sql.functions.concat.identifier = 'concat'
attribute sqlalchemy.sql.functions.concat.name = 'concat'
attribute sqlalchemy.sql.functions.concat.type

alias of String

class sqlalchemy.sql.functions.count(expression=None, **kwargs)

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

Members

identifier, name, type

attribute sqlalchemy.sql.functions.count.identifier = 'count'
attribute sqlalchemy.sql.functions.count.name = 'count'
attribute sqlalchemy.sql.functions.count.type

alias of Integer

class sqlalchemy.sql.functions.cube(*args, **kwargs)

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.

Members

identifier, name

attribute sqlalchemy.sql.functions.cube.identifier = 'cube'
attribute sqlalchemy.sql.functions.cube.name = 'cube'
class sqlalchemy.sql.functions.cume_dist(*args, **kwargs)

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.

Members

identifier, name, type

attribute sqlalchemy.sql.functions.cume_dist.identifier = 'cume_dist'
attribute sqlalchemy.sql.functions.cume_dist.name = 'cume_dist'
attribute sqlalchemy.sql.functions.cume_dist.type = Numeric()
class sqlalchemy.sql.functions.current_date(**kwargs)

Members

identifier, name, type

attribute sqlalchemy.sql.functions.current_date.identifier = 'current_date'
attribute sqlalchemy.sql.functions.current_date.name = 'current_date'
attribute sqlalchemy.sql.functions.current_date.type

alias of Date

class sqlalchemy.sql.functions.current_time(**kwargs)

Members

identifier, name, type

attribute sqlalchemy.sql.functions.current_time.identifier = 'current_time'
attribute sqlalchemy.sql.functions.current_time.name = 'current_time'
attribute sqlalchemy.sql.functions.current_time.type

alias of Time

class sqlalchemy.sql.functions.current_timestamp(**kwargs)

Members

identifier, name, type

attribute sqlalchemy.sql.functions.current_timestamp.identifier = 'current_timestamp'
attribute sqlalchemy.sql.functions.current_timestamp.name = 'current_timestamp'
attribute sqlalchemy.sql.functions.current_timestamp.type

alias of DateTime

class sqlalchemy.sql.functions.current_user(**kwargs)

Members

identifier, name, type

attribute sqlalchemy.sql.functions.current_user.identifier = 'current_user'
attribute sqlalchemy.sql.functions.current_user.name = 'current_user'
attribute sqlalchemy.sql.functions.current_user.type

alias of String

class sqlalchemy.sql.functions.dense_rank(*args, **kwargs)

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.

Members

identifier, name, type

attribute sqlalchemy.sql.functions.dense_rank.identifier = 'dense_rank'
attribute sqlalchemy.sql.functions.dense_rank.name = 'dense_rank'
attribute sqlalchemy.sql.functions.dense_rank.type = Integer()
class sqlalchemy.sql.functions.grouping_sets(*args, **kwargs)

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.

Members

identifier, name

attribute sqlalchemy.sql.functions.grouping_sets.identifier = 'grouping_sets'
attribute sqlalchemy.sql.functions.grouping_sets.name = 'grouping_sets'
class sqlalchemy.sql.functions.localtime(**kwargs)

Members

identifier, name, type

attribute sqlalchemy.sql.functions.localtime.identifier = 'localtime'
attribute sqlalchemy.sql.functions.localtime.name = 'localtime'
attribute sqlalchemy.sql.functions.localtime.type

alias of DateTime

class sqlalchemy.sql.functions.localtimestamp(**kwargs)

Members

identifier, name, type

attribute sqlalchemy.sql.functions.localtimestamp.identifier = 'localtimestamp'
attribute sqlalchemy.sql.functions.localtimestamp.name = 'localtimestamp'
attribute sqlalchemy.sql.functions.localtimestamp.type

alias of DateTime

class sqlalchemy.sql.functions.max(*args, **kwargs)

Members

identifier, name

attribute sqlalchemy.sql.functions.max.identifier = 'max'
attribute sqlalchemy.sql.functions.max.name = 'max'
class sqlalchemy.sql.functions.min(*args, **kwargs)

Members

identifier, name

attribute sqlalchemy.sql.functions.min.identifier = 'min'
attribute sqlalchemy.sql.functions.min.name = 'min'
class sqlalchemy.sql.functions.mode(*args, **kwargs)

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.

Members

identifier, name

attribute sqlalchemy.sql.functions.mode.identifier = 'mode'
attribute sqlalchemy.sql.functions.mode.name = 'mode'
class sqlalchemy.sql.functions.next_value(seq, **kw)

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.

Members

identifier, name, type

attribute sqlalchemy.sql.functions.next_value.identifier = 'next_value'
attribute sqlalchemy.sql.functions.next_value.name = 'next_value'
attribute sqlalchemy.sql.functions.next_value.type = Integer()
class sqlalchemy.sql.functions.now(*args, **kwargs)

Members

identifier, name, type

attribute sqlalchemy.sql.functions.now.identifier = 'now'
attribute sqlalchemy.sql.functions.now.name = 'now'
attribute sqlalchemy.sql.functions.now.type

alias of DateTime

class sqlalchemy.sql.functions.percent_rank(*args, **kwargs)

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.

Members

identifier, name, type

attribute sqlalchemy.sql.functions.percent_rank.identifier = 'percent_rank'
attribute sqlalchemy.sql.functions.percent_rank.name = 'percent_rank'
attribute sqlalchemy.sql.functions.percent_rank.type = Numeric()
class sqlalchemy.sql.functions.percentile_cont(*args, **kwargs)

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 ARRAY of the sort expression’s type.

New in version 1.1.

attribute sqlalchemy.sql.functions.percentile_cont.array_for_multi_clause = True
attribute sqlalchemy.sql.functions.percentile_cont.identifier = 'percentile_cont'
attribute sqlalchemy.sql.functions.percentile_cont.name = 'percentile_cont'
class sqlalchemy.sql.functions.percentile_disc(*args, **kwargs)

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 ARRAY of the sort expression’s type.

New in version 1.1.

attribute sqlalchemy.sql.functions.percentile_disc.array_for_multi_clause = True
attribute sqlalchemy.sql.functions.percentile_disc.identifier = 'percentile_disc'
attribute sqlalchemy.sql.functions.percentile_disc.name = 'percentile_disc'
class sqlalchemy.sql.functions.random(*args, **kwargs)

Members

identifier, name

attribute sqlalchemy.sql.functions.random.identifier = 'random'
attribute sqlalchemy.sql.functions.random.name = 'random'
class sqlalchemy.sql.functions.rank(*args, **kwargs)

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.

Members

identifier, name, type

attribute sqlalchemy.sql.functions.rank.identifier = 'rank'
attribute sqlalchemy.sql.functions.rank.name = 'rank'
attribute sqlalchemy.sql.functions.rank.type = Integer()
function 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).

class sqlalchemy.sql.functions.rollup(*args, **kwargs)

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.

Members

identifier, name

attribute sqlalchemy.sql.functions.rollup.identifier = 'rollup'
attribute sqlalchemy.sql.functions.rollup.name = 'rollup'
class sqlalchemy.sql.functions.session_user(**kwargs)

Members

identifier, name, type

attribute sqlalchemy.sql.functions.session_user.identifier = 'session_user'
attribute sqlalchemy.sql.functions.session_user.name = 'session_user'
attribute sqlalchemy.sql.functions.session_user.type

alias of String

class sqlalchemy.sql.functions.sum(*args, **kwargs)

Members

identifier, name

attribute sqlalchemy.sql.functions.sum.identifier = 'sum'
attribute sqlalchemy.sql.functions.sum.name = 'sum'
class sqlalchemy.sql.functions.sysdate(**kwargs)

Members

identifier, name, type

attribute sqlalchemy.sql.functions.sysdate.identifier = 'sysdate'
attribute sqlalchemy.sql.functions.sysdate.name = 'sysdate'
attribute sqlalchemy.sql.functions.sysdate.type

alias of DateTime

class sqlalchemy.sql.functions.user(**kwargs)

Members

identifier, name, type

attribute sqlalchemy.sql.functions.user.identifier = 'user'
attribute sqlalchemy.sql.functions.user.name = 'user'
attribute sqlalchemy.sql.functions.user.type

alias of String