Column Elements and Expressions

The expression API consists of a series of classes each of which represents aspecific lexical element within a SQL string. Composed togetherinto a larger structure, they form a statement construct that maybe compiled into a string representation that can be passed to a database.The classes are organized into ahierarchy that begins at the basemost ClauseElement class. Key subclassesinclude ColumnElement, which represents the role of any column-based expressionin a SQL statement, such as in the columns clause, WHERE clause, and ORDER BYclause, and FromClause, which represents the role of a token that is placed inthe 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.:

  1. # postgresql '5 = ALL (somearray)'
  2. expr = 5 == all_(mytable.c.somearray)
  3.  
  4. # mysql '5 = ALL (SELECT value FROM table)'
  5. expr = 5 == all_(select([table.c.value]))

New in version 1.1.

See also

expression.any_()

E.g.:

  1. from sqlalchemy import and_
  2.  
  3. stmt = select([users_table]).where(
  4. and_(
  5. users_table.c.name == 'wendy',
  6. users_table.c.enrolled == True
  7. )
  8. )

The and_() conjunction is also available using thePython & operator (though note that compound expressionsneed to be parenthesized in order to function with Pythonoperator precedence behavior):

  1. stmt = select([users_table]).where(
  2. (users_table.c.name == 'wendy') &
  3. (users_table.c.enrolled == True)
  4. )

The and_() operation is also implicit in some cases;the Select.where() method for example can be invoked multipletimes against a statement, which will have the effect of eachclause being combined using and_():

  1. stmt = select([users_table]). where(users_table.c.name == 'wendy'). where(users_table.c.enrolled == True)

See also

or_()

  • 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.:

  1. # postgresql '5 = ANY (somearray)'
  2. expr = 5 == any_(mytable.c.somearray)
  3.  
  4. # mysql '5 = ANY (SELECT value FROM table)'
  5. expr = 5 == any_(select([table.c.value]))

New in version 1.1.

See also

expression.all_()

  • sqlalchemy.sql.expression.asc(column)
  • Produce an ascending ORDER BY clause element.

e.g.:

  1. from sqlalchemy import asc
  2. stmt = select([users_table]).order_by(asc(users_table.c.name))

will produce SQL as:

  1. SELECT id, name FROM user ORDER BY name ASC

The asc() function is a standalone version of theColumnElement.asc() method available on all SQL expressions,e.g.:

  1. 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.

See also

desc()

nullsfirst()

nullslast()

Select.order_by()

  • sqlalchemy.sql.expression.between(expr, lower_bound, upper_bound, symmetric=False)
  • Produce a BETWEEN predicate clause.

E.g.:

  1. from sqlalchemy import between
  2. stmt = select([users_table]).where(between(users_table.c.id, 5, 7))

Would produce SQL resembling:

  1. SELECT id, name FROM user WHERE id BETWEEN :id_1 AND :id_2

The between() function is a standalone version of theColumnElement.between() method available on allSQL expressions, as in:

  1. stmt = select([users_table]).where(users_table.c.id.between(5, 7))

All arguments passed to between(), including the left sidecolumn expression, are coerced from Python scalar values if athe value is not a ColumnElement subclass. For example,three fixed values can be compared as in:

  1. print(between(5, 3, 7))

Which would produce:

  1. :param_1 BETWEEN :param_2 AND :param_3
  • Parameters
    • expr – a column expression, typically a ColumnElementinstance or alternatively a Python scalar expression to be coercedinto a column expression, serving as the left side of the BETWEENexpression.

    • lower_bound – a column or Python scalar expression serving as thelower bound of the right side of the BETWEEN expression.

    • upper_bound – a column or Python scalar expression serving as theupper bound of the right side of the BETWEEN expression.

    • symmetric

if True, will render ” BETWEEN SYMMETRIC “. Notethat not all databases support this syntax.

New in version 0.9.5.

See also

ColumnElement.between()

  • 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, comparedto_operator=None, comparedto_type=None)
  • Produce a “bound expression”.

The return value is an instance of BindParameter; thisis a ColumnElement subclass which represents a so-called“placeholder” value in a SQL expression, the value of which issupplied at the point at which the statement in executed against adatabase connection.

In SQLAlchemy, the bindparam() construct hasthe ability to carry along the actual value that will be ultimatelyused at expression time. In this way, it serves not just asa “placeholder” for eventual population, but also as a means ofrepresenting so-called “unsafe” values which should not be rendereddirectly in a SQL statement, but rather should be passed alongto the DBAPI as values which need to be correctly escapedand potentially handled for type-safety.

When using bindparam() explicitly, the use case is typicallyone of traditional deferment of parameters; the bindparam()construct accepts a name which can then be referred to at executiontime:

  1. from sqlalchemy import bindparam
  2.  
  3. stmt = select([users_table]).\
  4. where(users_table.c.name == bindparam('username'))

The above statement, when rendered, will produce SQL similar to:

  1. SELECT id, name FROM user WHERE name = :username

In order to populate the value of :username above, the valuewould typically be applied at execution time to a methodlike Connection.execute():

  1. result = connection.execute(stmt, username='wendy')

Explicit use of bindparam() is also common when producingUPDATE or DELETE statements that are to be invoked multiple times,where the WHERE criterion of the statement is to change on eachinvocation, such as:

  1. stmt = (users_table.update().
  2. where(user_table.c.name == bindparam('username')).
  3. values(fullname=bindparam('fullname'))
  4. )
  5.  
  6. connection.execute(
  7. stmt, [{"username": "wendy", "fullname": "Wendy Smith"},
  8. {"username": "jack", "fullname": "Jack Jones"},
  9. ]
  10. )

SQLAlchemy’s Core expression system makes wide use ofbindparam() in an implicit sense. It is typical that Pythonliteral values passed to virtually all SQL expression functions arecoerced into fixed bindparam() constructs. For example, givena comparison operation such as:

  1. expr = users_table.c.name == 'Wendy'

The above expression will produce a BinaryExpressionconstruct, where the left side is the Column objectrepresenting the name column, and the right side is aBindParameter representing the literal value:

  1. print(repr(expr.right))
  2. BindParameter('%(4327771088 name)s', 'Wendy', type_=String())

The expression above will render SQL such as:

  1. user.name = :name_1

Where the :name_1 parameter name is an anonymous name. Theactual string Wendy is not in the rendered string, but is carriedalong where it is later used within statement execution. If weinvoke a statement like the following:

  1. stmt = select([users_table]).where(users_table.c.name == 'Wendy')
  2. result = connection.execute(stmt)

We would see SQL logging output as:

  1. SELECT "user".id, "user".name
  2. FROM "user"
  3. WHERE "user".name = %(name_1)s
  4. {'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 formfor the target database, in this case the PostgreSQL database.

Similarly, bindparam() is invoked automaticallywhen working with CRUD statements as far as the “VALUES”portion is concerned. The insert() construct produces anINSERT expression which will, at statement execution time,generate bound placeholders based on the arguments passed, as in:

  1. stmt = users_table.insert()
  2. result = connection.execute(stmt, name='Wendy')

The above will produce SQL output as:

  1. INSERT INTO "user" (name) VALUES (%(name)s)
  2. {'name': 'Wendy'}

The Insert construct, at compilation/execution time,rendered a single bindparam() mirroring the columnname name as a result of the single name parameterwe passed to the Connection.execute() method.

  • Parameters
    • key – the key (e.g. the name) for this bind param.Will be used in the generatedSQL statement for dialects that use named parameters. Thisvalue may be modified when part of a compilation operation,if other BindParameter objects exist with the samekey, or if its length is too long and truncation isrequired.

    • value – Initial value for this bind param. Will be used at statementexecution time as the value for this parameter passed to theDBAPI, if no other value is indicated to the statement executionmethod for this particular parameter name. Defaults to None.

    • callable_ – A callable function that takes the place of “value”. The functionwill be called at statement execution time to determine theultimate value. Used for scenarios where the actual bindvalue cannot be determined at the point at which the clauseconstruct is created, but embedded bind values are still desirable.

    • type_

A TypeEngine class or instance representing an optionaldatatype for this bindparam(). If not passed, a typemay be determined automatically for the bind, based on the givenvalue; for example, trivial Python types such as str,int, boolmay result in the String, Integer orBoolean types being automatically selected.

The type of a bindparam() is significant especially in thatthe type will apply pre-processing to the value before it ispassed to the database. For example, a bindparam() whichrefers to a datetime value, and is specified as holding theDateTime type, may apply conversion needed to thevalue (such as stringification on SQLite) before passing the valueto the database.

  1. -

unique – if True, the key name of this BindParameter will bemodified if another BindParameter of the same namealready has been located within the containingexpression. This flag is used generally by the internalswhen producing so-called “anonymous” bound expressions, itisn’t generally applicable to explicitly-named bindparam()constructs.

  1. -

required – If True, a value is required at execution time. If not passed,it defaults to True if neither bindparam.valueor bindparam.callable were passed. If either of theseparameters are present, then bindparam.requireddefaults to False.

  1. -

quote – True if this parameter name requires quoting and is notcurrently known as a SQLAlchemy reserved word; this currentlyonly applies to the Oracle backend, where bound names mustsometimes be quoted.

  1. -

isoutparam – if True, the parameter should be treated like a stored procedure“OUT” parameter. This applies to backends such as Oracle whichsupport OUT parameters.

  1. -

expanding

if True, this parameter will be treated as an “expanding” parameterat execution time; the parameter value is expected to be a sequence,rather than a scalar value, and the string SQL statement willbe transformed on a per-execution basis to accommodate the sequencewith a variable number of parameter slots passed to the DBAPI.This is to allow statement caching to be used in conjunction withan IN clause.

See also

ColumnOperators.in_()

Using IN expressions - with baked queries

Note

The “expanding” feature does not support “executemany”-style parameter sets.

New in version 1.2.

Changed in version 1.3: the “expanding” bound parameter feature nowsupports empty lists.

See also

Bind Parameter Objects

Insert Expressions

outparam()

  • sqlalchemy.sql.expression.case(whens, value=None, else=None_)
  • Produce a CASE expression.

The CASE construct in SQL is a conditional object thatacts somewhat analogously to an “if/then” construct in otherlanguages. 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:

  1. from sqlalchemy import case
  2.  
  3. stmt = select([users_table]).\
  4. where(
  5. case(
  6. [
  7. (users_table.c.name == 'wendy', 'W'),
  8. (users_table.c.name == 'jack', 'J')
  9. ],
  10. else_='E'
  11. )
  12. )

The above statement will produce SQL resembling:

  1. SELECT id, name FROM user
  2. WHERE CASE
  3. WHEN (name = :name_1) THEN :param_1
  4. WHEN (name = :name_2) THEN :param_2
  5. ELSE :param_3
  6. END

When simple equality expressions of several values against a singleparent column are needed, case() also has a “shorthand” formatused via thecase.value parameter, which is passed a columnexpression to be compared. In this form, the case.whensparameter is passed as a dictionary containing expressions to becompared against keyed to result expressions. The statement below isequivalent to the preceding statement:

  1. stmt = select([users_table]).\
  2. where(
  3. case(
  4. {"wendy": "W", "jack": "J"},
  5. value=users_table.c.name,
  6. else_='E'
  7. )
  8. )

The values which are accepted as result values incase.whens as well as with case.else_ arecoerced from Python literals into bindparam() constructs.SQL expressions, e.g. ColumnElement constructs, are acceptedas well. To coerce a literal string expression into a constantexpression rendered inline, use the literal_column() construct,as in:

  1. from sqlalchemy import case, literal_column
  2.  
  3. case(
  4. [
  5. (
  6. orderline.c.qty > 100,
  7. literal_column("'greaterthan100'")
  8. ),
  9. (
  10. orderline.c.qty > 10,
  11. literal_column("'greaterthan10'")
  12. )
  13. ],
  14. else_=literal_column("'lessthan10'")
  15. )

The above will render the given constants without using boundparameters for the result values (but still for the comparisonvalues), as in:

  1. CASE
  2. WHEN (orderline.qty > :qty_1) THEN 'greaterthan100'
  3. WHEN (orderline.qty > :qty_2) THEN 'greaterthan10'
  4. ELSE 'lessthan10'
  5. END
  • Parameters
    • whens

The criteria to be compared against,case.whens accepts two different forms, based onwhether or not case.value is used.

In the first form, it accepts a list of 2-tuples; each 2-tupleconsists of (<sql expression>, <value>), where the SQLexpression is a boolean expression and “value” is a resulting value,e.g.:

  1. case([
  2. (users_table.c.name == 'wendy', 'W'),
  3. (users_table.c.name == 'jack', 'J')
  4. ])

In the second form, it accepts a Python dictionary of comparisonvalues mapped to a resulting value; this form requirescase.value to be present, and values will be comparedusing the == operator, e.g.:

  1. case(
  2. {"wendy": "W", "jack": "J"},
  3. value=users_table.c.name
  4. )
  1. -

value – An optional SQL expression which will be used as afixed “comparison point” for candidate values within a dictionarypassed to case.whens.

  1. -

else_ – An optional SQL expression which will be the evaluatedresult of the CASE construct if all expressions withincase.whens evaluate to false. When omitted, mostdatabases will produce a result of NULL if none of the “when”expressions evaluate to true.

  • sqlalchemy.sql.expression.cast(expression, type_)
  • Produce a CAST expression.

cast() returns an instance of Cast.

E.g.:

  1. from sqlalchemy import cast, Numeric
  2.  
  3. stmt = select([
  4. cast(product_table.c.unit_price, Numeric(10, 4))
  5. ])

The above statement will produce SQL resembling:

  1. SELECT CAST(unit_price AS NUMERIC(10, 4)) FROM product

The cast() function performs two distinct functions whenused. The first is that it renders the CAST expression withinthe resulting SQL string. The second is that it associates the giventype (e.g. TypeEngine class or instance) with the columnexpression on the Python side, which means the expression will takeon the expression operator behavior associated with that type,as well as the bound-value handling and result-row-handling behaviorof the type.

Changed in version 0.9.0: cast() now applies the given typeto the expression such that it takes effect on the bound-value,e.g. the Python-to-database direction, in addition to theresult 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 expressionwith a specific type, but does not render the CAST expressionin SQL.

  • Parameters
    • expression – A SQL expression, such as a ColumnElementexpression or a Python string which will be coerced into a boundliteral value.

    • type_ – A TypeEngine class or instance indicatingthe type to which the CAST should apply.

See also

Data Casts and Type Coercion

type_coerce() - an alternative to CAST that coerces the typeon the Python side only, which is often sufficient to generate thecorrect 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 theColumn class. The column() function canbe invoked with just a name alone, as in:

  1. from sqlalchemy import column
  2.  
  3. id, name = column("id"), column("name")
  4. stmt = select([id, name]).select_from("user")

The above statement would produce SQL like:

  1. SELECT id, name FROM user

Once constructed, column() may be used like any other SQLexpression element such as within select() constructs:

  1. from sqlalchemy.sql import column
  2.  
  3. id, name = column("id"), column("name")
  4. stmt = select([id, name]).select_from("user")

The text handled by column() is assumed to be handledlike the name of a database column; if the string contains mixed case,special characters, or matches a known reserved word on the targetbackend, the column expression will render using the quotingbehavior determined by the backend. To produce a textual SQLexpression that is rendered exactly without any quoting,use literal_column() instead, or pass True as thevalue of column.is_literal. Additionally, full SQLstatements are best handled using the text() construct.

column() can be used in a table-likefashion by combining it with the table() function(which is the lightweight analogue to Table) to producea working table construct with minimal boilerplate:

  1. from sqlalchemy import table, column, select
  2.  
  3. user = table("user",
  4. column("id"),
  5. column("name"),
  6. column("description"),
  7. )
  8.  
  9. stmt = select([user.c.description]).where(user.c.name == 'wendy')

A column() / table() construct like that illustratedabove can be created in anad-hoc fashion and is not associated with anyschema.MetaData, DDL, or events, unlike itsTable counterpart.

Changed in version 1.0.0: expression.column() can nowbe imported from the plain sqlalchemy namespace like anyother SQL element.

  • Parameters
    • text – the text of the element.

    • typetypes.TypeEngine object which can associatethis ColumnClause with a type.

    • is_literal – if True, the ColumnClause is assumed tobe an exact expression that will be delivered to the output with noquoting rules applied regardless of case sensitive settings. theliteral_column() function essentially invokescolumn() while passing is_literal=True.

See also

Column

literal_column()

table()

text()

Using More Specific Text with table(), literal_column(), and column()

  • sqlalchemy.sql.expression.collate(expression, collation)
  • Return the clause expression COLLATE collation.

e.g.:

  1. collate(mycolumn, 'utf8_bin')

produces:

  1. mycolumn COLLATE utf8_bin

The collation expression is also quoted if it is a case sensitiveidentifier, e.g. contains uppercase characters.

Changed in version 1.2: quoting is automatically applied to COLLATEexpressions if they are case sensitive.

  • sqlalchemy.sql.expression.desc(column)
  • Produce a descending ORDER BY clause element.

e.g.:

  1. from sqlalchemy import desc
  2.  
  3. stmt = select([users_table]).order_by(desc(users_table.c.name))

will produce SQL as:

  1. SELECT id, name FROM user ORDER BY name DESC

The desc() function is a standalone version of theColumnElement.desc() method available on all SQL expressions,e.g.:

  1. 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.

See also

asc()

nullsfirst()

nullslast()

Select.order_by()

  • sqlalchemy.sql.expression.distinct(expr)
  • Produce an column-expression-level unary DISTINCT clause.

This applies the DISTINCT keyword to an individual columnexpression, and is typically contained within an aggregate function,as in:

  1. from sqlalchemy import distinct, func
  2. stmt = select([func.count(distinct(users_table.c.name))])

The above would produce an expression resembling:

  1. SELECT COUNT(DISTINCT name) FROM user

The distinct() function is also available as a column-levelmethod, e.g. ColumnElement.distinct(), as in:

  1. stmt = select([func.count(users_table.c.name.distinct())])

The distinct() operator is different from theSelect.distinct() method of Select,which produces a SELECT statementwith DISTINCT applied to the result set as a whole,e.g. a SELECT DISTINCT expression. See that method for furtherinformation.

See also

ColumnElement.distinct()

Select.distinct()

func

  • sqlalchemy.sql.expression.extract(field, expr, **kwargs)
  • Return a Extract construct.

This is typically available as extract()as well as func.extract from thefunc namespace.

  • sqlalchemy.sql.expression.false()
  • Return a False_ construct.

E.g.:

  1. >>> from sqlalchemy import false
  2. >>> print select([t.c.x]).where(false())
  3. SELECT x FROM t WHERE false

A backend which does not support true/false constants will render asan expression against 1 or 0:

  1. >>> print select([t.c.x]).where(false())
  2. SELECT x FROM t WHERE 0 = 1

The true() and false() constants also feature“short circuit” operation within an and_() or or_()conjunction:

  1. >>> print select([t.c.x]).where(or_(t.c.x > 5, true()))
  2. SELECT x FROM t WHERE true
  3.  
  4. >>> print select([t.c.x]).where(and_(t.c.x > 5, false()))
  5. SELECT x FROM t WHERE false

Changed in version 0.9: true() and false() featurebetter integrated behavior within conjunctions and on dialectsthat don’t support true/false constants.

See also

true()

  • sqlalchemy.sql.expression.func =
  • Generate Function objects based on getattr calls.
  • 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.:

  1. from sqlalchemy import funcfilter
  2. 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 funcconstruct itself via the FunctionElement.filter() method.

New in version 1.0.0.

See also

FunctionElement.filter()

  • sqlalchemy.sql.expression.label(name, element, type=None_)
  • Return a Label object for thegiven ColumnElement.

A label changes the name of an element in the columns clause of aSELECT statement, typically via the AS SQL keyword.

This functionality is more conveniently available via theColumnElement.label() method on ColumnElement.

  • 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.) areused in a comparison operation with a ColumnElement subclass,such as a Column object. Use this functionto force the generation of a literal clause, which will be created as aBindParameter with a bound value.

  • Parameters
    • value – the value to be bound. Can be any Python object supported bythe underlying DB-API, or is translatable via the given type argument.

    • type_ – an optional TypeEngine whichwill provide bind-parameter translation for this literal.

literal_column() is similar to column(), except thatit is more often used as a “standalone” column expression that rendersexactly as stated; while column() stores a string name thatwill be assumed to be part of a table and may be quoted as such,literal_column() can be that, or any other arbitrary column-orientedexpression.

  • Parameters
    • text – the text of the expression; can be any SQL expression.Quoting rules will not be applied. To specify a column-name expressionwhich should be subject to quoting rules, use the column()function.

    • type_ – an optional TypeEngineobject which willprovide result-set translation and additional expression semantics forthis column. If left as None the type will be NullType.

See also

column()

text()

Using More Specific Text with table(), literal_column(), and column()

  • sqlalchemy.sql.expression.not(_clause)
  • Return a negation of the given clause, i.e. NOT(clause).

The ~ operator is also overloaded on allColumnElement subclasses to produce thesame result.

  • sqlalchemy.sql.expression.null()
  • Return a constant Null construct.

  • sqlalchemy.sql.expression.nullsfirst(column)

  • Produce the NULLS FIRST modifier for an ORDER BY expression.

nullsfirst() is intended to modify the expression producedby asc() or desc(), and indicates how NULL valuesshould be handled when they are encountered during ordering:

  1. from sqlalchemy import desc, nullsfirst
  2.  
  3. stmt = select([users_table]). order_by(nullsfirst(desc(users_table.c.name)))

The SQL expression from the above would resemble:

  1. SELECT id, name FROM user ORDER BY name DESC NULLS FIRST

Like asc() and desc(), nullsfirst() is typicallyinvoked from the column expression itself usingColumnElement.nullsfirst(), rather than as its standalonefunction version, as in:

  1. stmt = (select([users_table]).
  2. order_by(users_table.c.name.desc().nullsfirst())
  3. )

See also

asc()

desc()

nullslast()

Select.order_by()

  • sqlalchemy.sql.expression.nullslast(column)
  • Produce the NULLS LAST modifier for an ORDER BY expression.

nullslast() is intended to modify the expression producedby asc() or desc(), and indicates how NULL valuesshould be handled when they are encountered during ordering:

  1. from sqlalchemy import desc, nullslast
  2.  
  3. stmt = select([users_table]). order_by(nullslast(desc(users_table.c.name)))

The SQL expression from the above would resemble:

  1. SELECT id, name FROM user ORDER BY name DESC NULLS LAST

Like asc() and desc(), nullslast() is typicallyinvoked from the column expression itself usingColumnElement.nullslast(), rather than as its standalonefunction version, as in:

  1. stmt = select([users_table]). order_by(users_table.c.name.desc().nullslast())

See also

asc()

desc()

nullsfirst()

Select.order_by()

E.g.:

  1. from sqlalchemy import or_
  2.  
  3. stmt = select([users_table]).where(
  4. or_(
  5. users_table.c.name == 'wendy',
  6. users_table.c.name == 'jack'
  7. )
  8. )

The or_() conjunction is also available using thePython | operator (though note that compound expressionsneed to be parenthesized in order to function with Pythonoperator precedence behavior):

  1. stmt = select([users_table]).where(
  2. (users_table.c.name == 'wendy') |
  3. (users_table.c.name == 'jack')
  4. )

See also

and_()

  • 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 theResultProxy object via its out_parametersattribute, 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 usingthe FunctionElement.over() method, e.g.:

  1. func.row_number().over(order_by=mytable.c.some_column)

Would produce:

  1. ROW_NUMBER() OVER(ORDER BY some_column)

Ranges are also possible using the expression.over.range_and expression.over.rows parameters. Thesemutually-exclusive parameters each accept a 2-tuple, which containsa combination of integers and None:

  1. func.row_number().over(
  2. order_by=my_table.c.some_column, range_=(None, 0))

The above would produce:

  1. ROW_NUMBER() OVER(ORDER BY some_column
  2. RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW)

A value of None indicates “unbounded”, avalue of zero indicates “current row”, and negative / positiveintegers indicate “preceding” and “following”:

  • RANGE BETWEEN 5 PRECEDING AND 10 FOLLOWING:
  1. func.row_number().over(order_by='x', range_=(-5, 10))
  • ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW:
  1. func.row_number().over(order_by='x', rows=(None, 0))
  • RANGE BETWEEN 2 PRECEDING AND UNBOUNDED FOLLOWING:
  1. func.row_number().over(order_by='x', range_=(-2, None))
  • RANGE BETWEEN 1 FOLLOWING AND 3 FOLLOWING:
  1. func.row_number().over(order_by='x', range_=(1, 3))

New in version 1.1: support for RANGE / ROWS within a window

  • Parameters
    • element – a FunctionElement, WithinGroup,or other compatible construct.

    • partition_by – a column element or string, or a listof such, that will be used as the PARTITION BY clauseof the OVER construct.

    • order_by – a column element or string, or a listof such, that will be used as the ORDER BY clauseof the OVER construct.

    • range_

optional range clause for the window. This is atuple value which can contain integer values or None, and willrender a RANGE BETWEEN PRECEDING / FOLLOWING clause

New in version 1.1.

  1. -

rows

optional rows clause for the window. This is a tuplevalue which can contain integer values or None, and will rendera ROWS BETWEEN PRECEDING / FOLLOWING clause.

New in version 1.1.

This function is also available from the funcconstruct itself via the FunctionElement.over() method.

See also

expression.func

expression.within_group()

  • sqlalchemy.sql.expression.text(text, bind=None, bindparams=None, typemap=None, autocommit=None)
  • Construct a new TextClause clause, representinga textual SQL string directly.

E.g.:

  1. from sqlalchemy import text
  2.  
  3. t = text("SELECT * FROM users")
  4. result = connection.execute(t)

The advantages text() provides over a plain string arebackend-neutral support for bind parameters, per-statementexecution options, as well asbind parameter and result-column typing behavior, allowingSQLAlchemy type constructs to play a role when executinga statement that is specified literally. The construct can alsobe provided with a .c collection of column elements, allowingit to be embedded in other SQL expression constructs as a subquery.

Bind parameters are specified by name, using the format :name.E.g.:

  1. t = text("SELECT * FROM users WHERE id=:user_id")
  2. result = connection.execute(t, user_id=12)

For SQL statements where a colon is required verbatim, as withinan inline string, use a backslash to escape:

  1. t = text("SELECT * FROM users WHERE name='\:username'")

The TextClause construct includes methods which canprovide information about the bound parameters as well as the columnvalues which would be returned from the textual statement, assumingit’s an executable SELECT type of statement. TheTextClause.bindparams() method is used to provide boundparameter detail, and TextClause.columns() method allowsspecification of return columns including names and types:

  1. t = text("SELECT * FROM users WHERE id=:user_id").\
  2. bindparams(user_id=7).\
  3. columns(id=Integer, name=String)
  4.  
  5. for id, name in connection.execute(t):
  6. print(id, name)

The text() construct is used in cases whena literal string SQL fragment is specified as part of a larger query,such as for the WHERE clause of a SELECT statement:

  1. s = select([users.c.id, users.c.name]).where(text("id=:user_id"))
  2. result = connection.execute(s, user_id=12)

text() is also used for the constructionof a full, standalone statement using plain text.As such, SQLAlchemy refersto it as an Executable object, and it supportsthe Executable.execution_options() method. For example,a text() construct that should be subject to “autocommit”can be set explicitly so using theConnection.execution_options.autocommit option:

  1. t = text("EXEC my_procedural_thing()").\
  2. execution_options(autocommit=True)

Note that SQLAlchemy’s usual “autocommit” behavior applies totext() constructs implicitly - that is, statements which beginwith a phrase such as INSERT, UPDATE, DELETE,or a variety of other phrases specific to certain backends, willbe eligible for autocommit if no transaction is in progress.

  • Parameters
    • text

the text of the SQL statement to be created. use :<param>to specify bind parameters; they will be compiled to theirengine-specific format.

Warning

The text.text argument to text() can be passed as a Python string argument, which will be treated as trusted SQL text and rendered as given. DO NOT PASS UNTRUSTED INPUT TO THIS PARAMETER.

  1. -

autocommit

whether or not to set the “autocommit” executionoption for this TextClause object.

Deprecated since version 0.6: The text.autocommit parameter is deprecated and will be removed in a future release. Please use the Connection.execution_options.autocommit parameter in conjunction with the Executable.execution_options() method.

  1. -

bind – an optional connection or engine to be used for this text query.

  1. -

bindparams

A list of bindparam() instances used toprovide information about parameters embedded in the statement.

Deprecated since version 0.9: The text.bindparams parameter is deprecated and will be removed in a future release. Please refer to the TextClause.bindparams() method.

E.g.:

  1. stmt = text("SELECT * FROM table WHERE id=:id",
  2. bindparams=[bindparam('id', value=5, type_=Integer)])
  1. -

typemap

A dictionary mapping the names of columns represented in the columnsclause of a SELECT statement to type objects.

Deprecated since version 0.9: The text.typemap parameter is deprecated and will be removed in a future release. Please refer to the TextClause.columns() method.

E.g.:

  1. stmt = text("SELECT * FROM table",
  2. typemap={'id': Integer, 'name': String},
  3. )

See also

Using Textual SQL - in the Core tutorial

Using Textual SQL - in the ORM tutorial

  • sqlalchemy.sql.expression.true()
  • Return a constant True_ construct.

E.g.:

  1. >>> from sqlalchemy import true
  2. >>> print select([t.c.x]).where(true())
  3. SELECT x FROM t WHERE true

A backend which does not support true/false constants will render asan expression against 1 or 0:

  1. >>> print select([t.c.x]).where(true())
  2. SELECT x FROM t WHERE 1 = 1

The true() and false() constants also feature“short circuit” operation within an and_() or or_()conjunction:

  1. >>> print select([t.c.x]).where(or_(t.c.x > 5, true()))
  2. SELECT x FROM t WHERE true
  3.  
  4. >>> print select([t.c.x]).where(and_(t.c.x > 5, false()))
  5. SELECT x FROM t WHERE false

Changed in version 0.9: true() and false() featurebetter integrated behavior within conjunctions and on dialectsthat don’t support true/false constants.

See also

false()

Main usage is to produce a composite IN construct usingColumnOperators.in_()

  1. from sqlalchemy import tuple_
  2.  
  3. tuple_(table.c.col1, table.c.col2).in_(
  4. [(1, 2), (5, 12), (10, 19)]
  5. )

Changed in version 1.3.6: Added support for SQLite IN tuples.

Warning

The composite IN construct is not supported by all backends, and iscurrently known to work on PostgreSQL, MySQL, and SQLite.Unsupported backends will raise a subclass ofDBAPIError when such an expression isinvoked.

  • sqlalchemy.sql.expression.typecoerce(_expression, type_)
  • Associate a SQL expression with a particular type, without renderingCAST.

E.g.:

  1. from sqlalchemy import type_coerce
  2.  
  3. stmt = select([
  4. type_coerce(log_table.date_string, StringDateTime())
  5. ])

The above construct will produce a TypeCoerce object, whichrenders SQL that labels the expression, but otherwise does notmodify its value on the SQL side:

  1. SELECT date_string AS anon_1 FROM log

When result rows are fetched, the StringDateTime typewill be applied to result rows on behalf of the date_string column.The rationale for the “anon_1” label is so that the type-coercedcolumn remains separate in the list of result columns vs. othertype-coerced or direct values of the target column. In order toprovide a named label for the expression, useColumnElement.label():

  1. stmt = select([
  2. type_coerce(
  3. log_table.date_string, StringDateTime()).label('date')
  4. ])

A type that features bound-value handling will also have that behaviortake effect when literal values or bindparam() constructs arepassed to type_coerce() as targets.For example, if a type implements theTypeEngine.bind_expression()method or TypeEngine.bind_processor() method or equivalent,these functions will take effect at statement compilation/executiontime when a literal value is passed, as in:

  1. # bound-value handling of MyStringType will be applied to the
  2. # literal value "some string"
  3. 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 resultingstatement.

  • Parameters
    • expression – A SQL expression, such as a ColumnElementexpression or a Python string which will be coerced into a boundliteral value.

    • type_ – A TypeEngine class or instance indicatingthe type to which the expression is coerced.

See also

Data Casts and Type Coercion

cast()

  • sqlalchemy.sql.expression.withingroup(_element, *order_by)
  • Produce a WithinGroup object against a function.

Used against so-called “ordered set aggregate” and “hypotheticalset aggregate” functions, including percentile_cont,rank, dense_rank, etc.

within_group() is usually called usingthe FunctionElement.within_group() method, e.g.:

  1. from sqlalchemy import within_group
  2. stmt = select([
  3. department.c.id,
  4. func.percentile_cont(0.5).within_group(
  5. department.c.salary.desc()
  6. )
  7. ])

The above statement would produce SQL similar toSELECT department.id, percentile_cont(0.5)WITHIN GROUP (ORDER BY department.salary DESC).

  • Parameters
    • element – a FunctionElement construct, typicallygenerated by func.

    • *order_by – one or more column elements that will be usedas the ORDER BY clause of the WITHIN GROUP construct.

New in version 1.1.

See also

expression.func

expression.over()

Represent an expression that is LEFT <operator> RIGHT.

A BinaryExpression is generated automaticallywhenever two column expressions are used in a Python binary expression:

  1. >>> from sqlalchemy.sql import column
  2. >>> column('a') + column('b')
  3. <sqlalchemy.sql.expression.BinaryExpression object at 0x101029dd0>
  4. >>> print column('a') + column('b')
  5. a + b

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-level).

  • selfgroup(_against=None)
  • Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a“grouping” construct, i.e. parenthesis. In particularit’s used by “binary” expressions to provide a groupingaround themselves when placed into a larger expression,as well as by select() constructs when placed intothe FROM clause of another select(). (Note thatsubqueries should be normally created using theSelect.alias() method, as many platforms requirenested SELECT statements to be named).

As expressions are composed together, the application ofself_group() is automatic - end-user code should neverneed to use this method directly. Note that SQLAlchemy’sclause constructs take operator precedence into account -so parenthesis might not be needed, for example, inan expression like x OR (y AND z) - AND takes precedenceover OR.

The base self_group() method of ClauseElementjust returns self.

  • class 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, comparedto_operator=None, comparedto_type=None)
  • Bases: sqlalchemy.sql.expression.ColumnElement

Represent a “bound expression”.

BindParameter is invoked explicitly using thebindparam() function, as in:

  1. from sqlalchemy import bindparam
  2.  
  3. stmt = select([users_table]).\
  4. where(users_table.c.name == bindparam('username'))

Detailed discussion of how BindParameter is used isat bindparam().

See also

bindparam()

  • init(key, value=symbol('NO_ARG'), type=None, _unique=False, required=symbol('NO_ARG'), quote=None, callable=None, _expanding=False, isoutparam=False, comparedto_operator=None, comparedto_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 givenclause.

  • property effective_value

  • Return the value of this bound parameter,taking into account if the callable parameterwas set.

The callable value will be evaluatedand returned if present, else value.

Represent a CASE expression.

Case is produced using the case() factory function,as in:

  1. from sqlalchemy import case
  2.  
  3. stmt = select([users_table]). where(
  4. case(
  5. [
  6. (users_table.c.name == 'wendy', 'W'),
  7. (users_table.c.name == 'jack', 'J')
  8. ],
  9. else_='E'
  10. )
  11. )

Details on Case usage is at case().

See also

case()

This constructor is mirrored as a public API function; see case() for a full usage and argument description.

  • getchildren(**kwargs_)
  • Return immediate child elements of this ClauseElement.

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-level).

Represent a CAST expression.

Cast is produced using the cast() factory function,as in:

  1. from sqlalchemy import cast, Numeric
  2.  
  3. stmt = select([
  4. cast(product_table.c.unit_price, Numeric(10, 4))
  5. ])

Details on Cast usage is at cast().

See also

Data Casts and Type Coercion

cast()

type_coerce() - an alternative to CAST that coerces the typeon the Python side only, which is often sufficient to generate thecorrect SQL and data coercion.

This constructor is mirrored as a public API function; see cast() for a full usage and argument description.

  • getchildren(**kwargs_)
  • Return immediate child elements of this ClauseElement.

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-level).

Base class for elements of a programmatically constructed SQLexpression.

  • compare(other, **kw)
  • Compare this ClauseElement to the given ClauseElement.

Subclasses should override the default behavior, which is astraight identity comparison.

**kw are arguments consumed by subclass compare() methods andmay 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 astring representation of the result. TheCompiled object also can return adictionary of bind parameter names and valuesusing the params accessor.

  1. - Parameters
  2. -
  3. -

bind – An Engine or Connection from which aCompiled will be acquired. This argument takes precedence overthis ClauseElement’s bound engine, if any.

  1. -

column_keys – Used for INSERT and UPDATE statements, a list ofcolumn names which should be present in the VALUES clause of thecompiled statement. If None, all columns from the target tableobject are rendered.

  1. -

dialect – A Dialect instance from which a Compiledwill be acquired. This argument takes precedence over the _bind_argument as well as this ClauseElement’s bound engine,if any.

  1. -

inline – Used for INSERT statements, for a dialect which doesnot support inline retrieval of newly generated primary keycolumns, will force the expression used to create the new primarykey value to be rendered inline within the INSERT statement’sVALUES clause. This typically refers to Sequence execution but mayalso refer to any server-side default generation functionassociated with a primary key Column.

  1. -

compile_kwargs

optional dictionary of additional parametersthat will be passed through to the compiler within all “visit”methods. This allows any custom flag to be passed through toa custom compilation construct, for example. It is also usedfor the case of passing the literal_binds flag through:

  1. from sqlalchemy.sql import table, column, select
  2.  
  3. t = table('t', column('x'))
  4.  
  5. s = select([t]).where(t.c.x == 5)
  6.  
  7. print s.compile(compile_kwargs={"literal_binds": True})

New in version 0.9.0.

See also

How do I render SQL expressions as strings, possibly with bound parameters inlined?

  • getchildren(**kwargs_)
  • Return immediate child elements of this ClauseElement.

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-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:

  1. >>> clause = column('x') + bindparam('foo')
  2. >>> print clause.compile().params
  3. {'foo':None}
  4. >>> print clause.params({'foo':7}).compile().params
  5. {'foo':7}
  • selfgroup(_against=None)
  • Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a“grouping” construct, i.e. parenthesis. In particularit’s used by “binary” expressions to provide a groupingaround themselves when placed into a larger expression,as well as by select() constructs when placed intothe FROM clause of another select(). (Note thatsubqueries should be normally created using theSelect.alias() method, as many platforms requirenested SELECT statements to be named).

As expressions are composed together, the application ofself_group() is automatic - end-user code should neverneed to use this method directly. Note that SQLAlchemy’sclause constructs take operator precedence into account -so parenthesis might not be needed, for example, inan expression like x OR (y AND z) - AND takes precedenceover OR.

The base self_group() method of ClauseElementjust returns self.

  • uniqueparams(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 beused.

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.

  • getchildren(**kwargs_)

  • Return immediate child elements of this ClauseElement.

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-level).

  • selfgroup(_against=None)
  • Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a“grouping” construct, i.e. parenthesis. In particularit’s used by “binary” expressions to provide a groupingaround themselves when placed into a larger expression,as well as by select() constructs when placed intothe FROM clause of another select(). (Note thatsubqueries should be normally created using theSelect.alias() method, as many platforms requirenested SELECT statements to be named).

As expressions are composed together, the application ofself_group() is automatic - end-user code should neverneed to use this method directly. Note that SQLAlchemy’sclause constructs take operator precedence into account -so parenthesis might not be needed, for example, inan expression like x OR (y AND z) - AND takes precedenceover OR.

The base self_group() method of ClauseElementjust returns self.

Represents a column expression from any textual string.

The ColumnClause, a lightweight analogue to theColumn class, is typically invoked using thecolumn() function, as in:

  1. from sqlalchemy import column
  2.  
  3. id, name = column("id"), column("name")
  4. stmt = select([id, name]).select_from("user")

The above statement would produce SQL like:

  1. SELECT id, name FROM user

ColumnClause is the immediate superclass of the schema-specificColumn object. While the Column class has all thesame capabilities as ColumnClause, the ColumnClauseclass is usable by itself in those cases where behavioral requirementsare limited to simple SQL expression generation. The object has none ofthe associations with schema-level metadata or with execution-timebehavior that Column does, so in that sense is a “lightweight”version of Column.

Full details on ColumnClause usage is at column().

See also

column()

Column

This constructor is mirrored as a public API function; see column() for a full usage and argument description.

  • class sqlalchemy.sql.expression.ColumnCollection(*columns)
  • Bases: sqlalchemy.util._collections.OrderedProperties

An ordered dictionary that stores a list of ColumnElementinstances.

Overrides the eq() method to produce SQL clauses betweensets of correlated columns.

  • add(column)
  • Add a column to this collection.

The key attribute of the column will be used as the hash keyfor this dictionary.

  • as_immutable()
  • Return an immutable proxy for this Properties.

  • replace(column)

  • add the given column to this collection, removing unaliasedversions of this column as well as existing columns with thesame key.

e.g.:

  1. t = Table('sometable', metadata, Column('col1', Integer))t.columns.replace(Column('col1', Integer, key='columnone'))

will remove the original ‘col1’ from the collection, and addthe new column under the name ‘columnname’.

Used by schema.Column to override columns during table reflection.

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 theColumn object, ColumnElement serves as the basisfor any unit that may be present in a SQL expression, includingthe 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 expressionlevel, and are intended to accept instances of ColumnElement asarguments. These functions will typically document that they accept a“SQL expression” as an argument. What this means in terms of SQLAlchemyusually refers to an input which is either already in the form of aColumnElement object, or a value which can be coerced intoone. The coercion rules followed by most, but not all, SQLAlchemy Corefunctions with regards to SQL expressions are as follows:

  • a literal Python value, such as a string, integer or floatingpoint value, boolean, datetime, Decimal object, or virtuallyany other Python object, will be coerced into a “literal boundvalue”. This generally means that a bindparam() will beproduced featuring the given value embedded into the construct; theresulting BindParameter object is an instance ofColumnElement. The Python value will ultimately be sentto the DBAPI at execution time as a parameterized argument to theexecute() or executemany() methods, after SQLAlchemytype-specific converters (e.g. those provided by any associatedTypeEngine objects) are applied to the value.

  • any special object value, typically ORM-level constructs, whichfeature a method called clause_element(). The Coreexpression system looks for this method when an object of otherwiseunknown type is passed to a function that is looking to coerce theargument into a ColumnElement expression. Theclause_element() method, if present, should return aColumnElement instance. The primary use ofclause_element() within SQLAlchemy is that of class-boundattributes on ORM-mapped classes; a User class which contains amapped attribute named .name will have a methodUser.name.clause_element() which when invoked returns theColumn called name associated with the mapped table.

  • The Python None value is typically interpreted as NULL,which in SQLAlchemy Core produces an instance of null().

A ColumnElement provides the ability to generate newColumnElementobjects using Python expressions. This means that Python operatorssuch as ==, != and < are overloaded to mimic SQL operations,and allow the instantiation of further ColumnElement instanceswhich are composed from other, more fundamental ColumnElementobjects. For example, two ColumnClause objects can be addedtogether with the addition operator + to producea BinaryExpression.Both ColumnClause and BinaryExpression are subclassesof ColumnElement:

  1. >>> from sqlalchemy.sql import column
  2. >>> column('a') + column('b')
  3. <sqlalchemy.sql.expression.BinaryExpression object at 0x101029dd0>
  4. >>> print column('a') + column('b')
  5. a + b

See also

Column

expression.column()

  • eq(other)

inherited from theeq()method ofColumnOperators

Implement the == operator.

In a column context, produces the clause a = b.If the target is None, produces a IS NULL.

  • init()

inherited from the init() method of object

Initialize self. See help(type(self)) for accurate signature.

  • le(other)

inherited from thele()method ofColumnOperators

Implement the <= operator.

In a column context, produces the clause a <= b.

  • lt(other)

inherited from thelt()method ofColumnOperators

Implement the < operator.

In a column context, produces the clause a < b.

  • ne(other)

inherited from thene()method ofColumnOperators

Implement the != operator.

In a column context, produces the clause a != b.If the target is None, produces a IS NOT NULL.

inherited from theall_()method ofColumnOperators

Produce a all_() clause against theparent object.

This operator is only appropriate against a scalar subqueryobject, or for some backends an column expression that isagainst the ARRAY type, e.g.:

  1. # postgresql '5 = ALL (somearray)'
  2. expr = 5 == mytable.c.somearray.all_()
  3.  
  4. # mysql '5 = ALL (SELECT value FROM table)'
  5. expr = 5 == select([table.c.value]).as_scalar().all_()

See also

all_() - standalone version

any_() - ANY operator

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 sothat expressions can reference anon_label multiple times, producingthe same label name at compile time.

the compiler uses this function automatically at compile timefor expressions that are known to be ‘unnamed’ like binaryexpressions and function calls.

inherited from theany_()method ofColumnOperators

Produce a any_() clause against theparent object.

This operator is only appropriate against a scalar subqueryobject, or for some backends an column expression that isagainst the ARRAY type, e.g.:

  1. # postgresql '5 = ANY (somearray)'
  2. expr = 5 == mytable.c.somearray.any_()
  3.  
  4. # mysql '5 = ANY (SELECT value FROM table)'
  5. expr = 5 == select([table.c.value]).as_scalar().any_()

See also

any_() - standalone version

all_() - ALL operator

New in version 1.1.

  • asc()

inherited from theasc()method ofColumnOperators

Produce a asc() clause against theparent object.

  • base_columns
  • between(cleft, cright, symmetric=False)

inherited from thebetween()method ofColumnOperators

Produce a between() clause againstthe parent object, given the lower and upper range.

  • bind = None
  • boolop(_opstring, precedence=0)

inherited from thebool_op()method ofOperators

Return a custom boolean operator.

This method is shorthand for callingOperators.op() and passing theOperators.op.is_comparisonflag with True.

New in version 1.2.0b3.

See also

Operators.op()

  • cast(type_)
  • Produce a type cast, i.e. CAST(<expression> AS <type>).

This is a shortcut to the cast() function.

See also

Data Casts and Type Coercion

cast()

type_coerce()

New in version 1.0.7.

  • collate(collation)

inherited from thecollate()method ofColumnOperators

Produce a collate() clause againstthe parent object, given the collation string.

See also

collate()

  • comparator
  • compare(other, use_proxies=False, equivalents=None, **kw)
  • Compare this ColumnElement to another.

Special arguments understood:

  1. - Parameters
  2. -
  3. -

use_proxies – when True, consider two columns thatshare a common base column as equivalent (i.e. shares_lineage())

  1. -

equivalents – a dictionary of columns as keys mapped to setsof columns. If the given “other” column is present in thisdictionary, if any of the columns in the corresponding set() passthe comparison test, the result is True. This is used to expand thecomparison to other columns that may be known to be equivalent tothis one via foreign key or other criterion.

  • compile(default, bind=None, dialect=None, **kw)

inherited from thecompile()method ofClauseElement

Compile this SQL expression.

The return value is a Compiled object.Calling str() or unicode() on the returned value will yield astring representation of the result. TheCompiled object also can return adictionary of bind parameter names and valuesusing the params accessor.

  1. - Parameters
  2. -
  3. -

bind – An Engine or Connection from which aCompiled will be acquired. This argument takes precedence overthis ClauseElement’s bound engine, if any.

  1. -

column_keys – Used for INSERT and UPDATE statements, a list ofcolumn names which should be present in the VALUES clause of thecompiled statement. If None, all columns from the target tableobject are rendered.

  1. -

dialect – A Dialect instance from which a Compiledwill be acquired. This argument takes precedence over the _bind_argument as well as this ClauseElement’s bound engine,if any.

  1. -

inline – Used for INSERT statements, for a dialect which doesnot support inline retrieval of newly generated primary keycolumns, will force the expression used to create the new primarykey value to be rendered inline within the INSERT statement’sVALUES clause. This typically refers to Sequence execution but mayalso refer to any server-side default generation functionassociated with a primary key Column.

  1. -

compile_kwargs

optional dictionary of additional parametersthat will be passed through to the compiler within all “visit”methods. This allows any custom flag to be passed through toa custom compilation construct, for example. It is also usedfor the case of passing the literal_binds flag through:

  1. from sqlalchemy.sql import table, column, select
  2.  
  3. t = table('t', column('x'))
  4.  
  5. s = select([t]).where(t.c.x == 5)
  6.  
  7. print s.compile(compile_kwargs={"literal_binds": True})

New in version 0.9.0.

See also

How do I render SQL expressions as strings, possibly with bound parameters inlined?

  • concat(other)

inherited from theconcat()method ofColumnOperators

Implement the ‘concat’ operator.

In a column context, produces the clause a || b,or uses the concat() operator on MySQL.

  • contains(other, **kwargs)

inherited from thecontains()method ofColumnOperators

Implement the ‘contains’ operator.

Produces a LIKE expression that tests against a match for the middleof a string value:

  1. column LIKE '%' || <other> || '%'

E.g.:

  1. stmt = select([sometable]).\
  2. where(sometable.c.column.contains("foobar"))

Since the operator uses LIKE, wildcard characters"%" and "_" that are present inside the expressionwill behave like wildcards as well. For literal stringvalues, the ColumnOperators.contains.autoescape flagmay be set to True to apply escaping to occurrences of thesecharacters within the string value so that they match as themselvesand not as wildcard characters. Alternatively, theColumnOperators.contains.escape parameter will establisha given character as an escape character which can be of use whenthe target expression is not a literal string.

  1. - Parameters
  2. -
  3. -

other – expression to be compared. This is usually a plainstring value, but can also be an arbitrary SQL expression. LIKEwildcard characters % and _ are not escaped by default unlessthe ColumnOperators.contains.autoescape flag isset to True.

  1. -

autoescape

boolean; when True, establishes an escape characterwithin the LIKE expression, then applies it to all occurrences of"%", "_" and the escape character itself within thecomparison value, which is assumed to be a literal string and not aSQL expression.

An expression such as:

  1. somecolumn.contains("foo%bar", autoescape=True)

Will render as:

  1. somecolumn LIKE '%' || :param || '%' ESCAPE '/'

With the value of :param as "foo/%bar".

New in version 1.2.

Changed in version 1.2.0: TheColumnOperators.contains.autoescape parameter is now a simple boolean rather than a character; the escape character itself is also escaped, and defaults to a forwards slash, which itself can be customized using the ColumnOperators.contains.escape parameter.

  1. -

escape

a character which when given will render with theESCAPE keyword to establish that character as the escapecharacter. This character can then be placed preceding occurrencesof % and _ to allow them to act as themselves and notwildcard characters.

An expression such as:

  1. somecolumn.contains("foo/%bar", escape="^")

Will render as:

  1. somecolumn LIKE '%' || :param || '%' ESCAPE '^'

The parameter may also be combined withColumnOperators.contains.autoescape:

  1. somecolumn.contains("foo%bar^bat", escape="^", autoescape=True)

Where above, the given literal parameter will be converted to"foo^%bar^^bat" before being passed to the database.

See also

ColumnOperators.startswith()

ColumnOperators.endswith()

ColumnOperators.like()

  • desc()

inherited from thedesc()method ofColumnOperators

Produce a desc() clause against theparent object.

  • description = None
  • distinct()

inherited from thedistinct()method ofColumnOperators

Produce a distinct() clause against theparent object.

  • endswith(other, **kwargs)

inherited from theendswith()method ofColumnOperators

Implement the ‘endswith’ operator.

Produces a LIKE expression that tests against a match for the endof a string value:

  1. column LIKE '%' || <other>

E.g.:

  1. stmt = select([sometable]).\
  2. where(sometable.c.column.endswith("foobar"))

Since the operator uses LIKE, wildcard characters"%" and "_" that are present inside the expressionwill behave like wildcards as well. For literal stringvalues, the ColumnOperators.endswith.autoescape flagmay be set to True to apply escaping to occurrences of thesecharacters within the string value so that they match as themselvesand not as wildcard characters. Alternatively, theColumnOperators.endswith.escape parameter will establisha given character as an escape character which can be of use whenthe target expression is not a literal string.

  1. - Parameters
  2. -
  3. -

other – expression to be compared. This is usually a plainstring value, but can also be an arbitrary SQL expression. LIKEwildcard characters % and _ are not escaped by default unlessthe ColumnOperators.endswith.autoescape flag isset to True.

  1. -

autoescape

boolean; when True, establishes an escape characterwithin the LIKE expression, then applies it to all occurrences of"%", "_" and the escape character itself within thecomparison value, which is assumed to be a literal string and not aSQL expression.

An expression such as:

  1. somecolumn.endswith("foo%bar", autoescape=True)

Will render as:

  1. somecolumn LIKE '%' || :param ESCAPE '/'

With the value of :param as "foo/%bar".

New in version 1.2.

Changed in version 1.2.0: TheColumnOperators.endswith.autoescape parameter is now a simple boolean rather than a character; the escape character itself is also escaped, and defaults to a forwards slash, which itself can be customized using the ColumnOperators.endswith.escape parameter.

  1. -

escape

a character which when given will render with theESCAPE keyword to establish that character as the escapecharacter. This character can then be placed preceding occurrencesof % and _ to allow them to act as themselves and notwildcard characters.

An expression such as:

  1. somecolumn.endswith("foo/%bar", escape="^")

Will render as:

  1. somecolumn LIKE '%' || :param ESCAPE '^'

The parameter may also be combined withColumnOperators.endswith.autoescape:

  1. somecolumn.endswith("foo%bar^bat", escape="^", autoescape=True)

Where above, the given literal parameter will be converted to"foo^%bar^^bat" before being passed to the database.

See also

ColumnOperators.startswith()

ColumnOperators.contains()

ColumnOperators.like()

  • property expression
  • Return a column expression.

Part of the inspection interface; returns self.

  • foreignkeys = []_
  • getchildren(**kwargs_)

inherited from theget_children()method ofClauseElement

Return immediate child elements of this ClauseElement.

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-level).

  • ilike(other, escape=None)

inherited from theilike()method ofColumnOperators

Implement the ilike operator, e.g. case insensitive LIKE.

In a column context, produces an expression either of the form:

  1. lower(a) LIKE lower(other)

Or on backends that support the ILIKE operator:

  1. a ILIKE other

E.g.:

  1. stmt = select([sometable]).\
  2. where(sometable.c.column.ilike("%foobar%"))
  1. - Parameters
  2. -
  3. -

other – expression to be compared

  1. -

escape

optional escape character, renders the ESCAPEkeyword, e.g.:

  1. somecolumn.ilike("foo/%bar", escape="/")

See also

ColumnOperators.like()

  • in(_other)

inherited from thein_()method ofColumnOperators

Implement the in operator.

In a column context, produces the clause column IN <other>.

The given parameter other may be:

  1. -

A list of literal values, e.g.:

  1. stmt.where(column.in_([1, 2, 3]))

In this calling form, the list of items is converted to a set ofbound parameters the same length as the list given:

  1. WHERE COL IN (?, ?, ?)
  1. -

A list of tuples may be provided if the comparison is against atuple_() containing multiple expressions:

  1. from sqlalchemy import tuple_
  2. stmt.where(tuple_(col1, col2).in_([(1, 10), (2, 20), (3, 30)]))
  1. -

An empty list, e.g.:

  1. stmt.where(column.in_([]))

In this calling form, the expression renders a “false” expression,e.g.:

  1. WHERE 1 != 1

This “false” expression has historically had different behaviorsin older SQLAlchemy versions, seecreate_engine.empty_in_strategy for behavioral options.

Changed in version 1.2: simplified the behavior of “empty in”expressions

  1. -

A bound parameter, e.g. bindparam(), may be used if itincludes the bindparam.expanding flag:

  1. stmt.where(column.in_(bindparam('value', expanding=True)))

In this calling form, the expression renders a special non-SQLplaceholder expression that looks like:

  1. WHERE COL IN ([EXPANDING_value])

This placeholder expression is intercepted at statement executiontime to be converted into the variable number of bound parameterform illustrated earlier. If the statement were executed as:

  1. connection.execute(stmt, {"value": [1, 2, 3]})

The database would be passed a bound parameter for each value:

  1. 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. OnSQLite this would be:

  1. WHERE COL IN (SELECT 1 FROM (SELECT 1) WHERE 1!=1)

New in version 1.3: “expanding” bound parameters now supportempty lists

  1. -

a select() construct, which is usually a correlatedscalar select:

  1. stmt.where(
  2. column.in_(
  3. select([othertable.c.y]).
  4. where(table.c.x == othertable.c.x)
  5. )
  6. )

In this calling form, ColumnOperators.in_() renders as given:

  1. WHERE COL IN (SELECT othertable.y
  2. FROM othertable WHERE othertable.x = table.x)
  1. - Parameters
  2. -

other – a list of literals, a select() construct,or a bindparam() construct that includes thebindparam.expanding flag set to True.

  • is(_other)

inherited from theis_()method ofColumnOperators

Implement the IS operator.

Normally, IS is generated automatically when comparing to avalue of None, which resolves to NULL. However, explicitusage of IS may be desirable if comparing to boolean valueson certain platforms.

See also

ColumnOperators.isnot()

  • isclause_element = True_
  • isdistinct_from(_other)

inherited from theis_distinct_from()method ofColumnOperators

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.

  • isselectable = False_
  • isnot(other)

inherited from theisnot()method ofColumnOperators

Implement the IS NOT operator.

Normally, IS NOT is generated automatically when comparing to avalue of None, which resolves to NULL. However, explicitusage of IS NOT may be desirable if comparing to boolean valueson certain platforms.

See also

ColumnOperators.is_()

  • isnotdistinct_from(_other)

inherited from theisnot_distinct_from()method ofColumnOperators

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 aPython namespace.

This typically refers to the “key” of the column as present in the.c collection of a selectable, e.g. sometable.c[“somekey”] wouldreturn 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)

inherited from thelike()method ofColumnOperators

Implement the like operator.

In a column context, produces the expression:

  1. a LIKE other

E.g.:

  1. stmt = select([sometable]).\
  2. where(sometable.c.column.like("%foobar%"))
  1. - Parameters
  2. -
  3. -

other – expression to be compared

  1. -

escape

optional escape character, renders the ESCAPEkeyword, e.g.:

  1. somecolumn.like("foo/%bar", escape="/")

See also

ColumnOperators.ilike()

  • match(other, **kwargs)

inherited from thematch()method ofColumnOperators

Implements a database-specific ‘match’ operator.

match() attempts to resolve toa MATCH-like function or operator provided by the backend.Examples include:

  1. -

PostgreSQL - renders x @@ to_tsquery(y)

  1. -

MySQL - renders MATCH (x) AGAINST (y IN BOOLEAN MODE)

  1. -

Oracle - renders CONTAINS(x, y)

  1. -

other backends may provide special implementations.

  1. -

Backends without any special implementation will emitthe operator as “MATCH”. This is compatible with SQLite, forexample.

  • notilike(other, escape=None)

inherited from thenotilike()method ofColumnOperators

implement the NOT ILIKE operator.

This is equivalent to using negation withColumnOperators.ilike(), i.e. ~x.ilike(y).

See also

ColumnOperators.ilike()

  • notin(_other)

inherited from thenotin_()method ofColumnOperators

implement the NOT IN operator.

This is equivalent to using negation withColumnOperators.in_(), i.e. ~x.in_(y).

In the case that other is an empty sequence, the compilerproduces an “empty not in” expression. This defaults to theexpression “1 = 1” to produce true in all cases. Thecreate_engine.empty_in_strategy may be used toalter this behavior.

Changed in version 1.2: The ColumnOperators.in_() andColumnOperators.notin_() operatorsnow produce a “static” expression for an empty IN sequenceby default.

See also

ColumnOperators.in_()

  • notlike(other, escape=None)

inherited from thenotlike()method ofColumnOperators

implement the NOT LIKE operator.

This is equivalent to using negation withColumnOperators.like(), i.e. ~x.like(y).

See also

ColumnOperators.like()

  • nullsfirst()

inherited from thenullsfirst()method ofColumnOperators

Produce a nullsfirst() clause against theparent object.

  • nullslast()

inherited from thenullslast()method ofColumnOperators

Produce a nullslast() clause against theparent object.

  • op(opstring, precedence=0, is_comparison=False, return_type=None)

inherited from theop()method ofOperators

produce a generic operator function.

e.g.:

  1. somecolumn.op("*")(5)

produces:

  1. somecolumn * 5

This function can also be used to make bitwise operators explicit. Forexample:

  1. somecolumn.op('&')(0xff)

is a bitwise AND of the value in somecolumn.

  1. - Parameters
  2. -
  3. -

operator – a string which will be output as the infix operatorbetween this element and the expression passed to thegenerated function.

  1. -

precedence – precedence to apply to the operator, whenparenthesizing expressions. A lower number will cause the expressionto be parenthesized when applied against another operator withhigher precedence. The default value of 0 is lower than alloperators except for the comma (,) and AS operators.A value of 100 will be higher or equal to all operators, and -100will be lower than or equal to all operators.

  1. -

is_comparison

if True, the operator will be considered as a“comparison” operator, that is which evaluates to a booleantrue/false value, like ==, >, etc. This flag should be setso that ORM relationships can establish that the operator is acomparison operator when used in a custom join condition.

New in version 0.9.2: - added theOperators.op.is_comparison flag.

  1. -

return_type

a TypeEngine class or object that willforce the return type of an expression produced by this operatorto be of that type. By default, operators that specifyOperators.op.is_comparison will resolve toBoolean, and those that do not will be of the sametype as the left-hand operand.

New in version 1.2.0b3: - added theOperators.op.return_type argument.

See also

Redefining and Creating New Operators

Using custom operators in join conditions

  • operate(op, *other, **kwargs)
  • Operate on an argument.

This is the lowest level of operation, raisesNotImplementedError by default.

Overriding this on a subclass can allow commonbehavior to be applied to all operations.For example, overriding ColumnOperatorsto apply func.lower() to the left and rightside:

  1. class MyComparator(ColumnOperators):
  2. def operate(self, op, other):
  3. return op(func.lower(self), func.lower(other))
  1. - Parameters
  2. -
  3. -

op – Operator callable.

  1. -

*other – the ‘other’ side of the operation. Willbe a single scalar for most operations.

  1. -

**kwargs – modifiers. These may be passed by specialoperators such as ColumnOperators.contains().

  • params(*optionaldict, **kwargs)

inherited from theparams()method ofClauseElement

Return a copy with bindparam() elements replaced.

Returns a copy of this ClauseElement with bindparam()elements replaced with values taken from the given dictionary:

  1. >>> clause = column('x') + bindparam('foo')
  2. >>> print clause.compile().params
  3. {'foo':None}
  4. >>> print clause.params({'foo':7}).compile().params
  5. {'foo':7}
  • primarykey = False_
  • proxy_set
  • reverseoperate(_op, other, **kwargs)
  • Reverse operate on an argument.

Usage is the same as operate().

  • selfgroup(_against=None)
  • Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a“grouping” construct, i.e. parenthesis. In particularit’s used by “binary” expressions to provide a groupingaround themselves when placed into a larger expression,as well as by select() constructs when placed intothe FROM clause of another select(). (Note thatsubqueries should be normally created using theSelect.alias() method, as many platforms requirenested SELECT statements to be named).

As expressions are composed together, the application ofself_group() is automatic - end-user code should neverneed to use this method directly. Note that SQLAlchemy’sclause constructs take operator precedence into account -so parenthesis might not be needed, for example, inan expression like x OR (y AND z) - AND takes precedenceover OR.

The base self_group() method of ClauseElementjust returns self.

  • shareslineage(_othercolumn)
  • Return True if the given ColumnElementhas a common ancestor to this ColumnElement.

  • startswith(other, **kwargs)

inherited from thestartswith()method ofColumnOperators

Implement the startswith operator.

Produces a LIKE expression that tests against a match for the startof a string value:

  1. column LIKE <other> || '%'

E.g.:

  1. stmt = select([sometable]).\
  2. where(sometable.c.column.startswith("foobar"))

Since the operator uses LIKE, wildcard characters"%" and "_" that are present inside the expressionwill behave like wildcards as well. For literal stringvalues, the ColumnOperators.startswith.autoescape flagmay be set to True to apply escaping to occurrences of thesecharacters within the string value so that they match as themselvesand not as wildcard characters. Alternatively, theColumnOperators.startswith.escape parameter will establisha given character as an escape character which can be of use whenthe target expression is not a literal string.

  1. - Parameters
  2. -
  3. -

other – expression to be compared. This is usually a plainstring value, but can also be an arbitrary SQL expression. LIKEwildcard characters % and _ are not escaped by default unlessthe ColumnOperators.startswith.autoescape flag isset to True.

  1. -

autoescape

boolean; when True, establishes an escape characterwithin the LIKE expression, then applies it to all occurrences of"%", "_" and the escape character itself within thecomparison value, which is assumed to be a literal string and not aSQL expression.

An expression such as:

  1. somecolumn.startswith("foo%bar", autoescape=True)

Will render as:

  1. somecolumn LIKE :param || '%' ESCAPE '/'

With the value of :param as "foo/%bar".

New in version 1.2.

Changed in version 1.2.0: TheColumnOperators.startswith.autoescape parameter is now a simple boolean rather than a character; the escape character itself is also escaped, and defaults to a forwards slash, which itself can be customized using the ColumnOperators.startswith.escape parameter.

  1. -

escape

a character which when given will render with theESCAPE keyword to establish that character as the escapecharacter. This character can then be placed preceding occurrencesof % and _ to allow them to act as themselves and notwildcard characters.

An expression such as:

  1. somecolumn.startswith("foo/%bar", escape="^")

Will render as:

  1. somecolumn LIKE :param || '%' ESCAPE '^'

The parameter may also be combined withColumnOperators.startswith.autoescape:

  1. somecolumn.startswith("foo%bar^bat", escape="^", autoescape=True)

Where above, the given literal parameter will be converted to"foo^%bar^^bat" before being passed to the database.

See also

ColumnOperators.endswith()

ColumnOperators.contains()

ColumnOperators.like()

  • supportsexecution = False_
  • timetuple = None
  • type
  • uniqueparams(optionaldict, *kwargs_)

inherited from theunique_params()method ofClauseElement

Return a copy with bindparam() elements replaced.

Same functionality as params(), except adds _unique=True_to affected bind parameters so that multiple statements can beused.

Defines boolean, comparison, and other operators forColumnElement expressions.

By default, all methods call down tooperate() or reverse_operate(),passing in the appropriate operator function from thePython builtin operator module ora SQLAlchemy-specific operator function fromsqlalchemy.expression.operators. For examplethe eq function:

  1. def __eq__(self, other):
  2. return self.operate(operators.eq, other)

Where operators.eq is essentially:

  1. def eq(a, b):
  2. return a == b

The core column expression unit ColumnElementoverrides Operators.operate() and othersto return further ColumnElement constructs,so that the == operation above is replaced by a clauseconstruct.

See also

Redefining and Creating New Operators

TypeEngine.comparator_factory

ColumnOperators

PropComparator

  • add(other)
  • Implement the + operator.

In a column context, produces the clause a + bif 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)

inherited from theand()method ofOperators

Implement the & operator.

When used with SQL expressions, results in anAND operation, equivalent toand_(), that is:

  1. a & b

is equivalent to:

  1. from sqlalchemy import and_
  2. and_(a, b)

Care should be taken when using & regardingoperator precedence; the & operator has the highest precedence.The operands should be enclosed in parenthesis if they containfurther sub expressions:

  1. (a == 2) & (b == 4)
  • delattr()

inherited from the delattr() method of object

Implement delattr(self, name).

  • dir()

inherited from the 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()

inherited from the format() method of object

Default object formatter.

  • ge(other)
  • Implement the >= operator.

In a column context, produces the clause a >= b.

  • getattribute()

inherited from the getattribute() method of object

Return getattr(self, name).

  • getitem(index)
  • Implement the [] operator.

This can be used by some database-specific typessuch as PostgreSQL ARRAY and HSTORE.

  • gt(other)
  • Implement the > operator.

In a column context, produces the clause a > b.

  • hash()
  • Return hash(self).

  • init()

inherited from the init() method of object

Initialize self. See help(type(self)) for accurate signature.

  • init_subclass()

inherited from the init_subclass() method of object

This method is called when a class is subclassed.

The default implementation does nothing. It may beoverridden to extend subclasses.

  • invert()

inherited from theinvert()method ofOperators

Implement the ~ operator.

When used with SQL expressions, results in aNOT operation, equivalent tonot_(), that is:

  1. ~a

is equivalent to:

  1. from sqlalchemy import not_
  2. 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 providedfor 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()

inherited from the new() method of object

Create and return a new object. See help(type) for accurate signature.

  • or(other)

inherited from theor()method ofOperators

Implement the | operator.

When used with SQL expressions, results in anOR operation, equivalent toor_(), that is:

  1. a | b

is equivalent to:

  1. from sqlalchemy import or_
  2. or_(a, b)

Care should be taken when using | regardingoperator precedence; the | operator has the highest precedence.The operands should be enclosed in parenthesis if they containfurther sub expressions:

  1. (a == 2) | (b == 4)
  • radd(other)
  • Implement the + operator in reverse.

See ColumnOperators.add().

  • rdiv(other)
  • Implement the / operator in reverse.

See ColumnOperators.div().

  • reduce()

inherited from the reduce() method of object

Helper for pickle.

  • reduce_ex()

inherited from the reduce_ex() method of object

Helper for pickle.

  • repr()

inherited from the repr() method of object

Return repr(self).

  • rmod(other)
  • Implement the % operator in reverse.

See ColumnOperators.mod().

  • rmul(other)
  • Implement the * operator in reverse.

See ColumnOperators.mul().

  • rshift(other)
  • implement the >> operator.

Not used by SQLAlchemy core, this is providedfor custom operator systems which want to use>> as an extension point.

  • rsub(other)
  • Implement the - operator in reverse.

See ColumnOperators.sub().

  • rtruediv(other)
  • Implement the // operator in reverse.

See ColumnOperators.truediv().

  • setattr()

inherited from the setattr() method of object

Implement setattr(self, name, value).

  • sizeof()

inherited from the sizeof() method of object

Size of object in memory, in bytes.

  • str()

inherited from the str() method of object

Return str(self).

  • sub(other)
  • Implement the - operator.

In a column context, produces the clause a - b.

  • subclasshook()

inherited from the 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 returnsNotImplemented, the normal algorithm is used. Otherwise, itoverrides the normal algorithm (and the outcome is cached).

  • truediv(other)
  • Implement the // operator.

In a column context, produces the clause a / b.

This operator is only appropriate against a scalar subqueryobject, or for some backends an column expression that isagainst the ARRAY type, e.g.:

  1. # postgresql '5 = ALL (somearray)'
  2. expr = 5 == mytable.c.somearray.all_()
  3.  
  4. # mysql '5 = ALL (SELECT value FROM table)'
  5. expr = 5 == select([table.c.value]).as_scalar().all_()

See also

all_() - standalone version

any_() - ANY operator

New in version 1.1.

This operator is only appropriate against a scalar subqueryobject, or for some backends an column expression that isagainst the ARRAY type, e.g.:

  1. # postgresql '5 = ANY (somearray)'
  2. expr = 5 == mytable.c.somearray.any_()
  3.  
  4. # mysql '5 = ANY (SELECT value FROM table)'
  5. expr = 5 == select([table.c.value]).as_scalar().any_()

See also

any_() - standalone version

all_() - ALL operator

New in version 1.1.

  • asc()
  • Produce a asc() clause against theparent object.

  • between(cleft, cright, symmetric=False)

  • Produce a between() clause againstthe parent object, given the lower and upper range.

  • boolop(_opstring, precedence=0)

inherited from thebool_op()method ofOperators

Return a custom boolean operator.

This method is shorthand for callingOperators.op() and passing theOperators.op.is_comparisonflag with True.

New in version 1.2.0b3.

See also

Operators.op()

  • collate(collation)
  • Produce a collate() clause againstthe parent object, given the collation string.

See also

collate()

  • 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 middleof a string value:

  1. column LIKE '%' || <other> || '%'

E.g.:

  1. stmt = select([sometable]).\
  2. where(sometable.c.column.contains("foobar"))

Since the operator uses LIKE, wildcard characters"%" and "_" that are present inside the expressionwill behave like wildcards as well. For literal stringvalues, the ColumnOperators.contains.autoescape flagmay be set to True to apply escaping to occurrences of thesecharacters within the string value so that they match as themselvesand not as wildcard characters. Alternatively, theColumnOperators.contains.escape parameter will establisha given character as an escape character which can be of use whenthe target expression is not a literal string.

  1. - Parameters
  2. -
  3. -

other – expression to be compared. This is usually a plainstring value, but can also be an arbitrary SQL expression. LIKEwildcard characters % and _ are not escaped by default unlessthe ColumnOperators.contains.autoescape flag isset to True.

  1. -

autoescape

boolean; when True, establishes an escape characterwithin the LIKE expression, then applies it to all occurrences of"%", "_" and the escape character itself within thecomparison value, which is assumed to be a literal string and not aSQL expression.

An expression such as:

  1. somecolumn.contains("foo%bar", autoescape=True)

Will render as:

  1. somecolumn LIKE '%' || :param || '%' ESCAPE '/'

With the value of :param as "foo/%bar".

New in version 1.2.

Changed in version 1.2.0: TheColumnOperators.contains.autoescape parameter is now a simple boolean rather than a character; the escape character itself is also escaped, and defaults to a forwards slash, which itself can be customized using the ColumnOperators.contains.escape parameter.

  1. -

escape

a character which when given will render with theESCAPE keyword to establish that character as the escapecharacter. This character can then be placed preceding occurrencesof % and _ to allow them to act as themselves and notwildcard characters.

An expression such as:

  1. somecolumn.contains("foo/%bar", escape="^")

Will render as:

  1. somecolumn LIKE '%' || :param || '%' ESCAPE '^'

The parameter may also be combined withColumnOperators.contains.autoescape:

  1. somecolumn.contains("foo%bar^bat", escape="^", autoescape=True)

Where above, the given literal parameter will be converted to"foo^%bar^^bat" before being passed to the database.

See also

ColumnOperators.startswith()

ColumnOperators.endswith()

ColumnOperators.like()

  • desc()
  • Produce a desc() clause against theparent object.

  • distinct()

  • Produce a distinct() clause against theparent object.

  • endswith(other, **kwargs)

  • Implement the ‘endswith’ operator.

Produces a LIKE expression that tests against a match for the endof a string value:

  1. column LIKE '%' || <other>

E.g.:

  1. stmt = select([sometable]).\
  2. where(sometable.c.column.endswith("foobar"))

Since the operator uses LIKE, wildcard characters"%" and "_" that are present inside the expressionwill behave like wildcards as well. For literal stringvalues, the ColumnOperators.endswith.autoescape flagmay be set to True to apply escaping to occurrences of thesecharacters within the string value so that they match as themselvesand not as wildcard characters. Alternatively, theColumnOperators.endswith.escape parameter will establisha given character as an escape character which can be of use whenthe target expression is not a literal string.

  1. - Parameters
  2. -
  3. -

other – expression to be compared. This is usually a plainstring value, but can also be an arbitrary SQL expression. LIKEwildcard characters % and _ are not escaped by default unlessthe ColumnOperators.endswith.autoescape flag isset to True.

  1. -

autoescape

boolean; when True, establishes an escape characterwithin the LIKE expression, then applies it to all occurrences of"%", "_" and the escape character itself within thecomparison value, which is assumed to be a literal string and not aSQL expression.

An expression such as:

  1. somecolumn.endswith("foo%bar", autoescape=True)

Will render as:

  1. somecolumn LIKE '%' || :param ESCAPE '/'

With the value of :param as "foo/%bar".

New in version 1.2.

Changed in version 1.2.0: TheColumnOperators.endswith.autoescape parameter is now a simple boolean rather than a character; the escape character itself is also escaped, and defaults to a forwards slash, which itself can be customized using the ColumnOperators.endswith.escape parameter.

  1. -

escape

a character which when given will render with theESCAPE keyword to establish that character as the escapecharacter. This character can then be placed preceding occurrencesof % and _ to allow them to act as themselves and notwildcard characters.

An expression such as:

  1. somecolumn.endswith("foo/%bar", escape="^")

Will render as:

  1. somecolumn LIKE '%' || :param ESCAPE '^'

The parameter may also be combined withColumnOperators.endswith.autoescape:

  1. somecolumn.endswith("foo%bar^bat", escape="^", autoescape=True)

Where above, the given literal parameter will be converted to"foo^%bar^^bat" before being passed to the database.

See also

ColumnOperators.startswith()

ColumnOperators.contains()

ColumnOperators.like()

  • ilike(other, escape=None)
  • Implement the ilike operator, e.g. case insensitive LIKE.

In a column context, produces an expression either of the form:

  1. lower(a) LIKE lower(other)

Or on backends that support the ILIKE operator:

  1. a ILIKE other

E.g.:

  1. stmt = select([sometable]).\
  2. where(sometable.c.column.ilike("%foobar%"))
  1. - Parameters
  2. -
  3. -

other – expression to be compared

  1. -

escape

optional escape character, renders the ESCAPEkeyword, e.g.:

  1. somecolumn.ilike("foo/%bar", escape="/")

See also

ColumnOperators.like()

  • in(_other)
  • Implement the in operator.

In a column context, produces the clause column IN <other>.

The given parameter other may be:

  1. -

A list of literal values, e.g.:

  1. stmt.where(column.in_([1, 2, 3]))

In this calling form, the list of items is converted to a set ofbound parameters the same length as the list given:

  1. WHERE COL IN (?, ?, ?)
  1. -

A list of tuples may be provided if the comparison is against atuple_() containing multiple expressions:

  1. from sqlalchemy import tuple_
  2. stmt.where(tuple_(col1, col2).in_([(1, 10), (2, 20), (3, 30)]))
  1. -

An empty list, e.g.:

  1. stmt.where(column.in_([]))

In this calling form, the expression renders a “false” expression,e.g.:

  1. WHERE 1 != 1

This “false” expression has historically had different behaviorsin older SQLAlchemy versions, seecreate_engine.empty_in_strategy for behavioral options.

Changed in version 1.2: simplified the behavior of “empty in”expressions

  1. -

A bound parameter, e.g. bindparam(), may be used if itincludes the bindparam.expanding flag:

  1. stmt.where(column.in_(bindparam('value', expanding=True)))

In this calling form, the expression renders a special non-SQLplaceholder expression that looks like:

  1. WHERE COL IN ([EXPANDING_value])

This placeholder expression is intercepted at statement executiontime to be converted into the variable number of bound parameterform illustrated earlier. If the statement were executed as:

  1. connection.execute(stmt, {"value": [1, 2, 3]})

The database would be passed a bound parameter for each value:

  1. 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. OnSQLite this would be:

  1. WHERE COL IN (SELECT 1 FROM (SELECT 1) WHERE 1!=1)

New in version 1.3: “expanding” bound parameters now supportempty lists

  1. -

a select() construct, which is usually a correlatedscalar select:

  1. stmt.where(
  2. column.in_(
  3. select([othertable.c.y]).
  4. where(table.c.x == othertable.c.x)
  5. )
  6. )

In this calling form, ColumnOperators.in_() renders as given:

  1. WHERE COL IN (SELECT othertable.y
  2. FROM othertable WHERE othertable.x = table.x)
  1. - Parameters
  2. -

other – a list of literals, a select() construct,or a bindparam() construct that includes thebindparam.expanding flag set to True.

  • is(_other)
  • Implement the IS operator.

Normally, IS is generated automatically when comparing to avalue of None, which resolves to NULL. However, explicitusage of IS may be desirable if comparing to boolean valueson certain platforms.

See also

ColumnOperators.isnot()

  • isdistinct_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 avalue of None, which resolves to NULL. However, explicitusage of IS NOT may be desirable if comparing to boolean valueson certain platforms.

See also

ColumnOperators.is_()

  • isnotdistinct_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:

  1. a LIKE other

E.g.:

  1. stmt = select([sometable]).\
  2. where(sometable.c.column.like("%foobar%"))
  1. - Parameters
  2. -
  3. -

other – expression to be compared

  1. -

escape

optional escape character, renders the ESCAPEkeyword, e.g.:

  1. somecolumn.like("foo/%bar", escape="/")

See also

ColumnOperators.ilike()

  • match(other, **kwargs)
  • Implements a database-specific ‘match’ operator.

match() attempts to resolve toa MATCH-like function or operator provided by the backend.Examples include:

  1. -

PostgreSQL - renders x @@ to_tsquery(y)

  1. -

MySQL - renders MATCH (x) AGAINST (y IN BOOLEAN MODE)

  1. -

Oracle - renders CONTAINS(x, y)

  1. -

other backends may provide special implementations.

  1. -

Backends without any special implementation will emitthe operator as “MATCH”. This is compatible with SQLite, forexample.

  • notilike(other, escape=None)
  • implement the NOT ILIKE operator.

This is equivalent to using negation withColumnOperators.ilike(), i.e. ~x.ilike(y).

See also

ColumnOperators.ilike()

  • notin(_other)
  • implement the NOT IN operator.

This is equivalent to using negation withColumnOperators.in_(), i.e. ~x.in_(y).

In the case that other is an empty sequence, the compilerproduces an “empty not in” expression. This defaults to theexpression “1 = 1” to produce true in all cases. Thecreate_engine.empty_in_strategy may be used toalter this behavior.

Changed in version 1.2: The ColumnOperators.in_() andColumnOperators.notin_() operatorsnow produce a “static” expression for an empty IN sequenceby default.

See also

ColumnOperators.in_()

  • notlike(other, escape=None)
  • implement the NOT LIKE operator.

This is equivalent to using negation withColumnOperators.like(), i.e. ~x.like(y).

See also

ColumnOperators.like()

  • nullsfirst()
  • Produce a nullsfirst() clause against theparent object.

  • nullslast()

  • Produce a nullslast() clause against theparent object.

  • op(opstring, precedence=0, is_comparison=False, return_type=None)

inherited from theop()method ofOperators

produce a generic operator function.

e.g.:

  1. somecolumn.op("*")(5)

produces:

  1. somecolumn * 5

This function can also be used to make bitwise operators explicit. Forexample:

  1. somecolumn.op('&')(0xff)

is a bitwise AND of the value in somecolumn.

  1. - Parameters
  2. -
  3. -

operator – a string which will be output as the infix operatorbetween this element and the expression passed to thegenerated function.

  1. -

precedence – precedence to apply to the operator, whenparenthesizing expressions. A lower number will cause the expressionto be parenthesized when applied against another operator withhigher precedence. The default value of 0 is lower than alloperators except for the comma (,) and AS operators.A value of 100 will be higher or equal to all operators, and -100will be lower than or equal to all operators.

  1. -

is_comparison

if True, the operator will be considered as a“comparison” operator, that is which evaluates to a booleantrue/false value, like ==, >, etc. This flag should be setso that ORM relationships can establish that the operator is acomparison operator when used in a custom join condition.

New in version 0.9.2: - added theOperators.op.is_comparison flag.

  1. -

return_type

a TypeEngine class or object that willforce the return type of an expression produced by this operatorto be of that type. By default, operators that specifyOperators.op.is_comparison will resolve toBoolean, and those that do not will be of the sametype as the left-hand operand.

New in version 1.2.0b3: - added theOperators.op.return_type argument.

See also

Redefining and Creating New Operators

Using custom operators in join conditions

  • operate(op, *other, **kwargs)

inherited from theoperate()method ofOperators

Operate on an argument.

This is the lowest level of operation, raisesNotImplementedError by default.

Overriding this on a subclass can allow commonbehavior to be applied to all operations.For example, overriding ColumnOperatorsto apply func.lower() to the left and rightside:

  1. class MyComparator(ColumnOperators):
  2. def operate(self, op, other):
  3. return op(func.lower(self), func.lower(other))
  1. - Parameters
  2. -
  3. -

op – Operator callable.

  1. -

*other – the ‘other’ side of the operation. Willbe a single scalar for most operations.

  1. -

**kwargs – modifiers. These may be passed by specialoperators such as ColumnOperators.contains().

  • reverseoperate(_op, other, **kwargs)

inherited from thereverse_operate()method ofOperators

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 startof a string value:

  1. column LIKE <other> || '%'

E.g.:

  1. stmt = select([sometable]).\
  2. where(sometable.c.column.startswith("foobar"))

Since the operator uses LIKE, wildcard characters"%" and "_" that are present inside the expressionwill behave like wildcards as well. For literal stringvalues, the ColumnOperators.startswith.autoescape flagmay be set to True to apply escaping to occurrences of thesecharacters within the string value so that they match as themselvesand not as wildcard characters. Alternatively, theColumnOperators.startswith.escape parameter will establisha given character as an escape character which can be of use whenthe target expression is not a literal string.

  1. - Parameters
  2. -
  3. -

other – expression to be compared. This is usually a plainstring value, but can also be an arbitrary SQL expression. LIKEwildcard characters % and _ are not escaped by default unlessthe ColumnOperators.startswith.autoescape flag isset to True.

  1. -

autoescape

boolean; when True, establishes an escape characterwithin the LIKE expression, then applies it to all occurrences of"%", "_" and the escape character itself within thecomparison value, which is assumed to be a literal string and not aSQL expression.

An expression such as:

  1. somecolumn.startswith("foo%bar", autoescape=True)

Will render as:

  1. somecolumn LIKE :param || '%' ESCAPE '/'

With the value of :param as "foo/%bar".

New in version 1.2.

Changed in version 1.2.0: TheColumnOperators.startswith.autoescape parameter is now a simple boolean rather than a character; the escape character itself is also escaped, and defaults to a forwards slash, which itself can be customized using the ColumnOperators.startswith.escape parameter.

  1. -

escape

a character which when given will render with theESCAPE keyword to establish that character as the escapecharacter. This character can then be placed preceding occurrencesof % and _ to allow them to act as themselves and notwildcard characters.

An expression such as:

  1. somecolumn.startswith("foo/%bar", escape="^")

Will render as:

  1. somecolumn LIKE :param || '%' ESCAPE '^'

The parameter may also be combined withColumnOperators.startswith.autoescape:

  1. somecolumn.startswith("foo%bar^bat", escape="^", autoescape=True)

Where above, the given literal parameter will be converted to"foo^%bar^^bat" before being passed to the database.

See also

ColumnOperators.endswith()

ColumnOperators.contains()

ColumnOperators.like()

  • timetuple = None
  • Hack, allows datetime objects to be compared on the LHS.
    • class sqlalchemy.sql.base.DialectKWArgs
    • Establish the ability for a class to have dialect-specific argumentswith defaults and constructor validation.

The DialectKWArgs interacts with theDefaultDialect.construct_arguments present on a dialect.

See also

DefaultDialect.construct_arguments

  • classmethod argumentfor(_dialect_name, argument_name, default)
  • Add a new kind of dialect-specific keyword argument for this class.

E.g.:

  1. Index.argument_for("mydialect", "length", None)
  2.  
  3. some_index = Index('a', 'b', mydialect_length=5)

The DialectKWArgs.argument_for() method is a per-argumentway adding extra arguments to theDefaultDialect.construct_arguments dictionary. Thisdictionary provides a list of argument names accepted by variousschema-level constructs on behalf of a dialect.

New dialects should typically specify this dictionary all at once as adata member of the dialect class. The use case for ad-hoc addition ofargument names is typically for end-user code that is also usinga custom compilation scheme which consumes the additional arguments.

  1. - Parameters
  2. -
  3. -

dialect_name – name of a dialect. The dialect must belocatable, else a NoSuchModuleError is raised. Thedialect must also include an existingDefaultDialect.construct_arguments collection, indicatingthat it participates in the keyword-argument validation and defaultsystem, else ArgumentError is raised. If the dialect doesnot include this collection, then any keyword argument can bespecified on behalf of this dialect already. All dialects packagedwithin SQLAlchemy include this collection, however for third partydialects, support may vary.

  1. -

argument_name – name of the parameter.

  1. -

default – default value of the parameter.

New in version 0.9.4.

  • dialect_kwargs
  • A collection of keyword arguments specified as dialect-specificoptions 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, whichcontains all options known by this dialect including defaults.

The collection is also writable; keys are accepted of theform <dialect>_<kwarg> where the value will be assembledinto the list of options.

New in version 0.9.2.

Changed in version 0.9.4: The DialectKWArgs.dialect_kwargscollection is now writable.

See also

DialectKWArgs.dialect_options - nested dictionary form

  • dialect_options
  • A collection of keyword arguments specified as dialect-specificoptions to this construct.

This is a two-level nested registry, keyed to <dialect_name>and <argument_name>. For example, the postgresql_whereargument would be locatable as:

  1. arg = my_object.dialect_options['postgresql']['where']

New in version 0.9.2.

See also

DialectKWArgs.dialect_kwargs - flat dictionary form

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.

  • getchildren(**kwargs_)
  • Return immediate child elements of this ClauseElement.

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-level).

Represent the false keyword, or equivalent, in a SQL statement.

False_ is accessed as a constant via thefalse() function.

  • compare(other)
  • Compare this ColumnElement to another.

Special arguments understood:

  1. - Parameters
  2. -
  3. -

use_proxies – when True, consider two columns thatshare a common base column as equivalent (i.e. shares_lineage())

  1. -

equivalents – a dictionary of columns as keys mapped to setsof columns. If the given “other” column is present in thisdictionary, if any of the columns in the corresponding set() passthe comparison test, the result is True. This is used to expand thecomparison to other columns that may be known to be equivalent tothis one via foreign key or other criterion.

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 viaFunctionElement.filter():

  1. func.count(1).filter(True)

New in version 1.0.0.

See also

FunctionElement.filter()

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 criteriaset up by FunctionElement.filter().

Multiple criteria are joined together at SQL render timevia AND.

  • getchildren(**kwargs_)
  • Return immediate child elements of this ClauseElement.

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-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:

  1. func.rank().filter(MyClass.y > 5).over(order_by='x')

is shorthand for:

  1. from sqlalchemy import over, funcfilter
  2. over(funcfilter(func.rank(), MyClass.y > 5), order_by='x')

See over() for a full description.

  • selfgroup(_against=None)
  • Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a“grouping” construct, i.e. parenthesis. In particularit’s used by “binary” expressions to provide a groupingaround themselves when placed into a larger expression,as well as by select() constructs when placed intothe FROM clause of another select(). (Note thatsubqueries should be normally created using theSelect.alias() method, as many platforms requirenested SELECT statements to be named).

As expressions are composed together, the application ofself_group() is automatic - end-user code should neverneed to use this method directly. Note that SQLAlchemy’sclause constructs take operator precedence into account -so parenthesis might not be needed, for example, inan expression like x OR (y AND z) - AND takes precedenceover OR.

The base self_group() method of ClauseElementjust returns self.

Represents a column label (AS).

Represent a label, as typically applied to any column-levelelement using the AS sql keyword.

This constructor is mirrored as a public API function; see label() for a full usage and argument description.

  • property 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.

  • getchildren(**kwargs_)
  • Return immediate child elements of this ClauseElement.

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-level).

  • property 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.

  • selfgroup(_against=None)
  • Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a“grouping” construct, i.e. parenthesis. In particularit’s used by “binary” expressions to provide a groupingaround themselves when placed into a larger expression,as well as by select() constructs when placed intothe FROM clause of another select(). (Note thatsubqueries should be normally created using theSelect.alias() method, as many platforms requirenested SELECT statements to be named).

As expressions are composed together, the application ofself_group() is automatic - end-user code should neverneed to use this method directly. Note that SQLAlchemy’sclause constructs take operator precedence into account -so parenthesis might not be needed, for example, inan expression like x OR (y AND z) - AND takes precedenceover OR.

The base self_group() method of ClauseElementjust returns self.

Represent the NULL keyword in a SQL statement.

Null is accessed as a constant via thenull() function.

  • compare(other)
  • Compare this ColumnElement to another.

Special arguments understood:

  1. - Parameters
  2. -
  3. -

use_proxies – when True, consider two columns thatshare a common base column as equivalent (i.e. shares_lineage())

  1. -

equivalents – a dictionary of columns as keys mapped to setsof columns. If the given “other” column is present in thisdictionary, if any of the columns in the corresponding set() passthe comparison test, the result is True. This is used to expand thecomparison to other columns that may be known to be equivalent tothis one via foreign key or other criterion.

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 setitself. It’s supported only by certain databasebackends.

  • 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.

  • element = None
  • The underlying expression object to which this Overobject refers towards.

  • property func

  • the element referred to by this Overclause.

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.

  • getchildren(**kwargs_)
  • Return immediate child elements of this ClauseElement.

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-level).

Represent a literal SQL text fragment.

E.g.:

  1. from sqlalchemy import text
  2.  
  3. t = text("SELECT * FROM users")
  4. result = connection.execute(t)

The Text construct is produced using the text()function; see that function for full documentation.

See also

text()

  • bindparams(*binds, **names_to_values)
  • Establish the values and/or types of bound parameters withinthis TextClause construct.

Given a text construct such as:

  1. from sqlalchemy import text
  2. stmt = text("SELECT id, name FROM user WHERE name=:name "
  3. "AND timestamp=:timestamp")

the TextClause.bindparams() method can be used to establishthe initial value of :name and :timestamp,using simple keyword arguments:

  1. stmt = stmt.bindparams(name='jack',
  2. timestamp=datetime.datetime(2012, 10, 8, 15, 12, 5))

Where above, new BindParameter objectswill be generated with the names name and timestamp, andvalues of jack and datetime.datetime(2012, 10, 8, 15, 12, 5),respectively. The types will beinferred from the values given, in this case String andDateTime.

When specific typing behavior is needed, the positional *bindsargument can be used in which to specify bindparam() constructsdirectly. These constructs must include at least the keyargument, then an optional value and type:

  1. from sqlalchemy import bindparam
  2. stmt = stmt.bindparams(
  3. bindparam('name', value='jack', type_=String),
  4. bindparam('timestamp', type_=DateTime)
  5. )

Above, we specified the type of DateTime for thetimestamp bind, and the type of String for the namebind. In the case of name we also set the default value of"jack".

Additional bound parameters can be supplied at statement executiontime, e.g.:

  1. result = connection.execute(stmt,
  2. 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 addnew information. For example, we can callTextClause.bindparams() first with typing information, and asecond time with value information, and it will be combined:

  1. stmt = text("SELECT id, name FROM user WHERE name=:name "
  2. "AND timestamp=:timestamp")
  3. stmt = stmt.bindparams(
  4. bindparam('name', type_=String),
  5. bindparam('timestamp', type_=DateTime)
  6. )
  7. stmt = stmt.bindparams(
  8. name='jack',
  9. timestamp=datetime.datetime(2012, 10, 8, 15, 12, 5)
  10. )
  • columns(selectable, *cols, **types)
  • Turn this TextClause object into a TextAsFromobject that can be embedded into another statement.

This function essentially bridges the gap between an entirelytextual SELECT statement and the SQL expression language conceptof a “selectable”:

  1. from sqlalchemy.sql import column, text
  2.  
  3. stmt = text("SELECT id, name FROM some_table")
  4. stmt = stmt.columns(column('id'), column('name')).alias('st')
  5.  
  6. stmt = select([mytable]). select_from(
  7. mytable.join(stmt, mytable.c.name == stmt.c.name)
  8. ).where(stmt.c.id > 5)

Above, we pass a series of column() elements to theTextClause.columns() method positionally. These column()elements now become first class elements upon the TextAsFrom.ccolumn collection, just like any other selectable.

The column expressions we pass to TextClause.columns() mayalso be typed; when we do so, these TypeEngine objects becomethe effective return type of the column, so that SQLAlchemy’sresult-set-processing systems may be used on the return values.This is often needed for types such as date or boolean types, as wellas for unicode processing on some dialect configurations:

  1. stmt = text("SELECT id, name, timestamp FROM some_table")
  2. stmt = stmt.columns(
  3. column('id', Integer),
  4. column('name', Unicode),
  5. column('timestamp', DateTime)
  6. )
  7.  
  8. for id, name, timestamp in connection.execute(stmt):
  9. print(id, name, timestamp)

As a shortcut to the above syntax, keyword arguments referring totypes alone may be used, if only type conversion is needed:

  1. stmt = text("SELECT id, name, timestamp FROM some_table")
  2. stmt = stmt.columns(
  3. id=Integer,
  4. name=Unicode,
  5. timestamp=DateTime
  6. )
  7.  
  8. for id, name, timestamp in connection.execute(stmt):
  9. print(id, name, timestamp)

The positional form of TextClause.columns() also provides theunique feature of positional column targeting, which isparticularly useful when using the ORM with complex textual queries. Ifwe specify the columns from our model to TextClause.columns(),the result set will match to those columns positionally, meaning thename or origin of the column in the textual SQL doesn’t matter:

  1. stmt = text("SELECT users.id, addresses.id, users.id, "
  2. "users.name, addresses.email_address AS email "
  3. "FROM users JOIN addresses ON users.id=addresses.user_id "
  4. "WHERE users.id = 1").columns(
  5. User.id,
  6. Address.id,
  7. Address.user_id,
  8. User.name,
  9. Address.email_address
  10. )
  11.  
  12. query = session.query(User).from_statement(stmt).options(
  13. contains_eager(User.addresses))

New in version 1.1: the TextClause.columns() method nowoffers positional column targeting in the result set whenthe column expressions are passed purely positionally.

The TextClause.columns() method provides a directroute to calling FromClause.alias() as well asSelectBase.cte() against a textual SELECT statement:

  1. stmt = stmt.columns(id=Integer, name=String).cte('st')
  2.  
  3. stmt = select([sometable]).where(sometable.c.id == stmt.c.id)

New in version 0.9.0: text() can now be converted into afully featured “selectable” construct using theTextClause.columns() method.

  • compare(other)
  • Compare this ClauseElement to the given ClauseElement.

Subclasses should override the default behavior, which is astraight identity comparison.

**kw are arguments consumed by subclass compare() methods andmay be used to modify the criteria for comparison.(see ColumnElement)

  • getchildren(**kwargs_)
  • Return immediate child elements of this ClauseElement.

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-level).

  • selfgroup(_against=None)
  • Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a“grouping” construct, i.e. parenthesis. In particularit’s used by “binary” expressions to provide a groupingaround themselves when placed into a larger expression,as well as by select() constructs when placed intothe FROM clause of another select(). (Note thatsubqueries should be normally created using theSelect.alias() method, as many platforms requirenested SELECT statements to be named).

As expressions are composed together, the application ofself_group() is automatic - end-user code should neverneed to use this method directly. Note that SQLAlchemy’sclause constructs take operator precedence into account -so parenthesis might not be needed, for example, inan expression like x OR (y AND z) - AND takes precedenceover OR.

The base self_group() method of ClauseElementjust returns self.

Represent a SQL tuple.

  • init(*clauses, **kw)
  • Construct a new Tuple object.

This constructor is mirrored as a public API function; see tuple_() for a full usage and argument description.

Represent a WITHIN GROUP (ORDER BY) clause.

This is a special operator against so-called“ordered set aggregate” and “hypotheticalset 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 themethod FunctionElement.within_group_type(). If this returnsNone, 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.

  • getchildren(**kwargs_)
  • Return immediate child elements of this ClauseElement.

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-level).

  • over(partition_by=None, order_by=None, range=None, _rows=None)
  • Produce an OVER clause against this WithinGroupconstruct.

This function has the same signature as that ofFunctionElement.over().

Represent the true keyword, or equivalent, in a SQL statement.

True_ is accessed as a constant via thetrue() function.

  • compare(other)
  • Compare this ColumnElement to another.

Special arguments understood:

  1. - Parameters
  2. -
  3. -

use_proxies – when True, consider two columns thatshare a common base column as equivalent (i.e. shares_lineage())

  1. -

equivalents – a dictionary of columns as keys mapped to setsof columns. If the given “other” column is present in thisdictionary, if any of the columns in the corresponding set() passthe comparison test, the result is True. This is used to expand thecomparison to other columns that may be known to be equivalent tothis one via foreign key or other criterion.

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 producesa persistent TypeCoerce wrapper object rather thantranslating the given object in place.

See also

expression.type_coerce()

cast()

This constructor is mirrored as a public API function; see type_coerce() for a full usage and argument description.

  • getchildren(**kwargs_)
  • Return immediate child elements of this ClauseElement.

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-level).

  • class sqlalchemy.sql.operators.customop(_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 theOperators.op() or Operators.bool_op() methodsare used to create a custom operator callable. The class can also beused directly when programmatically constructing expressions. E.g.to represent the “factorial” operation:

  1. from sqlalchemy.sql import UnaryExpression
  2. from sqlalchemy.sql import operators
  3. from sqlalchemy import Numeric
  4.  
  5. unary = UnaryExpression(table.c.somecolumn,
  6. modifier=operators.custom_op("!"),
  7. type_=Numeric)

See also

Operators.op()

Operators.bool_op()

  • class sqlalchemy.sql.operators.Operators
  • Base of comparison and logical operators.

Implements base methodsoperate() andreverse_operate(), as well asand(),or(),invert().

Usually is used via its most common subclassColumnOperators.

  • and(other)
  • Implement the & operator.

When used with SQL expressions, results in anAND operation, equivalent toand_(), that is:

  1. a & b

is equivalent to:

  1. from sqlalchemy import and_
  2. and_(a, b)

Care should be taken when using & regardingoperator precedence; the & operator has the highest precedence.The operands should be enclosed in parenthesis if they containfurther sub expressions:

  1. (a == 2) & (b == 4)
  • invert()
  • Implement the ~ operator.

When used with SQL expressions, results in aNOT operation, equivalent tonot_(), that is:

  1. ~a

is equivalent to:

  1. from sqlalchemy import not_
  2. not_(a)
  • or(other)
  • Implement the | operator.

When used with SQL expressions, results in anOR operation, equivalent toor_(), that is:

  1. a | b

is equivalent to:

  1. from sqlalchemy import or_
  2. or_(a, b)

Care should be taken when using | regardingoperator precedence; the | operator has the highest precedence.The operands should be enclosed in parenthesis if they containfurther sub expressions:

  1. (a == 2) | (b == 4)
  • boolop(_opstring, precedence=0)
  • Return a custom boolean operator.

This method is shorthand for callingOperators.op() and passing theOperators.op.is_comparisonflag with True.

New in version 1.2.0b3.

See also

Operators.op()

  • op(opstring, precedence=0, is_comparison=False, return_type=None)
  • produce a generic operator function.

e.g.:

  1. somecolumn.op("*")(5)

produces:

  1. somecolumn * 5

This function can also be used to make bitwise operators explicit. Forexample:

  1. somecolumn.op('&')(0xff)

is a bitwise AND of the value in somecolumn.

  1. - Parameters
  2. -
  3. -

operator – a string which will be output as the infix operatorbetween this element and the expression passed to thegenerated function.

  1. -

precedence – precedence to apply to the operator, whenparenthesizing expressions. A lower number will cause the expressionto be parenthesized when applied against another operator withhigher precedence. The default value of 0 is lower than alloperators except for the comma (,) and AS operators.A value of 100 will be higher or equal to all operators, and -100will be lower than or equal to all operators.

  1. -

is_comparison

if True, the operator will be considered as a“comparison” operator, that is which evaluates to a booleantrue/false value, like ==, >, etc. This flag should be setso that ORM relationships can establish that the operator is acomparison operator when used in a custom join condition.

New in version 0.9.2: - added theOperators.op.is_comparison flag.

  1. -

return_type

a TypeEngine class or object that willforce the return type of an expression produced by this operatorto be of that type. By default, operators that specifyOperators.op.is_comparison will resolve toBoolean, and those that do not will be of the sametype as the left-hand operand.

New in version 1.2.0b3: - added theOperators.op.return_type argument.

See also

Redefining and Creating New Operators

Using custom operators in join conditions

  • operate(op, *other, **kwargs)
  • Operate on an argument.

This is the lowest level of operation, raisesNotImplementedError by default.

Overriding this on a subclass can allow commonbehavior to be applied to all operations.For example, overriding ColumnOperatorsto apply func.lower() to the left and rightside:

  1. class MyComparator(ColumnOperators):
  2. def operate(self, op, other):
  3. return op(func.lower(self), func.lower(other))
  1. - Parameters
  2. -
  3. -

op – Operator callable.

  1. -

*other – the ‘other’ side of the operation. Willbe a single scalar for most operations.

  1. -

**kwargs – modifiers. These may be passed by specialoperators such as ColumnOperators.contains().

  • reverseoperate(_op, other, **kwargs)
  • Reverse operate on an argument.

Usage is the same as operate().

  • class 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 whichrepresents a particular identifier name along with aquote flag. This quote flag, when set toTrue or False, overrides automatic quoting behaviorfor this identifier in order to either unconditionally quoteor to not quote the name. If left at its default of None,quoting behavior is applied to the identifier on a per-backend basisbased on an examination of the token itself.

A quoted_name object with quote=True is alsoprevented from being modified in the case of a so-called“name normalize” option. Certain database backends, such asOracle, Firebird, and DB2 “normalize” case-insensitive namesas uppercase. The SQLAlchemy dialects for these backendsconvert from SQLAlchemy’s lower-case-means-insensitive conventionto the upper-case-means-insensitive conventions of those backends.The quote=True flag here will prevent this conversion from occurringto support an identifier that’s quoted as all lower case againstsuch a backend.

The quoted_name object is normally created automaticallywhen specifying the name for key schema constructs such asTable, Column, and others. The class can also bepassed explicitly as the name to any function that receives a name whichcan be quoted. Such as to use the Engine.has_table() method withan unconditionally quoted name:

  1. from sqlalchemy import create_engine
  2. from sqlalchemy.sql import quoted_name
  3.  
  4. engine = create_engine("oracle+cx_oracle://some_dsn")
  5. 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 toupper case.

New in version 0.9.0.

Changed in version 1.2: The quoted_name construct is nowimportable from sqlalchemy.sql, in addition to the previouslocation of sqlalchemy.sql.elements.

  • quote
  • whether the string should be unconditionally quoted

Define a ‘unary’ expression.

A unary expression has a single column expressionand 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 operatorsincluding those used by desc(), asc(), distinct(),nullsfirst() and nullslast().

This is used for visit traversal.

**kwargs may contain flags that change the collection that isreturned, for example to return a subset of items in order tocut down on larger traversals, or to return child items from adifferent context (such as schema-level collections instead ofclause-level).

  • selfgroup(_against=None)
  • Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a“grouping” construct, i.e. parenthesis. In particularit’s used by “binary” expressions to provide a groupingaround themselves when placed into a larger expression,as well as by select() constructs when placed intothe FROM clause of another select(). (Note thatsubqueries should be normally created using theSelect.alias() method, as many platforms requirenested SELECT statements to be named).

As expressions are composed together, the application ofself_group() is automatic - end-user code should neverneed to use this method directly. Note that SQLAlchemy’sclause constructs take operator precedence into account -so parenthesis might not be needed, for example, inan expression like x OR (y AND z) - AND takes precedenceover OR.

The base self_group() method of ClauseElementjust returns self.