The expression API consists of a series of classes each of which represents a specific lexical element within a SQL string. Composed together into a larger structure, they form a statement construct that may be compiled into a string representation that can be passed to a database. The classes are organized into a hierarchy that begins at the basemost ClauseElement class. Key subclasses include ColumnElement, which represents the role of any column-based expression in a SQL statement, such as in the columns clause, WHERE clause, and ORDER BY clause, and FromClause, which represents the role of a token that is placed in the FROM clause of a SELECT statement.
sqlalchemy.sql.expression.
all_
(expr)¶Produce an ALL expression.
This may apply to an array type for some dialects (e.g. postgresql), or to a subquery for others (e.g. mysql). e.g.:
# postgresql '5 = ALL (somearray)'
expr = 5 == all_(mytable.c.somearray)
# mysql '5 = ALL (SELECT value FROM table)'
expr = 5 == all_(select([table.c.value]))
New in version 1.1.
See also
sqlalchemy.sql.expression.
and_
(*clauses)¶Produce a conjunction of expressions joined by AND
.
E.g.:
from sqlalchemy import and_
stmt = select([users_table]).where(
and_(
users_table.c.name == 'wendy',
users_table.c.enrolled == True
)
)
The and_()
conjunction is also available using the
Python &
operator (though note that compound expressions
need to be parenthesized in order to function with Python
operator precedence behavior):
stmt = select([users_table]).where(
(users_table.c.name == 'wendy') &
(users_table.c.enrolled == True)
)
The and_()
operation is also implicit in some cases;
the Select.where()
method for example can be invoked multiple
times against a statement, which will have the effect of each
clause being combined using and_()
:
stmt = select([users_table]). where(users_table.c.name == 'wendy'). where(users_table.c.enrolled == True)
See also
sqlalchemy.sql.expression.
any_
(expr)¶Produce an ANY expression.
This may apply to an array type for some dialects (e.g. postgresql), or to a subquery for others (e.g. mysql). e.g.:
# postgresql '5 = ANY (somearray)'
expr = 5 == any_(mytable.c.somearray)
# mysql '5 = ANY (SELECT value FROM table)'
expr = 5 == any_(select([table.c.value]))
New in version 1.1.
See also
sqlalchemy.sql.expression.
asc
(column)¶Produce an ascending ORDER BY
clause element.
e.g.:
from sqlalchemy import asc
stmt = select([users_table]).order_by(asc(users_table.c.name))
will produce SQL as:
SELECT id, name FROM user ORDER BY name ASC
The asc()
function is a standalone version of the
ColumnElement.asc()
method available on all SQL expressions,
e.g.:
stmt = select([users_table]).order_by(users_table.c.name.asc())
Parameters: | column¶ – A ColumnElement (e.g. scalar SQL expression)
with which to apply the asc() operation. |
---|
sqlalchemy.sql.expression.
between
(expr, lower_bound, upper_bound, symmetric=False)¶Produce a BETWEEN
predicate clause.
E.g.:
from sqlalchemy import between
stmt = select([users_table]).where(between(users_table.c.id, 5, 7))
Would produce SQL resembling:
SELECT id, name FROM user WHERE id BETWEEN :id_1 AND :id_2
The between()
function is a standalone version of the
ColumnElement.between()
method available on all
SQL expressions, as in:
stmt = select([users_table]).where(users_table.c.id.between(5, 7))
All arguments passed to between()
, including the left side
column expression, are coerced from Python scalar values if a
the value is not a ColumnElement
subclass. For example,
three fixed values can be compared as in:
print(between(5, 3, 7))
Which would produce:
:param_1 BETWEEN :param_2 AND :param_3
Parameters: |
|
---|
See also
sqlalchemy.sql.expression.
bindparam
(key, value=symbol('NO_ARG'), type_=None, unique=False, required=symbol('NO_ARG'), quote=None, callable_=None, expanding=False, isoutparam=False, _compared_to_operator=None, _compared_to_type=None)¶Produce a “bound expression”.
The return value is an instance of BindParameter
; this
is a ColumnElement
subclass which represents a so-called
“placeholder” value in a SQL expression, the value of which is
supplied at the point at which the statement in executed against a
database connection.
In SQLAlchemy, the bindparam()
construct has
the ability to carry along the actual value that will be ultimately
used at expression time. In this way, it serves not just as
a “placeholder” for eventual population, but also as a means of
representing so-called “unsafe” values which should not be rendered
directly in a SQL statement, but rather should be passed along
to the DBAPI as values which need to be correctly escaped
and potentially handled for type-safety.
When using bindparam()
explicitly, the use case is typically
one of traditional deferment of parameters; the bindparam()
construct accepts a name which can then be referred to at execution
time:
from sqlalchemy import bindparam
stmt = select([users_table]).\
where(users_table.c.name == bindparam('username'))
The above statement, when rendered, will produce SQL similar to:
SELECT id, name FROM user WHERE name = :username
In order to populate the value of :username
above, the value
would typically be applied at execution time to a method
like Connection.execute()
:
result = connection.execute(stmt, username='wendy')
Explicit use of bindparam()
is also common when producing
UPDATE or DELETE statements that are to be invoked multiple times,
where the WHERE criterion of the statement is to change on each
invocation, such as:
stmt = (users_table.update().
where(user_table.c.name == bindparam('username')).
values(fullname=bindparam('fullname'))
)
connection.execute(
stmt, [{"username": "wendy", "fullname": "Wendy Smith"},
{"username": "jack", "fullname": "Jack Jones"},
]
)
SQLAlchemy’s Core expression system makes wide use of
bindparam()
in an implicit sense. It is typical that Python
literal values passed to virtually all SQL expression functions are
coerced into fixed bindparam()
constructs. For example, given
a comparison operation such as:
expr = users_table.c.name == 'Wendy'
The above expression will produce a BinaryExpression
construct, where the left side is the Column
object
representing the name
column, and the right side is a
BindParameter
representing the literal value:
print(repr(expr.right))
BindParameter('%(4327771088 name)s', 'Wendy', type_=String())
The expression above will render SQL such as:
user.name = :name_1
Where the :name_1
parameter name is an anonymous name. The
actual string Wendy
is not in the rendered string, but is carried
along where it is later used within statement execution. If we
invoke a statement like the following:
stmt = select([users_table]).where(users_table.c.name == 'Wendy')
result = connection.execute(stmt)
We would see SQL logging output as:
SELECT "user".id, "user".name
FROM "user"
WHERE "user".name = %(name_1)s
{'name_1': 'Wendy'}
Above, we see that Wendy
is passed as a parameter to the database,
while the placeholder :name_1
is rendered in the appropriate form
for the target database, in this case the PostgreSQL database.
Similarly, bindparam()
is invoked automatically
when working with CRUD statements as far as the “VALUES”
portion is concerned. The insert()
construct produces an
INSERT
expression which will, at statement execution time,
generate bound placeholders based on the arguments passed, as in:
stmt = users_table.insert()
result = connection.execute(stmt, name='Wendy')
The above will produce SQL output as:
INSERT INTO "user" (name) VALUES (%(name)s)
{'name': 'Wendy'}
The Insert
construct, at compilation/execution time,
rendered a single bindparam()
mirroring the column
name name
as a result of the single name
parameter
we passed to the Connection.execute()
method.
Parameters: |
|
---|
sqlalchemy.sql.expression.
case
(whens, value=None, else_=None)¶Produce a CASE
expression.
The CASE
construct in SQL is a conditional object that
acts somewhat analogously to an “if/then” construct in other
languages. It returns an instance of Case
.
case()
in its usual form is passed a list of “when”
constructs, that is, a list of conditions and results as tuples:
from sqlalchemy import case
stmt = select([users_table]).\
where(
case(
[
(users_table.c.name == 'wendy', 'W'),
(users_table.c.name == 'jack', 'J')
],
else_='E'
)
)
The above statement will produce SQL resembling:
SELECT id, name FROM user
WHERE CASE
WHEN (name = :name_1) THEN :param_1
WHEN (name = :name_2) THEN :param_2
ELSE :param_3
END
When simple equality expressions of several values against a single
parent column are needed, case()
also has a “shorthand” format
used via the
case.value
parameter, which is passed a column
expression to be compared. In this form, the case.whens
parameter is passed as a dictionary containing expressions to be
compared against keyed to result expressions. The statement below is
equivalent to the preceding statement:
stmt = select([users_table]).\
where(
case(
{"wendy": "W", "jack": "J"},
value=users_table.c.name,
else_='E'
)
)
The values which are accepted as result values in
case.whens
as well as with case.else_
are
coerced from Python literals into bindparam()
constructs.
SQL expressions, e.g. ColumnElement
constructs, are accepted
as well. To coerce a literal string expression into a constant
expression rendered inline, use the literal_column()
construct,
as in:
from sqlalchemy import case, literal_column
case(
[
(
orderline.c.qty > 100,
literal_column("'greaterthan100'")
),
(
orderline.c.qty > 10,
literal_column("'greaterthan10'")
)
],
else_=literal_column("'lessthan10'")
)
The above will render the given constants without using bound parameters for the result values (but still for the comparison values), as in:
CASE
WHEN (orderline.qty > :qty_1) THEN 'greaterthan100'
WHEN (orderline.qty > :qty_2) THEN 'greaterthan10'
ELSE 'lessthan10'
END
Parameters: |
|
---|
sqlalchemy.sql.expression.
cast
(expression, type_)¶Produce a CAST
expression.
cast()
returns an instance of Cast
.
E.g.:
from sqlalchemy import cast, Numeric
stmt = select([
cast(product_table.c.unit_price, Numeric(10, 4))
])
The above statement will produce SQL resembling:
SELECT CAST(unit_price AS NUMERIC(10, 4)) FROM product
The cast()
function performs two distinct functions when
used. The first is that it renders the CAST
expression within
the resulting SQL string. The second is that it associates the given
type (e.g. TypeEngine
class or instance) with the column
expression on the Python side, which means the expression will take
on the expression operator behavior associated with that type,
as well as the bound-value handling and result-row-handling behavior
of the type.
Changed in version 0.9.0: cast()
now applies the given type
to the expression such that it takes effect on the bound-value,
e.g. the Python-to-database direction, in addition to the
result handling, e.g. database-to-Python, direction.
An alternative to cast()
is the type_coerce()
function.
This function performs the second task of associating an expression
with a specific type, but does not render the CAST
expression
in SQL.
Parameters: |
|
---|
See also
type_coerce()
- an alternative to CAST that coerces the type
on the Python side only, which is often sufficient to generate the
correct SQL and data coercion.
sqlalchemy.sql.expression.
column
(text, type_=None, is_literal=False, _selectable=None)¶Produce a ColumnClause
object.
The ColumnClause
is a lightweight analogue to the
Column
class. The column()
function can
be invoked with just a name alone, as in:
from sqlalchemy import column
id, name = column("id"), column("name")
stmt = select([id, name]).select_from("user")
The above statement would produce SQL like:
SELECT id, name FROM user
Once constructed, column()
may be used like any other SQL
expression element such as within select()
constructs:
from sqlalchemy.sql import column
id, name = column("id"), column("name")
stmt = select([id, name]).select_from("user")
The text handled by column()
is assumed to be handled
like the name of a database column; if the string contains mixed case,
special characters, or matches a known reserved word on the target
backend, the column expression will render using the quoting
behavior determined by the backend. To produce a textual SQL
expression that is rendered exactly without any quoting,
use literal_column()
instead, or pass True
as the
value of column.is_literal
. Additionally, full SQL
statements are best handled using the text()
construct.
column()
can be used in a table-like
fashion by combining it with the table()
function
(which is the lightweight analogue to Table
) to produce
a working table construct with minimal boilerplate:
from sqlalchemy import table, column, select
user = table("user",
column("id"),
column("name"),
column("description"),
)
stmt = select([user.c.description]).where(user.c.name == 'wendy')
A column()
/ table()
construct like that illustrated
above can be created in an
ad-hoc fashion and is not associated with any
schema.MetaData
, DDL, or events, unlike its
Table
counterpart.
Changed in version 1.0.0: expression.column()
can now
be imported from the plain sqlalchemy
namespace like any
other SQL element.
Parameters: |
|
---|
sqlalchemy.sql.expression.
collate
(expression, collation)¶Return the clause expression COLLATE collation
.
e.g.:
collate(mycolumn, 'utf8_bin')
produces:
mycolumn COLLATE utf8_bin
The collation expression is also quoted if it is a case sensitive identifier, e.g. contains uppercase characters.
Changed in version 1.2: quoting is automatically applied to COLLATE expressions if they are case sensitive.
sqlalchemy.sql.expression.
desc
(column)¶Produce a descending ORDER BY
clause element.
e.g.:
from sqlalchemy import desc
stmt = select([users_table]).order_by(desc(users_table.c.name))
will produce SQL as:
SELECT id, name FROM user ORDER BY name DESC
The desc()
function is a standalone version of the
ColumnElement.desc()
method available on all SQL expressions,
e.g.:
stmt = select([users_table]).order_by(users_table.c.name.desc())
Parameters: | column¶ – A ColumnElement (e.g. scalar SQL expression)
with which to apply the desc() operation. |
---|
sqlalchemy.sql.expression.
distinct
(expr)¶Produce an column-expression-level unary DISTINCT
clause.
This applies the DISTINCT
keyword to an individual column
expression, and is typically contained within an aggregate function,
as in:
from sqlalchemy import distinct, func
stmt = select([func.count(distinct(users_table.c.name))])
The above would produce an expression resembling:
SELECT COUNT(DISTINCT name) FROM user
The distinct()
function is also available as a column-level
method, e.g. ColumnElement.distinct()
, as in:
stmt = select([func.count(users_table.c.name.distinct())])
The distinct()
operator is different from the
Select.distinct()
method of Select
,
which produces a SELECT
statement
with DISTINCT
applied to the result set as a whole,
e.g. a SELECT DISTINCT
expression. See that method for further
information.
sqlalchemy.sql.expression.
extract
(field, expr, **kwargs)¶Return a Extract
construct.
This is typically available as extract()
as well as func.extract
from the
func
namespace.
sqlalchemy.sql.expression.
false
()¶Return a False_
construct.
E.g.:
>>> from sqlalchemy import false
>>> print select([t.c.x]).where(false())
SELECT x FROM t WHERE false
A backend which does not support true/false constants will render as an expression against 1 or 0:
>>> print select([t.c.x]).where(false())
SELECT x FROM t WHERE 0 = 1
The true()
and false()
constants also feature
“short circuit” operation within an and_()
or or_()
conjunction:
>>> print select([t.c.x]).where(or_(t.c.x > 5, true()))
SELECT x FROM t WHERE true
>>> print select([t.c.x]).where(and_(t.c.x > 5, false()))
SELECT x FROM t WHERE false
Changed in version 0.9: true()
and false()
feature
better integrated behavior within conjunctions and on dialects
that don’t support true/false constants.
See also
sqlalchemy.sql.expression.
func
= <sqlalchemy.sql.functions._FunctionGenerator object>¶Generate SQL function expressions.
func
is a special object instance which generates SQL
functions based on name-based attributes, e.g.:
>>> print(func.count(1))
count(:param_1)
The returned object is an instance of Function
, and is a
column-oriented SQL element like any other, and is used in that way:
>>> print(select([func.count(table.c.id)]))
SELECT count(sometable.id) FROM sometable
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:
>>> print(func.current_timestamp())
CURRENT_TIMESTAMP
To call functions which are present in dot-separated packages, specify them in the same manner:
>>> 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
treated as a string in expressions, specify
Unicode
as the type:
>>> print(func.my_string(u'hi', type_=Unicode) + ' ' +
... 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 usually an instance of
Function
.
This object meets the “column” interface, including comparison and labeling
functions. The object can also be passed the execute()
method of a Connection
or Engine
, where it will be
wrapped inside of a SELECT statement first:
print(connection.execute(func.current_timestamp()).scalar())
In a few exception cases, the func
accessor
will redirect a name to a built-in expression such as cast()
or extract()
, as these names have well-known meaning
but are not exactly the same as “functions” from a SQLAlchemy
perspective.
Functions which are interpreted as “generic” functions know how to calculate their return type automatically. For a listing of known generic functions, see SQL and Generic Functions.
Note
The func
construct has only limited support for calling
standalone “stored procedures”, especially those with special
parameterization concerns.
See the section Calling Stored Procedures for details on how to use
the DBAPI-level callproc()
method for fully traditional stored
procedures.
sqlalchemy.sql.expression.
funcfilter
(func, *criterion)¶Produce a FunctionFilter
object against a function.
Used against aggregate and window functions, for database backends that support the “FILTER” clause.
E.g.:
from sqlalchemy import funcfilter
funcfilter(func.count(1), MyClass.name == 'some name')
Would produce “COUNT(1) FILTER (WHERE myclass.name = ‘some name’)”.
This function is also available from the func
construct itself via the FunctionElement.filter()
method.
New in version 1.0.0.
See also
sqlalchemy.sql.expression.
label
(name, element, type_=None)¶Return a Label
object for the
given ColumnElement
.
A label changes the name of an element in the columns clause of a
SELECT
statement, typically via the AS
SQL keyword.
This functionality is more conveniently available via the
ColumnElement.label()
method on ColumnElement
.
Parameters: |
|
---|
sqlalchemy.sql.expression.
literal
(value, type_=None)¶Return a literal clause, bound to a bind parameter.
Literal clauses are created automatically when non-
ClauseElement
objects (such as strings, ints, dates, etc.) are
used in a comparison operation with a ColumnElement
subclass,
such as a Column
object. Use this function
to force the generation of a literal clause, which will be created as a
BindParameter
with a bound value.
Parameters: |
|
---|
sqlalchemy.sql.expression.
literal_column
(text, type_=None)¶Produce a ColumnClause
object that has the
column.is_literal
flag set to True.
literal_column()
is similar to column()
, except that
it is more often used as a “standalone” column expression that renders
exactly as stated; while column()
stores a string name that
will be assumed to be part of a table and may be quoted as such,
literal_column()
can be that, or any other arbitrary column-oriented
expression.
Parameters: |
|
---|
sqlalchemy.sql.expression.
not_
(clause)¶Return a negation of the given clause, i.e. NOT(clause)
.
The ~
operator is also overloaded on all
ColumnElement
subclasses to produce the
same result.
sqlalchemy.sql.expression.
nullsfirst
(column)¶Produce the NULLS FIRST
modifier for an ORDER BY
expression.
nullsfirst()
is intended to modify the expression produced
by asc()
or desc()
, and indicates how NULL values
should be handled when they are encountered during ordering:
from sqlalchemy import desc, nullsfirst
stmt = select([users_table]). order_by(nullsfirst(desc(users_table.c.name)))
The SQL expression from the above would resemble:
SELECT id, name FROM user ORDER BY name DESC NULLS FIRST
Like asc()
and desc()
, nullsfirst()
is typically
invoked from the column expression itself using
ColumnElement.nullsfirst()
, rather than as its standalone
function version, as in:
stmt = (select([users_table]).
order_by(users_table.c.name.desc().nullsfirst())
)
sqlalchemy.sql.expression.
nullslast
(column)¶Produce the NULLS LAST
modifier for an ORDER BY
expression.
nullslast()
is intended to modify the expression produced
by asc()
or desc()
, and indicates how NULL values
should be handled when they are encountered during ordering:
from sqlalchemy import desc, nullslast
stmt = select([users_table]). order_by(nullslast(desc(users_table.c.name)))
The SQL expression from the above would resemble:
SELECT id, name FROM user ORDER BY name DESC NULLS LAST
Like asc()
and desc()
, nullslast()
is typically
invoked from the column expression itself using
ColumnElement.nullslast()
, rather than as its standalone
function version, as in:
stmt = select([users_table]). order_by(users_table.c.name.desc().nullslast())
sqlalchemy.sql.expression.
or_
(*clauses)¶Produce a conjunction of expressions joined by OR
.
E.g.:
from sqlalchemy import or_
stmt = select([users_table]).where(
or_(
users_table.c.name == 'wendy',
users_table.c.name == 'jack'
)
)
The or_()
conjunction is also available using the
Python |
operator (though note that compound expressions
need to be parenthesized in order to function with Python
operator precedence behavior):
stmt = select([users_table]).where(
(users_table.c.name == 'wendy') |
(users_table.c.name == 'jack')
)
See also
sqlalchemy.sql.expression.
outparam
(key, type_=None)¶Create an ‘OUT’ parameter for usage in functions (stored procedures), for databases which support them.
The outparam
can be used like a regular function parameter.
The “output” value will be available from the
ResultProxy
object via its out_parameters
attribute, which returns a dictionary containing the values.
sqlalchemy.sql.expression.
over
(element, partition_by=None, order_by=None, range_=None, rows=None)¶Produce an Over
object against a function.
Used against aggregate or so-called “window” functions, for database backends that support window functions.
over()
is usually called using
the FunctionElement.over()
method, e.g.:
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 expression.over.range_
and 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))
RANGE BETWEEN 1 FOLLOWING AND 3 FOLLOWING:
func.row_number().over(order_by='x', range_=(1, 3))
New in version 1.1: support for RANGE / ROWS within a window
Parameters: |
|
---|
This function is also available from the func
construct itself via the FunctionElement.over()
method.
sqlalchemy.sql.expression.
text
(text, bind=None, bindparams=None, typemap=None, autocommit=None)¶Construct a new TextClause
clause, representing
a textual SQL string directly.
E.g.:
from sqlalchemy import text
t = text("SELECT * FROM users")
result = connection.execute(t)
The advantages text()
provides over a plain string are
backend-neutral support for bind parameters, per-statement
execution options, as well as
bind parameter and result-column typing behavior, allowing
SQLAlchemy type constructs to play a role when executing
a statement that is specified literally. The construct can also
be provided with a .c
collection of column elements, allowing
it to be embedded in other SQL expression constructs as a subquery.
Bind parameters are specified by name, using the format :name
.
E.g.:
t = text("SELECT * FROM users WHERE id=:user_id")
result = connection.execute(t, user_id=12)
For SQL statements where a colon is required verbatim, as within an inline string, use a backslash to escape:
t = text("SELECT * FROM users WHERE name='\:username'")
The TextClause
construct includes methods which can
provide information about the bound parameters as well as the column
values which would be returned from the textual statement, assuming
it’s an executable SELECT type of statement. The
TextClause.bindparams()
method is used to provide bound
parameter detail, and TextClause.columns()
method allows
specification of return columns including names and types:
t = text("SELECT * FROM users WHERE id=:user_id").\
bindparams(user_id=7).\
columns(id=Integer, name=String)
for id, name in connection.execute(t):
print(id, name)
The text()
construct is used in cases when
a literal string SQL fragment is specified as part of a larger query,
such as for the WHERE clause of a SELECT statement:
s = select([users.c.id, users.c.name]).where(text("id=:user_id"))
result = connection.execute(s, user_id=12)
text()
is also used for the construction
of a full, standalone statement using plain text.
As such, SQLAlchemy refers
to it as an Executable
object, and it supports
the Executable.execution_options()
method. For example,
a text()
construct that should be subject to “autocommit”
can be set explicitly so using the
Connection.execution_options.autocommit
option:
t = text("EXEC my_procedural_thing()").\
execution_options(autocommit=True)
Note that SQLAlchemy’s usual “autocommit” behavior applies to
text()
constructs implicitly - that is, statements which begin
with a phrase such as INSERT
, UPDATE
, DELETE
,
or a variety of other phrases specific to certain backends, will
be eligible for autocommit if no transaction is in progress.
Parameters: |
|
---|
sqlalchemy.sql.expression.
true
()¶Return a constant True_
construct.
E.g.:
>>> from sqlalchemy import true
>>> print select([t.c.x]).where(true())
SELECT x FROM t WHERE true
A backend which does not support true/false constants will render as an expression against 1 or 0:
>>> print select([t.c.x]).where(true())
SELECT x FROM t WHERE 1 = 1
The true()
and false()
constants also feature
“short circuit” operation within an and_()
or or_()
conjunction:
>>> print select([t.c.x]).where(or_(t.c.x > 5, true()))
SELECT x FROM t WHERE true
>>> print select([t.c.x]).where(and_(t.c.x > 5, false()))
SELECT x FROM t WHERE false
Changed in version 0.9: true()
and false()
feature
better integrated behavior within conjunctions and on dialects
that don’t support true/false constants.
See also
sqlalchemy.sql.expression.
tuple_
(*clauses, **kw)¶Return a Tuple
.
Main usage is to produce a composite IN construct using
ColumnOperators.in_()
from sqlalchemy import tuple_
tuple_(table.c.col1, table.c.col2).in_(
[(1, 2), (5, 12), (10, 19)]
)
Changed in version 1.3.6: Added support for SQLite IN tuples.
Warning
The composite IN construct is not supported by all backends, and is
currently known to work on PostgreSQL, MySQL, and SQLite.
Unsupported backends will raise a subclass of
DBAPIError
when such an expression is
invoked.
sqlalchemy.sql.expression.
type_coerce
(expression, type_)¶Associate a SQL expression with a particular type, without rendering
CAST
.
E.g.:
from sqlalchemy import type_coerce
stmt = select([
type_coerce(log_table.date_string, StringDateTime())
])
The above construct will produce a TypeCoerce
object, which
renders SQL that labels the expression, but otherwise does not
modify its value on the SQL side:
SELECT date_string AS anon_1 FROM log
When result rows are fetched, the StringDateTime
type
will be applied to result rows on behalf of the date_string
column.
The rationale for the “anon_1” label is so that the type-coerced
column remains separate in the list of result columns vs. other
type-coerced or direct values of the target column. In order to
provide a named label for the expression, use
ColumnElement.label()
:
stmt = select([
type_coerce(
log_table.date_string, StringDateTime()).label('date')
])
A type that features bound-value handling will also have that behavior
take effect when literal values or bindparam()
constructs are
passed to type_coerce()
as targets.
For example, if a type implements the
TypeEngine.bind_expression()
method or TypeEngine.bind_processor()
method or equivalent,
these functions will take effect at statement compilation/execution
time when a literal value is passed, as in:
# bound-value handling of MyStringType will be applied to the
# literal value "some string"
stmt = select([type_coerce("some string", MyStringType)])
type_coerce()
is similar to the cast()
function,
except that it does not render the CAST
expression in the resulting
statement.
Parameters: |
|
---|
sqlalchemy.sql.expression.
within_group
(element, *order_by)¶Produce a WithinGroup
object against a function.
Used against so-called “ordered set aggregate” and “hypothetical
set aggregate” functions, including percentile_cont
,
rank
, dense_rank
, etc.
within_group()
is usually called using
the FunctionElement.within_group()
method, e.g.:
from sqlalchemy import within_group
stmt = select([
department.c.id,
func.percentile_cont(0.5).within_group(
department.c.salary.desc()
)
])
The above statement would produce SQL similar to
SELECT department.id, percentile_cont(0.5)
WITHIN GROUP (ORDER BY department.salary DESC)
.
Parameters: |
|
---|
New in version 1.1.
sqlalchemy.sql.expression.
BinaryExpression
(left, right, operator, type_=None, negate=None, modifiers=None)¶Bases: sqlalchemy.sql.expression.ColumnElement
Represent an expression that is LEFT <operator> RIGHT
.
A BinaryExpression
is generated automatically
whenever two column expressions are used in a Python binary expression:
>>> from sqlalchemy.sql import column
>>> column('a') + column('b')
<sqlalchemy.sql.expression.BinaryExpression object at 0x101029dd0>
>>> print column('a') + column('b')
a + b
compare
(other, **kw)¶Compare this BinaryExpression
against the
given BinaryExpression
.
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).
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.
sqlalchemy.sql.expression.
BindParameter
(key, value=symbol('NO_ARG'), type_=None, unique=False, required=symbol('NO_ARG'), quote=None, callable_=None, expanding=False, isoutparam=False, _compared_to_operator=None, _compared_to_type=None)¶Bases: sqlalchemy.sql.expression.ColumnElement
Represent a “bound expression”.
BindParameter
is invoked explicitly using the
bindparam()
function, as in:
from sqlalchemy import bindparam
stmt = select([users_table]).\
where(users_table.c.name == bindparam('username'))
Detailed discussion of how BindParameter
is used is
at bindparam()
.
See also
__init__
(key, value=symbol('NO_ARG'), type_=None, unique=False, required=symbol('NO_ARG'), quote=None, callable_=None, expanding=False, isoutparam=False, _compared_to_operator=None, _compared_to_type=None)¶Construct a new BindParameter
object.
This constructor is mirrored as a public API function; see bindparam()
for a full usage and argument description.
compare
(other, **kw)¶Compare this BindParameter
to the given
clause.
effective_value
¶Return the value of this bound parameter,
taking into account if the callable
parameter
was set.
The callable
value will be evaluated
and returned if present, else value
.
sqlalchemy.sql.expression.
Case
(whens, value=None, else_=None)¶Bases: sqlalchemy.sql.expression.ColumnElement
Represent a CASE
expression.
Case
is produced using the case()
factory function,
as in:
from sqlalchemy import case
stmt = select([users_table]). where(
case(
[
(users_table.c.name == 'wendy', 'W'),
(users_table.c.name == 'jack', 'J')
],
else_='E'
)
)
Details on Case
usage is at case()
.
See also
__init__
(whens, value=None, else_=None)¶Construct a new Case
object.
This constructor is mirrored as a public API function; see case()
for a full usage and argument description.
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).
sqlalchemy.sql.expression.
Cast
(expression, type_)¶Bases: sqlalchemy.sql.expression.ColumnElement
Represent a CAST
expression.
Cast
is produced using the cast()
factory function,
as in:
from sqlalchemy import cast, Numeric
stmt = select([
cast(product_table.c.unit_price, Numeric(10, 4))
])
Details on Cast
usage is at cast()
.
See also
type_coerce()
- an alternative to CAST that coerces the type
on the Python side only, which is often sufficient to generate the
correct SQL and data coercion.
__init__
(expression, type_)¶Construct a new Cast
object.
This constructor is mirrored as a public API function; see cast()
for a full usage and argument description.
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).
sqlalchemy.sql.expression.
ClauseElement
¶Bases: sqlalchemy.sql.visitors.Visitable
Base class for elements of a programmatically constructed SQL expression.
compare
(other, **kw)¶Compare this ClauseElement to the given ClauseElement.
Subclasses should override the default behavior, which is a straight identity comparison.
**kw are arguments consumed by subclass compare() methods and
may be used to modify the criteria for comparison.
(see ColumnElement
)
compile
(default, bind=None, dialect=None, **kw)¶Compile this SQL expression.
The return value is a Compiled
object.
Calling str()
or unicode()
on the returned value will yield a
string representation of the result. The
Compiled
object also can return a
dictionary of bind parameter names and values
using the params
accessor.
Parameters: |
|
---|
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).
params
(*optionaldict, **kwargs)¶Return a copy with bindparam()
elements replaced.
Returns a copy of this ClauseElement with bindparam()
elements replaced with values taken from the given dictionary:
>>> clause = column('x') + bindparam('foo')
>>> print clause.compile().params
{'foo':None}
>>> print clause.params({'foo':7}).compile().params
{'foo':7}
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.
unique_params
(*optionaldict, **kwargs)¶Return a copy with bindparam()
elements replaced.
Same functionality as params()
, except adds unique=True
to affected bind parameters so that multiple statements can be
used.
sqlalchemy.sql.expression.
ClauseList
(*clauses, **kwargs)¶Bases: sqlalchemy.sql.expression.ClauseElement
Describe a list of clauses, separated by an operator.
By default, is comma-separated, such as a column listing.
compare
(other, **kw)¶Compare this ClauseList
to the given ClauseList
,
including a comparison of all the clause items.
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).
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.
sqlalchemy.sql.expression.
ColumnClause
(text, type_=None, is_literal=False, _selectable=None)¶Bases: sqlalchemy.sql.expression.Immutable
, sqlalchemy.sql.expression.ColumnElement
Represents a column expression from any textual string.
The ColumnClause
, a lightweight analogue to the
Column
class, is typically invoked using the
column()
function, as in:
from sqlalchemy import column
id, name = column("id"), column("name")
stmt = select([id, name]).select_from("user")
The above statement would produce SQL like:
SELECT id, name FROM user
ColumnClause
is the immediate superclass of the schema-specific
Column
object. While the Column
class has all the
same capabilities as ColumnClause
, the ColumnClause
class is usable by itself in those cases where behavioral requirements
are limited to simple SQL expression generation. The object has none of
the associations with schema-level metadata or with execution-time
behavior that Column
does, so in that sense is a “lightweight”
version of Column
.
Full details on ColumnClause
usage is at column()
.
__init__
(text, type_=None, is_literal=False, _selectable=None)¶Construct a new ColumnClause
object.
This constructor is mirrored as a public API function; see column()
for a full usage and argument description.
sqlalchemy.sql.expression.
ColumnCollection
(*columns)¶Bases: sqlalchemy.util._collections.OrderedProperties
An ordered dictionary that stores a list of ColumnElement instances.
Overrides the __eq__()
method to produce SQL clauses between
sets of correlated columns.
add
(column)¶Add a column to this collection.
The key attribute of the column will be used as the hash key for this dictionary.
as_immutable
()¶Return an immutable proxy for this Properties
.
replace
(column)¶add the given column to this collection, removing unaliased versions of this column as well as existing columns with the same key.
e.g.:
t = Table('sometable', metadata, Column('col1', Integer)) t.columns.replace(Column('col1', Integer, key='columnone'))will remove the original ‘col1’ from the collection, and add the new column under the name ‘columnname’.
Used by schema.Column to override columns during table reflection.
sqlalchemy.sql.expression.
ColumnElement
¶Bases: sqlalchemy.sql.operators.ColumnOperators
, sqlalchemy.sql.expression.ClauseElement
Represent a column-oriented SQL expression suitable for usage in the “columns” clause, WHERE clause etc. of a statement.
While the most familiar kind of ColumnElement
is the
Column
object, ColumnElement
serves as the basis
for any unit that may be present in a SQL expression, including
the expressions themselves, SQL functions, bound parameters,
literal expressions, keywords such as NULL
, etc.
ColumnElement
is the ultimate base class for all such elements.
A wide variety of SQLAlchemy Core functions work at the SQL expression
level, and are intended to accept instances of ColumnElement
as
arguments. These functions will typically document that they accept a
“SQL expression” as an argument. What this means in terms of SQLAlchemy
usually refers to an input which is either already in the form of a
ColumnElement
object, or a value which can be coerced into
one. The coercion rules followed by most, but not all, SQLAlchemy Core
functions with regards to SQL expressions are as follows:
- a literal Python value, such as a string, integer or floating point value, boolean, datetime,
Decimal
object, or virtually any other Python object, will be coerced into a “literal bound value”. This generally means that abindparam()
will be produced featuring the given value embedded into the construct; the resultingBindParameter
object is an instance ofColumnElement
. The Python value will ultimately be sent to the DBAPI at execution time as a parameterized argument to theexecute()
orexecutemany()
methods, after SQLAlchemy type-specific converters (e.g. those provided by any associatedTypeEngine
objects) are applied to the value.- any special object value, typically ORM-level constructs, which feature a method called
__clause_element__()
. The Core expression system looks for this method when an object of otherwise unknown type is passed to a function that is looking to coerce the argument into aColumnElement
expression. The__clause_element__()
method, if present, should return aColumnElement
instance. The primary use of__clause_element__()
within SQLAlchemy is that of class-bound attributes on ORM-mapped classes; aUser
class which contains a mapped attribute named.name
will have a methodUser.name.__clause_element__()
which when invoked returns theColumn
calledname
associated with the mapped table.- The Python
None
value is typically interpreted asNULL
, which in SQLAlchemy Core produces an instance ofnull()
.
A ColumnElement
provides the ability to generate new
ColumnElement
objects using Python expressions. This means that Python operators
such as ==
, !=
and <
are overloaded to mimic SQL operations,
and allow the instantiation of further ColumnElement
instances
which are composed from other, more fundamental ColumnElement
objects. For example, two ColumnClause
objects can be added
together with the addition operator +
to produce
a BinaryExpression
.
Both ColumnClause
and BinaryExpression
are subclasses
of ColumnElement
:
>>> from sqlalchemy.sql import column
>>> column('a') + column('b')
<sqlalchemy.sql.expression.BinaryExpression object at 0x101029dd0>
>>> print column('a') + column('b')
a + b
__eq__
(other)¶__eq__()
method of ColumnOperators
Implement the ==
operator.
In a column context, produces the clause a = b
.
If the target is None
, produces a IS NULL
.
__init__
¶__init__
attribute of object
Initialize self. See help(type(self)) for accurate signature.
__le__
(other)¶__le__()
method of ColumnOperators
Implement the <=
operator.
In a column context, produces the clause a <= b
.
__lt__
(other)¶__lt__()
method of ColumnOperators
Implement the <
operator.
In a column context, produces the clause a < b
.
__ne__
(other)¶__ne__()
method of ColumnOperators
Implement the !=
operator.
In a column context, produces the clause a != b
.
If the target is None
, produces a IS NOT NULL
.
all_
()¶all_()
method of ColumnOperators
Produce a all_()
clause against the
parent object.
This operator is only appropriate against a scalar subquery object, or for some backends an column expression that is against the ARRAY type, e.g.:
# postgresql '5 = ALL (somearray)'
expr = 5 == mytable.c.somearray.all_()
# mysql '5 = ALL (SELECT value FROM table)'
expr = 5 == select([table.c.value]).as_scalar().all_()
New in version 1.1.
anon_label
¶provides a constant ‘anonymous label’ for this ColumnElement.
This is a label() expression which will be named at compile time. The same label() is returned each time anon_label is called so that expressions can reference anon_label multiple times, producing the same label name at compile time.
the compiler uses this function automatically at compile time for expressions that are known to be ‘unnamed’ like binary expressions and function calls.
any_
()¶any_()
method of ColumnOperators
Produce a any_()
clause against the
parent object.
This operator is only appropriate against a scalar subquery object, or for some backends an column expression that is against the ARRAY type, e.g.:
# postgresql '5 = ANY (somearray)'
expr = 5 == mytable.c.somearray.any_()
# mysql '5 = ANY (SELECT value FROM table)'
expr = 5 == select([table.c.value]).as_scalar().any_()
New in version 1.1.
asc
()¶asc()
method of ColumnOperators
Produce a asc()
clause against the
parent object.
base_columns
¶between
(cleft, cright, symmetric=False)¶between()
method of ColumnOperators
Produce a between()
clause against
the parent object, given the lower and upper range.
bind
= None¶bool_op
(opstring, precedence=0)¶Return a custom boolean operator.
This method is shorthand for calling
Operators.op()
and passing the
Operators.op.is_comparison
flag with True.
New in version 1.2.0b3.
See also
cast
(type_)¶Produce a type cast, i.e. CAST(<expression> AS <type>)
.
This is a shortcut to the cast()
function.
New in version 1.0.7.
collate
(collation)¶collate()
method of ColumnOperators
Produce a collate()
clause against
the parent object, given the collation string.
See also
comparator
¶compare
(other, use_proxies=False, equivalents=None, **kw)¶Compare this ColumnElement to another.
Special arguments understood:
Parameters: |
|
---|
compile
(default, bind=None, dialect=None, **kw)¶compile()
method of ClauseElement
Compile this SQL expression.
The return value is a Compiled
object.
Calling str()
or unicode()
on the returned value will yield a
string representation of the result. The
Compiled
object also can return a
dictionary of bind parameter names and values
using the params
accessor.
Parameters: |
|
---|
concat
(other)¶concat()
method of ColumnOperators
Implement the ‘concat’ operator.
In a column context, produces the clause a || b
,
or uses the concat()
operator on MySQL.
contains
(other, **kwargs)¶contains()
method of ColumnOperators
Implement the ‘contains’ operator.
Produces a LIKE expression that tests against a match for the middle of a string value:
column LIKE '%' || <other> || '%'
E.g.:
stmt = select([sometable]).\
where(sometable.c.column.contains("foobar"))
Since the operator uses LIKE
, wildcard characters
"%"
and "_"
that are present inside the <other> expression
will behave like wildcards as well. For literal string
values, the ColumnOperators.contains.autoescape
flag
may be set to True
to apply escaping to occurrences of these
characters within the string value so that they match as themselves
and not as wildcard characters. Alternatively, the
ColumnOperators.contains.escape
parameter will establish
a given character as an escape character which can be of use when
the target expression is not a literal string.
Parameters: |
|
---|
desc
()¶desc()
method of ColumnOperators
Produce a desc()
clause against the
parent object.
description
= None¶distinct
()¶distinct()
method of ColumnOperators
Produce a distinct()
clause against the
parent object.
endswith
(other, **kwargs)¶endswith()
method of ColumnOperators
Implement the ‘endswith’ operator.
Produces a LIKE expression that tests against a match for the end of a string value:
column LIKE '%' || <other>
E.g.:
stmt = select([sometable]).\
where(sometable.c.column.endswith("foobar"))
Since the operator uses LIKE
, wildcard characters
"%"
and "_"
that are present inside the <other> expression
will behave like wildcards as well. For literal string
values, the ColumnOperators.endswith.autoescape
flag
may be set to True
to apply escaping to occurrences of these
characters within the string value so that they match as themselves
and not as wildcard characters. Alternatively, the
ColumnOperators.endswith.escape
parameter will establish
a given character as an escape character which can be of use when
the target expression is not a literal string.
Parameters: |
|
---|
expression
¶Return a column expression.
Part of the inspection interface; returns self.
foreign_keys
= []¶get_children
(**kwargs)¶get_children()
method of ClauseElement
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).
ilike
(other, escape=None)¶ilike()
method of ColumnOperators
Implement the ilike
operator, e.g. case insensitive LIKE.
In a column context, produces an expression either of the form:
lower(a) LIKE lower(other)
Or on backends that support the ILIKE operator:
a ILIKE other
E.g.:
stmt = select([sometable]).\
where(sometable.c.column.ilike("%foobar%"))
Parameters: |
---|
See also
in_
(other)¶in_()
method of ColumnOperators
Implement the in
operator.
In a column context, produces the clause column IN <other>
.
The given parameter other
may be:
A list of literal values, e.g.:
stmt.where(column.in_([1, 2, 3]))
In this calling form, the list of items is converted to a set of bound parameters the same length as the list given:
WHERE COL IN (?, ?, ?)
A list of tuples may be provided if the comparison is against a
tuple_()
containing multiple expressions:
from sqlalchemy import tuple_
stmt.where(tuple_(col1, col2).in_([(1, 10), (2, 20), (3, 30)]))
An empty list, e.g.:
stmt.where(column.in_([]))
In this calling form, the expression renders a “false” expression, e.g.:
WHERE 1 != 1
This “false” expression has historically had different behaviors
in older SQLAlchemy versions, see
create_engine.empty_in_strategy
for behavioral options.
Changed in version 1.2: simplified the behavior of “empty in” expressions
A bound parameter, e.g. bindparam()
, may be used if it
includes the bindparam.expanding
flag:
stmt.where(column.in_(bindparam('value', expanding=True)))
In this calling form, the expression renders a special non-SQL placeholder expression that looks like:
WHERE COL IN ([EXPANDING_value])
This placeholder expression is intercepted at statement execution time to be converted into the variable number of bound parameter form illustrated earlier. If the statement were executed as:
connection.execute(stmt, {"value": [1, 2, 3]})
The database would be passed a bound parameter for each value:
WHERE COL IN (?, ?, ?)
New in version 1.2: added “expanding” bound parameters
If an empty list is passed, a special “empty list” expression, which is specific to the database in use, is rendered. On SQLite this would be:
WHERE COL IN (SELECT 1 FROM (SELECT 1) WHERE 1!=1)
New in version 1.3: “expanding” bound parameters now support empty lists
a select()
construct, which is usually a correlated
scalar select:
stmt.where(
column.in_(
select([othertable.c.y]).
where(table.c.x == othertable.c.x)
)
)
In this calling form, ColumnOperators.in_()
renders as given:
WHERE COL IN (SELECT othertable.y
FROM othertable WHERE othertable.x = table.x)
Parameters: | other¶ – a list of literals, a select() construct,
or a bindparam() construct that includes the
bindparam.expanding flag set to True. |
---|
is_
(other)¶is_()
method of ColumnOperators
Implement the IS
operator.
Normally, IS
is generated automatically when comparing to a
value of None
, which resolves to NULL
. However, explicit
usage of IS
may be desirable if comparing to boolean values
on certain platforms.
See also
is_clause_element
= True¶is_distinct_from
(other)¶is_distinct_from()
method of ColumnOperators
Implement the IS DISTINCT FROM
operator.
Renders “a IS DISTINCT FROM b” on most platforms; on some such as SQLite may render “a IS NOT b”.
New in version 1.1.
is_selectable
= False¶isnot
(other)¶isnot()
method of ColumnOperators
Implement the IS NOT
operator.
Normally, IS NOT
is generated automatically when comparing to a
value of None
, which resolves to NULL
. However, explicit
usage of IS NOT
may be desirable if comparing to boolean values
on certain platforms.
See also
isnot_distinct_from
(other)¶isnot_distinct_from()
method of ColumnOperators
Implement the IS NOT DISTINCT FROM
operator.
Renders “a IS NOT DISTINCT FROM b” on most platforms; on some such as SQLite may render “a IS b”.
New in version 1.1.
key
= None¶the ‘key’ that in some circumstances refers to this object in a Python namespace.
This typically refers to the “key” of the column as present in the
.c
collection of a selectable, e.g. sometable.c[“somekey”] would
return a Column with a .key of “somekey”.
label
(name)¶Produce a column label, i.e. <columnname> AS <name>
.
This is a shortcut to the label()
function.
if ‘name’ is None, an anonymous label name will be generated.
like
(other, escape=None)¶like()
method of ColumnOperators
Implement the like
operator.
In a column context, produces the expression:
a LIKE other
E.g.:
stmt = select([sometable]).\
where(sometable.c.column.like("%foobar%"))
Parameters: |
---|
See also
match
(other, **kwargs)¶match()
method of ColumnOperators
Implements a database-specific ‘match’ operator.
match()
attempts to resolve to
a MATCH-like function or operator provided by the backend.
Examples include:
x @@ to_tsquery(y)
MATCH (x) AGAINST (y IN BOOLEAN MODE)
CONTAINS(x, y)
notilike
(other, escape=None)¶notilike()
method of ColumnOperators
implement the NOT ILIKE
operator.
This is equivalent to using negation with
ColumnOperators.ilike()
, i.e. ~x.ilike(y)
.
See also
notin_
(other)¶notin_()
method of ColumnOperators
implement the NOT IN
operator.
This is equivalent to using negation with
ColumnOperators.in_()
, i.e. ~x.in_(y)
.
In the case that other
is an empty sequence, the compiler
produces an “empty not in” expression. This defaults to the
expression “1 = 1” to produce true in all cases. The
create_engine.empty_in_strategy
may be used to
alter this behavior.
Changed in version 1.2: The ColumnOperators.in_()
and
ColumnOperators.notin_()
operators
now produce a “static” expression for an empty IN sequence
by default.
See also
notlike
(other, escape=None)¶notlike()
method of ColumnOperators
implement the NOT LIKE
operator.
This is equivalent to using negation with
ColumnOperators.like()
, i.e. ~x.like(y)
.
See also
nullsfirst
()¶nullsfirst()
method of ColumnOperators
Produce a nullsfirst()
clause against the
parent object.
nullslast
()¶nullslast()
method of ColumnOperators
Produce a nullslast()
clause against the
parent object.
op
(opstring, precedence=0, is_comparison=False, return_type=None)¶produce a generic operator function.
e.g.:
somecolumn.op("*")(5)
produces:
somecolumn * 5
This function can also be used to make bitwise operators explicit. For example:
somecolumn.op('&')(0xff)
is a bitwise AND of the value in somecolumn
.
Parameters: |
|
---|
operate
(op, *other, **kwargs)¶Operate on an argument.
This is the lowest level of operation, raises
NotImplementedError
by default.
Overriding this on a subclass can allow common
behavior to be applied to all operations.
For example, overriding ColumnOperators
to apply func.lower()
to the left and right
side:
class MyComparator(ColumnOperators):
def operate(self, op, other):
return op(func.lower(self), func.lower(other))
Parameters: |
---|
params
(*optionaldict, **kwargs)¶params()
method of ClauseElement
Return a copy with bindparam()
elements replaced.
Returns a copy of this ClauseElement with bindparam()
elements replaced with values taken from the given dictionary:
>>> clause = column('x') + bindparam('foo')
>>> print clause.compile().params
{'foo':None}
>>> print clause.params({'foo':7}).compile().params
{'foo':7}
primary_key
= False¶proxy_set
¶reverse_operate
(op, other, **kwargs)¶Reverse operate on an argument.
Usage is the same as operate()
.
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.
shares_lineage
(othercolumn)¶Return True if the given ColumnElement
has a common ancestor to this ColumnElement
.
startswith
(other, **kwargs)¶startswith()
method of ColumnOperators
Implement the startswith
operator.
Produces a LIKE expression that tests against a match for the start of a string value:
column LIKE <other> || '%'
E.g.:
stmt = select([sometable]).\
where(sometable.c.column.startswith("foobar"))
Since the operator uses LIKE
, wildcard characters
"%"
and "_"
that are present inside the <other> expression
will behave like wildcards as well. For literal string
values, the ColumnOperators.startswith.autoescape
flag
may be set to True
to apply escaping to occurrences of these
characters within the string value so that they match as themselves
and not as wildcard characters. Alternatively, the
ColumnOperators.startswith.escape
parameter will establish
a given character as an escape character which can be of use when
the target expression is not a literal string.
Parameters: |
|
---|
supports_execution
= False¶timetuple
= None¶type
¶unique_params
(*optionaldict, **kwargs)¶unique_params()
method of ClauseElement
Return a copy with bindparam()
elements replaced.
Same functionality as params()
, except adds unique=True
to affected bind parameters so that multiple statements can be
used.
sqlalchemy.sql.operators.
ColumnOperators
¶Bases: sqlalchemy.sql.operators.Operators
Defines boolean, comparison, and other operators for
ColumnElement
expressions.
By default, all methods call down to
operate()
or reverse_operate()
,
passing in the appropriate operator function from the
Python builtin operator
module or
a SQLAlchemy-specific operator function from
sqlalchemy.expression.operators
. For example
the __eq__
function:
def __eq__(self, other):
return self.operate(operators.eq, other)
Where operators.eq
is essentially:
def eq(a, b):
return a == b
The core column expression unit ColumnElement
overrides Operators.operate()
and others
to return further ColumnElement
constructs,
so that the ==
operation above is replaced by a clause
construct.
__add__
(other)¶Implement the +
operator.
In a column context, produces the clause a + b
if the parent object has non-string affinity.
If the parent object has a string affinity,
produces the concatenation operator, a || b
-
see ColumnOperators.concat()
.
__and__
(other)¶Implement the &
operator.
When used with SQL expressions, results in an
AND operation, equivalent to
and_()
, that is:
a & b
is equivalent to:
from sqlalchemy import and_
and_(a, b)
Care should be taken when using &
regarding
operator precedence; the &
operator has the highest precedence.
The operands should be enclosed in parenthesis if they contain
further sub expressions:
(a == 2) & (b == 4)
__delattr__
¶__delattr__
attribute of object
Implement delattr(self, name).
__dir__
()¶__dir__()
method of object
Default dir() implementation.
__div__
(other)¶Implement the /
operator.
In a column context, produces the clause a / b
.
__eq__
(other)¶Implement the ==
operator.
In a column context, produces the clause a = b
.
If the target is None
, produces a IS NULL
.
__format__
()¶__format__()
method of object
Default object formatter.
__ge__
(other)¶Implement the >=
operator.
In a column context, produces the clause a >= b
.
__getattribute__
¶__getattribute__
attribute of object
Return getattr(self, name).
__getitem__
(index)¶Implement the [] operator.
This can be used by some database-specific types such as PostgreSQL ARRAY and HSTORE.
__gt__
(other)¶Implement the >
operator.
In a column context, produces the clause a > b
.
__hash__
¶Return hash(self).
__init__
¶__init__
attribute of object
Initialize self. See help(type(self)) for accurate signature.
__init_subclass__
()¶__init_subclass__()
method of object
This method is called when a class is subclassed.
The default implementation does nothing. It may be overridden to extend subclasses.
__invert__
()¶__invert__()
method of Operators
Implement the ~
operator.
When used with SQL expressions, results in a
NOT operation, equivalent to
not_()
, that is:
~a
is equivalent to:
from sqlalchemy import not_
not_(a)
__le__
(other)¶Implement the <=
operator.
In a column context, produces the clause a <= b
.
__lshift__
(other)¶implement the << operator.
Not used by SQLAlchemy core, this is provided for custom operator systems which want to use << as an extension point.
__lt__
(other)¶Implement the <
operator.
In a column context, produces the clause a < b
.
__mod__
(other)¶Implement the %
operator.
In a column context, produces the clause a % b
.
__mul__
(other)¶Implement the *
operator.
In a column context, produces the clause a * b
.
__ne__
(other)¶Implement the !=
operator.
In a column context, produces the clause a != b
.
If the target is None
, produces a IS NOT NULL
.
__neg__
()¶Implement the -
operator.
In a column context, produces the clause -a
.
__new__
()¶__new__()
method of object
Create and return a new object. See help(type) for accurate signature.
__or__
(other)¶Implement the |
operator.
When used with SQL expressions, results in an
OR operation, equivalent to
or_()
, that is:
a | b
is equivalent to:
from sqlalchemy import or_
or_(a, b)
Care should be taken when using |
regarding
operator precedence; the |
operator has the highest precedence.
The operands should be enclosed in parenthesis if they contain
further sub expressions:
(a == 2) | (b == 4)
__radd__
(other)¶Implement the +
operator in reverse.
__rdiv__
(other)¶Implement the /
operator in reverse.
__reduce__
()¶__reduce__()
method of object
Helper for pickle.
__reduce_ex__
()¶__reduce_ex__()
method of object
Helper for pickle.
__repr__
¶__repr__
attribute of object
Return repr(self).
__rmod__
(other)¶Implement the %
operator in reverse.
__rmul__
(other)¶Implement the *
operator in reverse.
__rshift__
(other)¶implement the >> operator.
Not used by SQLAlchemy core, this is provided for custom operator systems which want to use >> as an extension point.
__rsub__
(other)¶Implement the -
operator in reverse.
__rtruediv__
(other)¶Implement the //
operator in reverse.
__setattr__
¶__setattr__
attribute of object
Implement setattr(self, name, value).
__sizeof__
()¶__sizeof__()
method of object
Size of object in memory, in bytes.
__str__
¶__str__
attribute of object
Return str(self).
__sub__
(other)¶Implement the -
operator.
In a column context, produces the clause a - b
.
__subclasshook__
()¶__subclasshook__()
method of object
Abstract classes can override this to customize issubclass().
This is invoked early on by abc.ABCMeta.__subclasscheck__(). It should return True, False or NotImplemented. If it returns NotImplemented, the normal algorithm is used. Otherwise, it overrides the normal algorithm (and the outcome is cached).
__truediv__
(other)¶Implement the //
operator.
In a column context, produces the clause a / b
.
all_
()¶Produce a all_()
clause against the
parent object.
This operator is only appropriate against a scalar subquery object, or for some backends an column expression that is against the ARRAY type, e.g.:
# postgresql '5 = ALL (somearray)'
expr = 5 == mytable.c.somearray.all_()
# mysql '5 = ALL (SELECT value FROM table)'
expr = 5 == select([table.c.value]).as_scalar().all_()
New in version 1.1.
any_
()¶Produce a any_()
clause against the
parent object.
This operator is only appropriate against a scalar subquery object, or for some backends an column expression that is against the ARRAY type, e.g.:
# postgresql '5 = ANY (somearray)'
expr = 5 == mytable.c.somearray.any_()
# mysql '5 = ANY (SELECT value FROM table)'
expr = 5 == select([table.c.value]).as_scalar().any_()
New in version 1.1.
between
(cleft, cright, symmetric=False)¶Produce a between()
clause against
the parent object, given the lower and upper range.
bool_op
(opstring, precedence=0)¶Return a custom boolean operator.
This method is shorthand for calling
Operators.op()
and passing the
Operators.op.is_comparison
flag with True.
New in version 1.2.0b3.
See also
collate
(collation)¶Produce a collate()
clause against
the parent object, given the collation string.
See also
concat
(other)¶Implement the ‘concat’ operator.
In a column context, produces the clause a || b
,
or uses the concat()
operator on MySQL.
contains
(other, **kwargs)¶Implement the ‘contains’ operator.
Produces a LIKE expression that tests against a match for the middle of a string value:
column LIKE '%' || <other> || '%'
E.g.:
stmt = select([sometable]).\
where(sometable.c.column.contains("foobar"))
Since the operator uses LIKE
, wildcard characters
"%"
and "_"
that are present inside the <other> expression
will behave like wildcards as well. For literal string
values, the ColumnOperators.contains.autoescape
flag
may be set to True
to apply escaping to occurrences of these
characters within the string value so that they match as themselves
and not as wildcard characters. Alternatively, the
ColumnOperators.contains.escape
parameter will establish
a given character as an escape character which can be of use when
the target expression is not a literal string.
Parameters: |
|
---|
distinct
()¶Produce a distinct()
clause against the
parent object.
endswith
(other, **kwargs)¶Implement the ‘endswith’ operator.
Produces a LIKE expression that tests against a match for the end of a string value:
column LIKE '%' || <other>
E.g.:
stmt = select([sometable]).\
where(sometable.c.column.endswith("foobar"))
Since the operator uses LIKE
, wildcard characters
"%"
and "_"
that are present inside the <other> expression
will behave like wildcards as well. For literal string
values, the ColumnOperators.endswith.autoescape
flag
may be set to True
to apply escaping to occurrences of these
characters within the string value so that they match as themselves
and not as wildcard characters. Alternatively, the
ColumnOperators.endswith.escape
parameter will establish
a given character as an escape character which can be of use when
the target expression is not a literal string.
Parameters: |
|
---|
ilike
(other, escape=None)¶Implement the ilike
operator, e.g. case insensitive LIKE.
In a column context, produces an expression either of the form:
lower(a) LIKE lower(other)
Or on backends that support the ILIKE operator:
a ILIKE other
E.g.:
stmt = select([sometable]).\
where(sometable.c.column.ilike("%foobar%"))
Parameters: |
---|
See also
in_
(other)¶Implement the in
operator.
In a column context, produces the clause column IN <other>
.
The given parameter other
may be:
A list of literal values, e.g.:
stmt.where(column.in_([1, 2, 3]))
In this calling form, the list of items is converted to a set of bound parameters the same length as the list given:
WHERE COL IN (?, ?, ?)
A list of tuples may be provided if the comparison is against a
tuple_()
containing multiple expressions:
from sqlalchemy import tuple_
stmt.where(tuple_(col1, col2).in_([(1, 10), (2, 20), (3, 30)]))
An empty list, e.g.:
stmt.where(column.in_([]))
In this calling form, the expression renders a “false” expression, e.g.:
WHERE 1 != 1
This “false” expression has historically had different behaviors
in older SQLAlchemy versions, see
create_engine.empty_in_strategy
for behavioral options.
Changed in version 1.2: simplified the behavior of “empty in” expressions
A bound parameter, e.g. bindparam()
, may be used if it
includes the bindparam.expanding
flag:
stmt.where(column.in_(bindparam('value', expanding=True)))
In this calling form, the expression renders a special non-SQL placeholder expression that looks like:
WHERE COL IN ([EXPANDING_value])
This placeholder expression is intercepted at statement execution time to be converted into the variable number of bound parameter form illustrated earlier. If the statement were executed as:
connection.execute(stmt, {"value": [1, 2, 3]})
The database would be passed a bound parameter for each value:
WHERE COL IN (?, ?, ?)
New in version 1.2: added “expanding” bound parameters
If an empty list is passed, a special “empty list” expression, which is specific to the database in use, is rendered. On SQLite this would be:
WHERE COL IN (SELECT 1 FROM (SELECT 1) WHERE 1!=1)
New in version 1.3: “expanding” bound parameters now support empty lists
a select()
construct, which is usually a correlated
scalar select:
stmt.where(
column.in_(
select([othertable.c.y]).
where(table.c.x == othertable.c.x)
)
)
In this calling form, ColumnOperators.in_()
renders as given:
WHERE COL IN (SELECT othertable.y
FROM othertable WHERE othertable.x = table.x)
Parameters: | other¶ – a list of literals, a select() construct,
or a bindparam() construct that includes the
bindparam.expanding flag set to True. |
---|
is_
(other)¶Implement the IS
operator.
Normally, IS
is generated automatically when comparing to a
value of None
, which resolves to NULL
. However, explicit
usage of IS
may be desirable if comparing to boolean values
on certain platforms.
See also
is_distinct_from
(other)¶Implement the IS DISTINCT FROM
operator.
Renders “a IS DISTINCT FROM b” on most platforms; on some such as SQLite may render “a IS NOT b”.
New in version 1.1.
isnot
(other)¶Implement the IS NOT
operator.
Normally, IS NOT
is generated automatically when comparing to a
value of None
, which resolves to NULL
. However, explicit
usage of IS NOT
may be desirable if comparing to boolean values
on certain platforms.
See also
isnot_distinct_from
(other)¶Implement the IS NOT DISTINCT FROM
operator.
Renders “a IS NOT DISTINCT FROM b” on most platforms; on some such as SQLite may render “a IS b”.
New in version 1.1.
like
(other, escape=None)¶Implement the like
operator.
In a column context, produces the expression:
a LIKE other
E.g.:
stmt = select([sometable]).\
where(sometable.c.column.like("%foobar%"))
Parameters: |
---|
See also
match
(other, **kwargs)¶Implements a database-specific ‘match’ operator.
match()
attempts to resolve to
a MATCH-like function or operator provided by the backend.
Examples include:
x @@ to_tsquery(y)
MATCH (x) AGAINST (y IN BOOLEAN MODE)
CONTAINS(x, y)
notilike
(other, escape=None)¶implement the NOT ILIKE
operator.
This is equivalent to using negation with
ColumnOperators.ilike()
, i.e. ~x.ilike(y)
.
See also
notin_
(other)¶implement the NOT IN
operator.
This is equivalent to using negation with
ColumnOperators.in_()
, i.e. ~x.in_(y)
.
In the case that other
is an empty sequence, the compiler
produces an “empty not in” expression. This defaults to the
expression “1 = 1” to produce true in all cases. The
create_engine.empty_in_strategy
may be used to
alter this behavior.
Changed in version 1.2: The ColumnOperators.in_()
and
ColumnOperators.notin_()
operators
now produce a “static” expression for an empty IN sequence
by default.
See also
notlike
(other, escape=None)¶implement the NOT LIKE
operator.
This is equivalent to using negation with
ColumnOperators.like()
, i.e. ~x.like(y)
.
See also
nullsfirst
()¶Produce a nullsfirst()
clause against the
parent object.
nullslast
()¶Produce a nullslast()
clause against the
parent object.
op
(opstring, precedence=0, is_comparison=False, return_type=None)¶produce a generic operator function.
e.g.:
somecolumn.op("*")(5)
produces:
somecolumn * 5
This function can also be used to make bitwise operators explicit. For example:
somecolumn.op('&')(0xff)
is a bitwise AND of the value in somecolumn
.
Parameters: |
|
---|
operate
(op, *other, **kwargs)¶Operate on an argument.
This is the lowest level of operation, raises
NotImplementedError
by default.
Overriding this on a subclass can allow common
behavior to be applied to all operations.
For example, overriding ColumnOperators
to apply func.lower()
to the left and right
side:
class MyComparator(ColumnOperators):
def operate(self, op, other):
return op(func.lower(self), func.lower(other))
Parameters: |
|
---|
reverse_operate
(op, other, **kwargs)¶reverse_operate()
method of Operators
Reverse operate on an argument.
Usage is the same as operate()
.
startswith
(other, **kwargs)¶Implement the startswith
operator.
Produces a LIKE expression that tests against a match for the start of a string value:
column LIKE <other> || '%'
E.g.:
stmt = select([sometable]).\
where(sometable.c.column.startswith("foobar"))
Since the operator uses LIKE
, wildcard characters
"%"
and "_"
that are present inside the <other> expression
will behave like wildcards as well. For literal string
values, the ColumnOperators.startswith.autoescape
flag
may be set to True
to apply escaping to occurrences of these
characters within the string value so that they match as themselves
and not as wildcard characters. Alternatively, the
ColumnOperators.startswith.escape
parameter will establish
a given character as an escape character which can be of use when
the target expression is not a literal string.
Parameters: |
|
---|
timetuple
= None¶Hack, allows datetime objects to be compared on the LHS.
sqlalchemy.sql.base.
DialectKWArgs
¶Establish the ability for a class to have dialect-specific arguments with defaults and constructor validation.
The DialectKWArgs
interacts with the
DefaultDialect.construct_arguments
present on a dialect.
See also
argument_for
(dialect_name, argument_name, default)¶Add a new kind of dialect-specific keyword argument for this class.
E.g.:
Index.argument_for("mydialect", "length", None)
some_index = Index('a', 'b', mydialect_length=5)
The DialectKWArgs.argument_for()
method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments
dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a data member of the dialect class. The use case for ad-hoc addition of argument names is typically for end-user code that is also using a custom compilation scheme which consumes the additional arguments.
Parameters: |
|
---|
New in version 0.9.4.
dialect_kwargs
¶A collection of keyword arguments specified as dialect-specific options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options
collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg>
where the value will be assembled
into the list of options.
New in version 0.9.2.
Changed in version 0.9.4: The DialectKWArgs.dialect_kwargs
collection is now writable.
See also
DialectKWArgs.dialect_options
- nested dictionary form
dialect_options
¶A collection of keyword arguments specified as dialect-specific options to this construct.
This is a two-level nested registry, keyed to <dialect_name>
and <argument_name>
. For example, the postgresql_where
argument would be locatable as:
arg = my_object.dialect_options['postgresql']['where']
New in version 0.9.2.
See also
DialectKWArgs.dialect_kwargs
- flat dictionary form
kwargs
¶A synonym for DialectKWArgs.dialect_kwargs
.
sqlalchemy.sql.expression.
Extract
(field, expr, **kwargs)¶Bases: sqlalchemy.sql.expression.ColumnElement
Represent a SQL EXTRACT clause, extract(field FROM expr)
.
__init__
(field, expr, **kwargs)¶Construct a new Extract
object.
This constructor is mirrored as a public API function; see extract()
for a full usage and argument description.
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).
sqlalchemy.sql.elements.
False_
¶Bases: sqlalchemy.sql.expression.ColumnElement
Represent the false
keyword, or equivalent, in a SQL statement.
False_
is accessed as a constant via the
false()
function.
compare
(other)¶Compare this ColumnElement to another.
Special arguments understood:
Parameters: |
|
---|
sqlalchemy.sql.expression.
FunctionFilter
(func, *criterion)¶Bases: sqlalchemy.sql.expression.ColumnElement
Represent a function FILTER clause.
This is a special operator against aggregate and window functions, which controls which rows are passed to it. It’s supported only by certain database backends.
Invocation of FunctionFilter
is via
FunctionElement.filter()
:
func.count(1).filter(True)
New in version 1.0.0.
See also
__init__
(func, *criterion)¶Construct a new FunctionFilter
object.
This constructor is mirrored as a public API function; see funcfilter()
for a full usage and argument description.
filter
(*criterion)¶Produce an additional FILTER against the function.
This method adds additional criteria to the initial criteria
set up by FunctionElement.filter()
.
Multiple criteria are joined together at SQL render time
via AND
.
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, range_=None, rows=None)¶Produce an OVER clause against this filtered function.
Used against aggregate or so-called “window” functions, for database backends that support window functions.
The expression:
func.rank().filter(MyClass.y > 5).over(order_by='x')
is shorthand for:
from sqlalchemy import over, funcfilter
over(funcfilter(func.rank(), MyClass.y > 5), order_by='x')
See over()
for a full description.
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.
sqlalchemy.sql.expression.
Label
(name, element, type_=None)¶Bases: sqlalchemy.sql.expression.ColumnElement
Represents a column label (AS).
Represent a label, as typically applied to any column-level
element using the AS
sql keyword.
__init__
(name, element, type_=None)¶Construct a new Label
object.
This constructor is mirrored as a public API function; see label()
for a full usage and argument description.
foreign_keys
¶Built-in mutable sequence.
If no argument is given, the constructor creates a new empty list. The argument must be an iterable if specified.
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).
primary_key
¶bool(x) -> bool
Returns True when the argument x is true, False otherwise. The builtins True and False are the only two instances of the class bool. The class bool is a subclass of the class int, and cannot be subclassed.
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.
sqlalchemy.sql.elements.
Null
¶Bases: sqlalchemy.sql.expression.ColumnElement
Represent the NULL keyword in a SQL statement.
Null
is accessed as a constant via the
null()
function.
compare
(other)¶Compare this ColumnElement to another.
Special arguments understood:
Parameters: |
|
---|
sqlalchemy.sql.expression.
Over
(element, partition_by=None, order_by=None, range_=None, rows=None)¶Bases: sqlalchemy.sql.expression.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.
__init__
(element, partition_by=None, order_by=None, range_=None, rows=None)¶Construct a new Over
object.
This constructor is mirrored as a public API function; see over()
for a full usage and argument description.
func
¶the element referred to by this Over
clause.
Deprecated since version 1.1: the Over.func
member of the Over
class is deprecated and will be removed in a future release. Please refer to the Over.element
attribute.
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).
sqlalchemy.sql.expression.
TextClause
(text, bind=None)¶Bases: sqlalchemy.sql.expression.Executable
, sqlalchemy.sql.expression.ClauseElement
Represent a literal SQL text fragment.
E.g.:
from sqlalchemy import text
t = text("SELECT * FROM users")
result = connection.execute(t)
The Text
construct is produced using the text()
function; see that function for full documentation.
See also
bindparams
(*binds, **names_to_values)¶Establish the values and/or types of bound parameters within
this TextClause
construct.
Given a text construct such as:
from sqlalchemy import text
stmt = text("SELECT id, name FROM user WHERE name=:name "
"AND timestamp=:timestamp")
the TextClause.bindparams()
method can be used to establish
the initial value of :name
and :timestamp
,
using simple keyword arguments:
stmt = stmt.bindparams(name='jack',
timestamp=datetime.datetime(2012, 10, 8, 15, 12, 5))
Where above, new BindParameter
objects
will be generated with the names name
and timestamp
, and
values of jack
and datetime.datetime(2012, 10, 8, 15, 12, 5)
,
respectively. The types will be
inferred from the values given, in this case String
and
DateTime
.
When specific typing behavior is needed, the positional *binds
argument can be used in which to specify bindparam()
constructs
directly. These constructs must include at least the key
argument, then an optional value and type:
from sqlalchemy import bindparam
stmt = stmt.bindparams(
bindparam('name', value='jack', type_=String),
bindparam('timestamp', type_=DateTime)
)
Above, we specified the type of DateTime
for the
timestamp
bind, and the type of String
for the name
bind. In the case of name
we also set the default value of
"jack"
.
Additional bound parameters can be supplied at statement execution time, e.g.:
result = connection.execute(stmt,
timestamp=datetime.datetime(2012, 10, 8, 15, 12, 5))
The TextClause.bindparams()
method can be called repeatedly,
where it will re-use existing BindParameter
objects to add
new information. For example, we can call
TextClause.bindparams()
first with typing information, and a
second time with value information, and it will be combined:
stmt = text("SELECT id, name FROM user WHERE name=:name "
"AND timestamp=:timestamp")
stmt = stmt.bindparams(
bindparam('name', type_=String),
bindparam('timestamp', type_=DateTime)
)
stmt = stmt.bindparams(
name='jack',
timestamp=datetime.datetime(2012, 10, 8, 15, 12, 5)
)
The TextClause.bindparams()
method also supports the concept of
unique bound parameters. These are parameters that are
“uniquified” on name at statement compilation time, so that multiple
text()
constructs may be combined together without the names
conflicting. To use this feature, specify the
BindParameter.unique
flag on each bindparam()
object:
stmt1 = text("select id from table where name=:name").bindparams(
bindparam("name", value='name1', unique=True)
)
stmt2 = text("select id from table where name=:name").bindparams(
bindparam("name", value='name2', unique=True)
)
union = union_all(
stmt1.columns(column("id")),
stmt2.columns(column("id"))
)
The above statement will render as:
select id from table where name=:name_1
UNION ALL select id from table where name=:name_2
New in version 1.3.11: Added support for the
BindParameter.unique
flag to work with text()
constructs.
columns
(selectable, *cols, **types)¶Turn this TextClause
object into a TextAsFrom
object that can be embedded into another statement.
This function essentially bridges the gap between an entirely textual SELECT statement and the SQL expression language concept of a “selectable”:
from sqlalchemy.sql import column, text
stmt = text("SELECT id, name FROM some_table")
stmt = stmt.columns(column('id'), column('name')).alias('st')
stmt = select([mytable]). select_from(
mytable.join(stmt, mytable.c.name == stmt.c.name)
).where(stmt.c.id > 5)
Above, we pass a series of column()
elements to the
TextClause.columns()
method positionally. These column()
elements now become first class elements upon the TextAsFrom.c
column collection, just like any other selectable.
The column expressions we pass to TextClause.columns()
may
also be typed; when we do so, these TypeEngine
objects become
the effective return type of the column, so that SQLAlchemy’s
result-set-processing systems may be used on the return values.
This is often needed for types such as date or boolean types, as well
as for unicode processing on some dialect configurations:
stmt = text("SELECT id, name, timestamp FROM some_table")
stmt = stmt.columns(
column('id', Integer),
column('name', Unicode),
column('timestamp', DateTime)
)
for id, name, timestamp in connection.execute(stmt):
print(id, name, timestamp)
As a shortcut to the above syntax, keyword arguments referring to types alone may be used, if only type conversion is needed:
stmt = text("SELECT id, name, timestamp FROM some_table")
stmt = stmt.columns(
id=Integer,
name=Unicode,
timestamp=DateTime
)
for id, name, timestamp in connection.execute(stmt):
print(id, name, timestamp)
The positional form of TextClause.columns()
also provides the
unique feature of positional column targeting, which is
particularly useful when using the ORM with complex textual queries. If
we specify the columns from our model to TextClause.columns()
,
the result set will match to those columns positionally, meaning the
name or origin of the column in the textual SQL doesn’t matter:
stmt = text("SELECT users.id, addresses.id, users.id, "
"users.name, addresses.email_address AS email "
"FROM users JOIN addresses ON users.id=addresses.user_id "
"WHERE users.id = 1").columns(
User.id,
Address.id,
Address.user_id,
User.name,
Address.email_address
)
query = session.query(User).from_statement(stmt).options(
contains_eager(User.addresses))
New in version 1.1: the TextClause.columns()
method now
offers positional column targeting in the result set when
the column expressions are passed purely positionally.
The TextClause.columns()
method provides a direct
route to calling FromClause.alias()
as well as
SelectBase.cte()
against a textual SELECT statement:
stmt = stmt.columns(id=Integer, name=String).cte('st')
stmt = select([sometable]).where(sometable.c.id == stmt.c.id)
New in version 0.9.0: text()
can now be converted into a
fully featured “selectable” construct using the
TextClause.columns()
method.
compare
(other)¶Compare this ClauseElement to the given ClauseElement.
Subclasses should override the default behavior, which is a straight identity comparison.
**kw are arguments consumed by subclass compare() methods and
may be used to modify the criteria for comparison.
(see ColumnElement
)
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).
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.
sqlalchemy.sql.expression.
Tuple
(*clauses, **kw)¶Bases: sqlalchemy.sql.expression.ClauseList
, sqlalchemy.sql.expression.ColumnElement
Represent a SQL tuple.
sqlalchemy.sql.expression.
WithinGroup
(element, *order_by)¶Bases: sqlalchemy.sql.expression.ColumnElement
Represent a WITHIN GROUP (ORDER BY) clause.
This is a special operator against so-called
“ordered set aggregate” and “hypothetical
set aggregate” functions, including percentile_cont()
,
rank()
, dense_rank()
, etc.
It’s supported only by certain database backends, such as PostgreSQL, Oracle and MS SQL Server.
The WithinGroup
construct extracts its type from the
method FunctionElement.within_group_type()
. If this returns
None
, the function’s .type
is used.
__init__
(element, *order_by)¶Construct a new WithinGroup
object.
This constructor is mirrored as a public API function; see within_group()
for a full usage and argument description.
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, range_=None, rows=None)¶Produce an OVER clause against this WithinGroup
construct.
This function has the same signature as that of
FunctionElement.over()
.
sqlalchemy.sql.elements.
True_
¶Bases: sqlalchemy.sql.expression.ColumnElement
Represent the true
keyword, or equivalent, in a SQL statement.
True_
is accessed as a constant via the
true()
function.
compare
(other)¶Compare this ColumnElement to another.
Special arguments understood:
Parameters: |
|
---|
sqlalchemy.sql.expression.
TypeCoerce
(expression, type_)¶Bases: sqlalchemy.sql.expression.ColumnElement
Represent a Python-side type-coercion wrapper.
TypeCoerce
supplies the expression.type_coerce()
function; see that function for usage details.
Changed in version 1.1: The type_coerce()
function now produces
a persistent TypeCoerce
wrapper object rather than
translating the given object in place.
__init__
(expression, type_)¶Construct a new TypeCoerce
object.
This constructor is mirrored as a public API function; see type_coerce()
for a full usage and argument description.
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).
sqlalchemy.sql.operators.
custom_op
(opstring, precedence=0, is_comparison=False, return_type=None, natural_self_precedent=False, eager_grouping=False)¶Represent a ‘custom’ operator.
custom_op
is normally instantiated when the
Operators.op()
or Operators.bool_op()
methods
are used to create a custom operator callable. The class can also be
used directly when programmatically constructing expressions. E.g.
to represent the “factorial” operation:
from sqlalchemy.sql import UnaryExpression
from sqlalchemy.sql import operators
from sqlalchemy import Numeric
unary = UnaryExpression(table.c.somecolumn,
modifier=operators.custom_op("!"),
type_=Numeric)
sqlalchemy.sql.operators.
Operators
¶Base of comparison and logical operators.
Implements base methods
operate()
and
reverse_operate()
, as well as
__and__()
,
__or__()
,
__invert__()
.
Usually is used via its most common subclass
ColumnOperators
.
__and__
(other)¶Implement the &
operator.
When used with SQL expressions, results in an
AND operation, equivalent to
and_()
, that is:
a & b
is equivalent to:
from sqlalchemy import and_
and_(a, b)
Care should be taken when using &
regarding
operator precedence; the &
operator has the highest precedence.
The operands should be enclosed in parenthesis if they contain
further sub expressions:
(a == 2) & (b == 4)
__invert__
()¶Implement the ~
operator.
When used with SQL expressions, results in a
NOT operation, equivalent to
not_()
, that is:
~a
is equivalent to:
from sqlalchemy import not_
not_(a)
__or__
(other)¶Implement the |
operator.
When used with SQL expressions, results in an
OR operation, equivalent to
or_()
, that is:
a | b
is equivalent to:
from sqlalchemy import or_
or_(a, b)
Care should be taken when using |
regarding
operator precedence; the |
operator has the highest precedence.
The operands should be enclosed in parenthesis if they contain
further sub expressions:
(a == 2) | (b == 4)
bool_op
(opstring, precedence=0)¶Return a custom boolean operator.
This method is shorthand for calling
Operators.op()
and passing the
Operators.op.is_comparison
flag with True.
New in version 1.2.0b3.
See also
op
(opstring, precedence=0, is_comparison=False, return_type=None)¶produce a generic operator function.
e.g.:
somecolumn.op("*")(5)
produces:
somecolumn * 5
This function can also be used to make bitwise operators explicit. For example:
somecolumn.op('&')(0xff)
is a bitwise AND of the value in somecolumn
.
Parameters: |
|
---|
operate
(op, *other, **kwargs)¶Operate on an argument.
This is the lowest level of operation, raises
NotImplementedError
by default.
Overriding this on a subclass can allow common
behavior to be applied to all operations.
For example, overriding ColumnOperators
to apply func.lower()
to the left and right
side:
class MyComparator(ColumnOperators):
def operate(self, op, other):
return op(func.lower(self), func.lower(other))
Parameters: |
|
---|
sqlalchemy.sql.elements.
quoted_name
¶Bases: sqlalchemy.util.langhelpers.MemoizedSlots
, builtins.str
Represent a SQL identifier combined with quoting preferences.
quoted_name
is a Python unicode/str subclass which
represents a particular identifier name along with a
quote
flag. This quote
flag, when set to
True
or False
, overrides automatic quoting behavior
for this identifier in order to either unconditionally quote
or to not quote the name. If left at its default of None
,
quoting behavior is applied to the identifier on a per-backend basis
based on an examination of the token itself.
A quoted_name
object with quote=True
is also
prevented from being modified in the case of a so-called
“name normalize” option. Certain database backends, such as
Oracle, Firebird, and DB2 “normalize” case-insensitive names
as uppercase. The SQLAlchemy dialects for these backends
convert from SQLAlchemy’s lower-case-means-insensitive convention
to the upper-case-means-insensitive conventions of those backends.
The quote=True
flag here will prevent this conversion from occurring
to support an identifier that’s quoted as all lower case against
such a backend.
The quoted_name
object is normally created automatically
when specifying the name for key schema constructs such as
Table
, Column
, and others. The class can also be
passed explicitly as the name to any function that receives a name which
can be quoted. Such as to use the Engine.has_table()
method with
an unconditionally quoted name:
from sqlalchemy import create_engine
from sqlalchemy.sql import quoted_name
engine = create_engine("oracle+cx_oracle://some_dsn")
engine.has_table(quoted_name("some_table", True))
The above logic will run the “has table” logic against the Oracle backend,
passing the name exactly as "some_table"
without converting to
upper case.
New in version 0.9.0.
Changed in version 1.2: The quoted_name
construct is now
importable from sqlalchemy.sql
, in addition to the previous
location of sqlalchemy.sql.elements
.
quote
¶whether the string should be unconditionally quoted
sqlalchemy.sql.expression.
UnaryExpression
(element, operator=None, modifier=None, type_=None, negate=None, wraps_column_expression=False)¶Bases: sqlalchemy.sql.expression.ColumnElement
Define a ‘unary’ expression.
A unary expression has a single column expression and an operator. The operator can be placed on the left (where it is called the ‘operator’) or right (where it is called the ‘modifier’) of the column expression.
UnaryExpression
is the basis for several unary operators
including those used by desc()
, asc()
, distinct()
,
nullsfirst()
and nullslast()
.
compare
(other, **kw)¶Compare this UnaryExpression
against the given
ClauseElement
.
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).
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.