Release: 1.1.0b1 | Release Date: not released

SQLAlchemy 1.1 Documentation

Selectables, Tables, FROM objects

The term “selectable” refers to any object that rows can be selected from; in SQLAlchemy, these objects descend from FromClause and their distinguishing feature is their FromClause.c attribute, which is a namespace of all the columns contained within the FROM clause (these elements are themselves ColumnElement subclasses).

sqlalchemy.sql.expression.alias(selectable, name=None, flat=False)

Return an Alias object.

An Alias represents any FromClause with an alternate name assigned within SQL, typically using the AS clause when generated, e.g. SELECT * FROM table AS aliasname.

Similar functionality is available via the alias() method available on all FromClause subclasses.

When an Alias is created from a Table object, this has the effect of the table being rendered as tablename AS aliasname in a SELECT statement.

For select() objects, the effect is that of creating a named subquery, i.e. (select ...) AS aliasname.

The name parameter is optional, and provides the name to use in the rendered SQL. If blank, an “anonymous” name will be deterministically generated at compile time. Deterministic means the name is guaranteed to be unique against other constructs used in the same statement, and will also be the same name for each successive compilation of the same statement object.

매개 변수:
  • selectable – any FromClause subclass, such as a table, select statement, etc.
  • name – string name to be assigned as the alias. If None, a name will be deterministically generated at compile time.
  • flat

    Will be passed through to if the given selectable is an instance of Join - see Join.alias() for details.

    버전 0.9.0에 추가.

sqlalchemy.sql.expression.except_(*selects, **kwargs)

Return an EXCEPT of multiple selectables.

The returned object is an instance of CompoundSelect.

*selects
a list of Select instances.
**kwargs
available keyword arguments are the same as those of select().
sqlalchemy.sql.expression.except_all(*selects, **kwargs)

Return an EXCEPT ALL of multiple selectables.

The returned object is an instance of CompoundSelect.

*selects
a list of Select instances.
**kwargs
available keyword arguments are the same as those of select().
sqlalchemy.sql.expression.exists(*args, **kwargs)

Construct a new Exists against an existing Select object.

Calling styles are of the following forms:

# use on an existing select()
s = select([table.c.col1]).where(table.c.col2==5)
s = exists(s)

# construct a select() at once
exists(['*'], **select_arguments).where(criterion)

# columns argument is optional, generates "EXISTS (SELECT *)"
# by default.
exists().where(table.c.col2==5)
sqlalchemy.sql.expression.intersect(*selects, **kwargs)

Return an INTERSECT of multiple selectables.

The returned object is an instance of CompoundSelect.

*selects
a list of Select instances.
**kwargs
available keyword arguments are the same as those of select().
sqlalchemy.sql.expression.intersect_all(*selects, **kwargs)

Return an INTERSECT ALL of multiple selectables.

The returned object is an instance of CompoundSelect.

*selects
a list of Select instances.
**kwargs
available keyword arguments are the same as those of select().
sqlalchemy.sql.expression.join(left, right, onclause=None, isouter=False, full=False)

Produce a Join object, given two FromClause expressions.

E.g.:

j = join(user_table, address_table,
         user_table.c.id == address_table.c.user_id)
stmt = select([user_table]).select_from(j)

would emit SQL along the lines of:

SELECT user.id, user.name FROM user
JOIN address ON user.id = address.user_id

Similar functionality is available given any FromClause object (e.g. such as a Table) using the FromClause.join() method.

매개 변수:
  • left – The left side of the join.
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • isouter – if True, render a LEFT OUTER JOIN, instead of JOIN.
  • full

    if True, render a FULL OUTER JOIN, instead of JOIN.

    버전 1.1에 추가.

더 보기

FromClause.join() - method form, based on a given left side

Join - the type of object produced

sqlalchemy.sql.expression.lateral(selectable, name=None)

Return a Lateral object.

Lateral is an Alias subclass that represents a subquery with the LATERAL keyword applied to it.

The special behavior of a LATERAL subquery is that it appears in the FROM clause of an enclosing SELECT, but may correlate to other FROM clauses of that SELECT. It is a special case of subquery only supported by a small number of backends, currently more recent Postgresql versions.

버전 1.1에 추가.

더 보기

LATERAL correlation - overview of usage.

sqlalchemy.sql.expression.outerjoin(left, right, onclause=None, full=False)

Return an OUTER JOIN clause element.

The returned object is an instance of Join.

Similar functionality is also available via the outerjoin() method on any FromClause.

매개 변수:
  • left – The left side of the join.
  • right – The right side of the join.
  • onclause – Optional criterion for the ON clause, is derived from foreign key relationships established between left and right otherwise.

To chain joins together, use the FromClause.join() or FromClause.outerjoin() methods on the resulting Join object.

sqlalchemy.sql.expression.select(columns=None, whereclause=None, from_obj=None, distinct=False, having=None, correlate=True, prefixes=None, suffixes=None, **kwargs)

Construct a new Select.

Similar functionality is also available via the FromClause.select() method on any FromClause.

All arguments which accept ClauseElement arguments also accept string arguments, which will be converted as appropriate into either text() or literal_column() constructs.

더 보기

Selecting - Core Tutorial description of select().

매개 변수:
  • columns

    A list of ColumnElement or FromClause objects which will form the columns clause of the resulting statement. For those objects that are instances of FromClause (typically Table or Alias objects), the FromClause.c collection is extracted to form a collection of ColumnElement objects.

    This parameter will also accept Text constructs as given, as well as ORM-mapped classes.

    주석

    The select.columns parameter is not available in the method form of select(), e.g. FromClause.select().

  • whereclause

    A ClauseElement expression which will be used to form the WHERE clause. It is typically preferable to add WHERE criterion to an existing Select using method chaining with Select.where().

    더 보기

    Select.where()

  • from_obj

    A list of ClauseElement objects which will be added to the FROM clause of the resulting statement. This is equivalent to calling Select.select_from() using method chaining on an existing Select object.

    더 보기

    Select.select_from() - full description of explicit FROM clause specification.

  • autocommit

    Deprecated. Use .execution_options(autocommit=<True|False>) to set the autocommit option.

  • bind=None – an Engine or Connection instance to which the resulting Select object will be bound. The Select object will otherwise automatically bind to whatever Connectable instances can be located within its contained ClauseElement members.
  • correlate=True

    indicates that this Select object should have its contained FromClause elements “correlated” to an enclosing Select object. It is typically preferable to specify correlations on an existing Select construct using Select.correlate().

    더 보기

    Select.correlate() - full description of correlation.

  • distinct=False

    when True, applies a DISTINCT qualifier to the columns clause of the resulting statement.

    The boolean argument may also be a column expression or list of column expressions - this is a special calling form which is understood by the Postgresql dialect to render the DISTINCT ON (<columns>) syntax.

    distinct is also available on an existing Select object via the distinct() method.

    더 보기

    Select.distinct()

  • for_update=False
    when True, applies FOR UPDATE to the end of the resulting statement.

    버전 0.9.0 폐지: - use Select.with_for_update() to specify the structure of the FOR UPDATE clause.

    for_update accepts various string values interpreted by specific backends, including:

    • "read" - on MySQL, translates to LOCK IN SHARE MODE; on Postgresql, translates to FOR SHARE.
    • "nowait" - on Postgresql and Oracle, translates to FOR UPDATE NOWAIT.
    • "read_nowait" - on Postgresql, translates to FOR SHARE NOWAIT.

    더 보기

    Select.with_for_update() - improved API for specifying the FOR UPDATE clause.

  • group_by

    a list of ClauseElement objects which will comprise the GROUP BY clause of the resulting select. This parameter is typically specified more naturally using the Select.group_by() method on an existing Select.

    더 보기

    Select.group_by()

  • having

    a ClauseElement that will comprise the HAVING clause of the resulting select when GROUP BY is used. This parameter is typically specified more naturally using the Select.having() method on an existing Select.

    더 보기

    Select.having()

  • limit=None

    a numerical value which usually renders as a LIMIT expression in the resulting select. Backends that don’t support LIMIT will attempt to provide similar functionality. This parameter is typically specified more naturally using the Select.limit() method on an existing Select.

    더 보기

    Select.limit()

  • offset=None

    a numeric value which usually renders as an OFFSET expression in the resulting select. Backends that don’t support OFFSET will attempt to provide similar functionality. This parameter is typically specified more naturally using the Select.offset() method on an existing Select.

    더 보기

    Select.offset()

  • order_by

    a scalar or list of ClauseElement objects which will comprise the ORDER BY clause of the resulting select. This parameter is typically specified more naturally using the Select.order_by() method on an existing Select.

    더 보기

    Select.order_by()

  • use_labels=False

    when True, the statement will be generated using labels for each column in the columns clause, which qualify each column with its parent table’s (or aliases) name so that name conflicts between columns in different tables don’t occur. The format of the label is <tablename>_<column>. The “c” collection of the resulting Select object will use these names as well for targeting column members.

    This parameter can also be specified on an existing Select object using the Select.apply_labels() method.

sqlalchemy.sql.expression.subquery(alias, *args, **kwargs)

Return an Alias object derived from a Select.

name
alias name

*args, **kwargs

all other arguments are delivered to the select() function.
sqlalchemy.sql.expression.table(name, *columns)

Produce a new TableClause.

The object returned is an instance of TableClause, which represents the “syntactical” portion of the schema-level Table object. It may be used to construct lightweight table constructs.

버전 1.0.0으로 변경: expression.table() can now be imported from the plain sqlalchemy namespace like any other SQL element.

매개 변수:
sqlalchemy.sql.expression.union(*selects, **kwargs)

Return a UNION of multiple selectables.

The returned object is an instance of CompoundSelect.

A similar union() method is available on all FromClause subclasses.

*selects
a list of Select instances.
**kwargs
available keyword arguments are the same as those of select().
sqlalchemy.sql.expression.union_all(*selects, **kwargs)

Return a UNION ALL of multiple selectables.

The returned object is an instance of CompoundSelect.

A similar union_all() method is available on all FromClause subclasses.

*selects
a list of Select instances.
**kwargs
available keyword arguments are the same as those of select().
class sqlalchemy.sql.expression.Alias(selectable, name=None)

Bases: sqlalchemy.sql.expression.FromClause

Represents an table or selectable alias (AS).

Represents an alias, as typically applied to any table or sub-select within a SQL statement using the AS keyword (or without the keyword on certain databases such as Oracle).

This object is constructed from the alias() module level function as well as the FromClause.alias() method available on all FromClause subclasses.

alias(name=None, flat=False)
inherited from the alias() method of FromClause

return an alias of this FromClause.

This is shorthand for calling:

from sqlalchemy import alias
a = alias(self, name=name)

See alias() for details.

c
inherited from the c attribute of FromClause

An alias for the columns attribute.

columns
inherited from the columns attribute of FromClause

A named-based collection of ColumnElement objects maintained by this FromClause.

The columns, or c collection, is the gateway to the construction of SQL expressions using table-bound or other selectable-bound columns:

select([mytable]).where(mytable.c.somecolumn == 5)
compare(other, **kw)
inherited from the compare() method of ClauseElement

Compare this ClauseElement to the given ClauseElement.

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

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

compile(bind=None, dialect=None, **kw)
inherited from the compile() method of ClauseElement

Compile this SQL expression.

The return value is a Compiled object. Calling str() or unicode() on the returned value will yield a string representation of the result. The Compiled object also can return a dictionary of bind parameter names and values using the params accessor.

매개 변수:
  • bind – An Engine or Connection from which a Compiled will be acquired. This argument takes precedence over this ClauseElement‘s bound engine, if any.
  • column_keys – Used for INSERT and UPDATE statements, a list of column names which should be present in the VALUES clause of the compiled statement. If None, all columns from the target table object are rendered.
  • dialect – A Dialect instance from which a Compiled will be acquired. This argument takes precedence over the bind argument as well as this ClauseElement‘s bound engine, if any.
  • inline – Used for INSERT statements, for a dialect which does not support inline retrieval of newly generated primary key columns, will force the expression used to create the new primary key value to be rendered inline within the INSERT statement’s VALUES clause. This typically refers to Sequence execution but may also refer to any server-side default generation function associated with a primary key Column.
  • compile_kwargs

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

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

    버전 0.9.0에 추가.

correspond_on_equivalents(column, equivalents)
inherited from the correspond_on_equivalents() method of FromClause

Return corresponding_column for the given column, or if None search for a match in the given dictionary.

corresponding_column(column, require_embedded=False)
inherited from the corresponding_column() method of FromClause

Given a ColumnElement, return the exported ColumnElement object from this Selectable which corresponds to that original Column via a common ancestor column.

매개 변수:
  • column – the target ColumnElement to be matched
  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this FromClause. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this FromClause.
count(whereclause=None, **params)
inherited from the count() method of FromClause

return a SELECT COUNT generated against this FromClause.

foreign_keys
inherited from the foreign_keys attribute of FromClause

Return the collection of ForeignKey objects which this FromClause references.

join(right, onclause=None, isouter=False, full=False)
inherited from the join() method of FromClause

Return a Join from this FromClause to another FromClause.

E.g.:

from sqlalchemy import join

j = user_table.join(address_table,
                user_table.c.id == address_table.c.user_id)
stmt = select([user_table]).select_from(j)

would emit SQL along the lines of:

SELECT user.id, user.name FROM user
JOIN address ON user.id = address.user_id
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • isouter – if True, render a LEFT OUTER JOIN, instead of JOIN.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN. Implies FromClause.join.isouter.

    버전 1.1에 추가.

더 보기

join() - standalone function

Join - the type of object produced

lateral(name=None)
inherited from the lateral() method of FromClause

Return a LATERAL alias of this FromClause.

The return value is the Lateral construct also provided by the top-level lateral() function.

버전 1.1에 추가.

더 보기

LATERAL correlation - overview of usage.

outerjoin(right, onclause=None, full=False)
inherited from the outerjoin() method of FromClause

Return a Join from this FromClause to another FromClause, with the “isouter” flag set to True.

E.g.:

from sqlalchemy import outerjoin

j = user_table.outerjoin(address_table,
                user_table.c.id == address_table.c.user_id)

The above is equivalent to:

j = user_table.join(
    address_table,
    user_table.c.id == address_table.c.user_id,
    isouter=True)
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN.

    버전 1.1에 추가.

더 보기

FromClause.join()

Join

params(*optionaldict, **kwargs)
inherited from the params() method of ClauseElement

Return a copy with bindparam() elements replaced.

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

>>> clause = column('x') + bindparam('foo')
>>> print clause.compile().params
{'foo':None}
>>> print clause.params({'foo':7}).compile().params
{'foo':7}
primary_key
inherited from the primary_key attribute of FromClause

Return the collection of Column objects which comprise the primary key of this FromClause.

replace_selectable(old, alias)
inherited from the replace_selectable() method of FromClause

replace all occurrences of FromClause ‘old’ with the given Alias object, returning a copy of this FromClause.

select(whereclause=None, **params)
inherited from the select() method of FromClause

return a SELECT of this FromClause.

더 보기

select() - general purpose method which allows for arbitrary column lists.

unique_params(*optionaldict, **kwargs)
inherited from the unique_params() method of ClauseElement

Return a copy with bindparam() elements replaced.

Same functionality as params(), except adds unique=True to affected bind parameters so that multiple statements can be used.

class sqlalchemy.sql.expression.CompoundSelect(keyword, *selects, **kwargs)

Bases: sqlalchemy.sql.expression.GenerativeSelect

Forms the basis of UNION, UNION ALL, and other
SELECT-based set operations.
alias(name=None, flat=False)
inherited from the alias() method of FromClause

return an alias of this FromClause.

This is shorthand for calling:

from sqlalchemy import alias
a = alias(self, name=name)

See alias() for details.

append_group_by(*clauses)
inherited from the append_group_by() method of GenerativeSelect

Append the given GROUP BY criterion applied to this selectable.

The criterion will be appended to any pre-existing GROUP BY criterion.

This is an in-place mutation method; the group_by() method is preferred, as it provides standard method chaining.

append_order_by(*clauses)
inherited from the append_order_by() method of GenerativeSelect

Append the given ORDER BY criterion applied to this selectable.

The criterion will be appended to any pre-existing ORDER BY criterion.

This is an in-place mutation method; the order_by() method is preferred, as it provides standard method chaining.

apply_labels()
inherited from the apply_labels() method of GenerativeSelect

return a new selectable with the ‘use_labels’ flag set to True.

This will result in column expressions being generated using labels against their table name, such as “SELECT somecolumn AS tablename_somecolumn”. This allows selectables which contain multiple FROM clauses to produce a unique set of column names regardless of name conflicts among the individual FROM clauses.

as_scalar()
inherited from the as_scalar() method of SelectBase

return a ‘scalar’ representation of this selectable, which can be used as a column expression.

Typically, a select statement which has only one column in its columns clause is eligible to be used as a scalar expression.

The returned object is an instance of ScalarSelect.

autocommit()
inherited from the autocommit() method of SelectBase

return a new selectable with the ‘autocommit’ flag set to True.

버전 0.6 폐지: autocommit() is deprecated. Use Executable.execution_options() with the ‘autocommit’ flag.

c
inherited from the c attribute of FromClause

An alias for the columns attribute.

columns
inherited from the columns attribute of FromClause

A named-based collection of ColumnElement objects maintained by this FromClause.

The columns, or c collection, is the gateway to the construction of SQL expressions using table-bound or other selectable-bound columns:

select([mytable]).where(mytable.c.somecolumn == 5)
compare(other, **kw)
inherited from the compare() method of ClauseElement

Compare this ClauseElement to the given ClauseElement.

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

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

compile(bind=None, dialect=None, **kw)
inherited from the compile() method of ClauseElement

Compile this SQL expression.

The return value is a Compiled object. Calling str() or unicode() on the returned value will yield a string representation of the result. The Compiled object also can return a dictionary of bind parameter names and values using the params accessor.

매개 변수:
  • bind – An Engine or Connection from which a Compiled will be acquired. This argument takes precedence over this ClauseElement‘s bound engine, if any.
  • column_keys – Used for INSERT and UPDATE statements, a list of column names which should be present in the VALUES clause of the compiled statement. If None, all columns from the target table object are rendered.
  • dialect – A Dialect instance from which a Compiled will be acquired. This argument takes precedence over the bind argument as well as this ClauseElement‘s bound engine, if any.
  • inline – Used for INSERT statements, for a dialect which does not support inline retrieval of newly generated primary key columns, will force the expression used to create the new primary key value to be rendered inline within the INSERT statement’s VALUES clause. This typically refers to Sequence execution but may also refer to any server-side default generation function associated with a primary key Column.
  • compile_kwargs

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

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

    버전 0.9.0에 추가.

correspond_on_equivalents(column, equivalents)
inherited from the correspond_on_equivalents() method of FromClause

Return corresponding_column for the given column, or if None search for a match in the given dictionary.

corresponding_column(column, require_embedded=False)
inherited from the corresponding_column() method of FromClause

Given a ColumnElement, return the exported ColumnElement object from this Selectable which corresponds to that original Column via a common ancestor column.

매개 변수:
  • column – the target ColumnElement to be matched
  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this FromClause. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this FromClause.
count(whereclause=None, **params)
inherited from the count() method of FromClause

return a SELECT COUNT generated against this FromClause.

cte(name=None, recursive=False)
inherited from the cte() method of HasCTE

Return a new CTE, or Common Table Expression instance.

Common table expressions are a SQL standard whereby SELECT statements can draw upon secondary statements specified along with the primary statement, using a clause called “WITH”. Special semantics regarding UNION can also be employed to allow “recursive” queries, where a SELECT statement can draw upon the set of rows that have previously been selected.

CTEs can also be applied to DML constructs UPDATE, INSERT and DELETE on some databases, both as a source of CTE rows when combined with RETURNING, as well as a consumer of CTE rows.

SQLAlchemy detects CTE objects, which are treated similarly to Alias objects, as special elements to be delivered to the FROM clause of the statement as well as to a WITH clause at the top of the statement.

버전 1.1으로 변경: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.

매개 변수:
  • name – name given to the common table expression. Like _FromClause.alias(), the name can be left as None in which case an anonymous symbol will be used at query compile time.
  • recursive – if True, will render WITH RECURSIVE. A recursive common table expression is intended to be used in conjunction with UNION ALL in order to derive rows from those already selected.

The following examples include two from Postgresql’s documentation at http://www.postgresql.org/docs/current/static/queries-with.html, as well as additional examples.

Example 1, non recursive:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

orders = Table('orders', metadata,
    Column('region', String),
    Column('amount', Integer),
    Column('product', String),
    Column('quantity', Integer)
)

regional_sales = select([
                    orders.c.region,
                    func.sum(orders.c.amount).label('total_sales')
                ]).group_by(orders.c.region).cte("regional_sales")


top_regions = select([regional_sales.c.region]).\
        where(
            regional_sales.c.total_sales >
            select([
                func.sum(regional_sales.c.total_sales)/10
            ])
        ).cte("top_regions")

statement = select([
            orders.c.region,
            orders.c.product,
            func.sum(orders.c.quantity).label("product_units"),
            func.sum(orders.c.amount).label("product_sales")
    ]).where(orders.c.region.in_(
        select([top_regions.c.region])
    )).group_by(orders.c.region, orders.c.product)

result = conn.execute(statement).fetchall()

Example 2, WITH RECURSIVE:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

parts = Table('parts', metadata,
    Column('part', String),
    Column('sub_part', String),
    Column('quantity', Integer),
)

included_parts = select([
                    parts.c.sub_part,
                    parts.c.part,
                    parts.c.quantity]).\
                    where(parts.c.part=='our part').\
                    cte(recursive=True)


incl_alias = included_parts.alias()
parts_alias = parts.alias()
included_parts = included_parts.union_all(
    select([
        parts_alias.c.sub_part,
        parts_alias.c.part,
        parts_alias.c.quantity
    ]).
        where(parts_alias.c.part==incl_alias.c.sub_part)
)

statement = select([
            included_parts.c.sub_part,
            func.sum(included_parts.c.quantity).
              label('total_quantity')
        ]).\
        group_by(included_parts.c.sub_part)

result = conn.execute(statement).fetchall()

Example 3, an upsert using UPDATE and INSERT with CTEs:

orders = table(
    'orders',
    column('region'),
    column('amount'),
    column('product'),
    column('quantity')
)

upsert = (
    orders.update()
    .where(orders.c.region == 'Region1')
    .values(amount=1.0, product='Product1', quantity=1)
    .returning(*(orders.c._all_columns)).cte('upsert'))

insert = orders.insert().from_select(
    orders.c.keys(),
    select([
        literal('Region1'), literal(1.0),
        literal('Product1'), literal(1)
    ).where(exists(upsert.select()))
)

connection.execute(insert)

더 보기

orm.query.Query.cte() - ORM version of HasCTE.cte().

description
inherited from the description attribute of FromClause

a brief description of this FromClause.

Used primarily for error message formatting.

execute(*multiparams, **params)
inherited from the execute() method of Executable

Compile and execute this Executable.

execution_options(**kw)
inherited from the execution_options() method of Executable

Set non-SQL options for the statement which take effect during execution.

Execution options can be set on a per-statement or per Connection basis. Additionally, the Engine and ORM Query objects provide access to execution options which they in turn configure upon connections.

The execution_options() method is generative. A new instance of this statement is returned that contains the options:

statement = select([table.c.x, table.c.y])
statement = statement.execution_options(autocommit=True)

Note that only a subset of possible execution options can be applied to a statement - these include “autocommit” and “stream_results”, but not “isolation_level” or “compiled_cache”. See Connection.execution_options() for a full list of possible options.

for_update
inherited from the for_update attribute of GenerativeSelect

Provide legacy dialect support for the for_update attribute.

foreign_keys
inherited from the foreign_keys attribute of FromClause

Return the collection of ForeignKey objects which this FromClause references.

group_by(*clauses)
inherited from the group_by() method of GenerativeSelect

return a new selectable with the given list of GROUP BY criterion applied.

The criterion will be appended to any pre-existing GROUP BY criterion.

join(right, onclause=None, isouter=False, full=False)
inherited from the join() method of FromClause

Return a Join from this FromClause to another FromClause.

E.g.:

from sqlalchemy import join

j = user_table.join(address_table,
                user_table.c.id == address_table.c.user_id)
stmt = select([user_table]).select_from(j)

would emit SQL along the lines of:

SELECT user.id, user.name FROM user
JOIN address ON user.id = address.user_id
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • isouter – if True, render a LEFT OUTER JOIN, instead of JOIN.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN. Implies FromClause.join.isouter.

    버전 1.1에 추가.

더 보기

join() - standalone function

Join - the type of object produced

label(name)
inherited from the label() method of SelectBase

return a ‘scalar’ representation of this selectable, embedded as a subquery with a label.

더 보기

as_scalar().

lateral(name=None)
inherited from the lateral() method of FromClause

Return a LATERAL alias of this FromClause.

The return value is the Lateral construct also provided by the top-level lateral() function.

버전 1.1에 추가.

더 보기

LATERAL correlation - overview of usage.

limit(limit)
inherited from the limit() method of GenerativeSelect

return a new selectable with the given LIMIT criterion applied.

This is a numerical value which usually renders as a LIMIT expression in the resulting select. Backends that don’t support LIMIT will attempt to provide similar functionality.

버전 1.0.0으로 변경: - Select.limit() can now accept arbitrary SQL expressions as well as integer values.

매개 변수:limit – an integer LIMIT parameter, or a SQL expression that provides an integer result.
offset(offset)
inherited from the offset() method of GenerativeSelect

return a new selectable with the given OFFSET criterion applied.

This is a numeric value which usually renders as an OFFSET expression in the resulting select. Backends that don’t support OFFSET will attempt to provide similar functionality.

버전 1.0.0으로 변경: - Select.offset() can now accept arbitrary SQL expressions as well as integer values.

매개 변수:offset – an integer OFFSET parameter, or a SQL expression that provides an integer result.
order_by(*clauses)
inherited from the order_by() method of GenerativeSelect

return a new selectable with the given list of ORDER BY criterion applied.

The criterion will be appended to any pre-existing ORDER BY criterion.

outerjoin(right, onclause=None, full=False)
inherited from the outerjoin() method of FromClause

Return a Join from this FromClause to another FromClause, with the “isouter” flag set to True.

E.g.:

from sqlalchemy import outerjoin

j = user_table.outerjoin(address_table,
                user_table.c.id == address_table.c.user_id)

The above is equivalent to:

j = user_table.join(
    address_table,
    user_table.c.id == address_table.c.user_id,
    isouter=True)
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN.

    버전 1.1에 추가.

더 보기

FromClause.join()

Join

params(*optionaldict, **kwargs)
inherited from the params() method of ClauseElement

Return a copy with bindparam() elements replaced.

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

>>> clause = column('x') + bindparam('foo')
>>> print clause.compile().params
{'foo':None}
>>> print clause.params({'foo':7}).compile().params
{'foo':7}
primary_key
inherited from the primary_key attribute of FromClause

Return the collection of Column objects which comprise the primary key of this FromClause.

replace_selectable(old, alias)
inherited from the replace_selectable() method of FromClause

replace all occurrences of FromClause ‘old’ with the given Alias object, returning a copy of this FromClause.

scalar(*multiparams, **params)
inherited from the scalar() method of Executable

Compile and execute this Executable, returning the result’s scalar representation.

select(whereclause=None, **params)
inherited from the select() method of FromClause

return a SELECT of this FromClause.

더 보기

select() - general purpose method which allows for arbitrary column lists.

unique_params(*optionaldict, **kwargs)
inherited from the unique_params() method of ClauseElement

Return a copy with bindparam() elements replaced.

Same functionality as params(), except adds unique=True to affected bind parameters so that multiple statements can be used.

with_for_update(nowait=False, read=False, of=None)
inherited from the with_for_update() method of GenerativeSelect

Specify a FOR UPDATE clause for this GenerativeSelect.

E.g.:

stmt = select([table]).with_for_update(nowait=True)

On a database like Postgresql or Oracle, the above would render a statement like:

SELECT table.a, table.b FROM table FOR UPDATE NOWAIT

on other backends, the nowait option is ignored and instead would produce:

SELECT table.a, table.b FROM table FOR UPDATE

When called with no arguments, the statement will render with the suffix FOR UPDATE. Additional arguments can then be provided which allow for common database-specific variants.

매개 변수:
  • nowait – boolean; will render FOR UPDATE NOWAIT on Oracle and Postgresql dialects.
  • read – boolean; will render LOCK IN SHARE MODE on MySQL, FOR SHARE on Postgresql. On Postgresql, when combined with nowait, will render FOR SHARE NOWAIT.
  • of – SQL expression or list of SQL expression elements (typically Column objects or a compatible expression) which will render into a FOR UPDATE OF clause; supported by PostgreSQL and Oracle. May render as a table or as a column depending on backend.

버전 0.9.0에 추가.

class sqlalchemy.sql.expression.CTE(selectable, name=None, recursive=False, _cte_alias=None, _restates=frozenset([]), _suffixes=None)

Bases: sqlalchemy.sql.expression.Generative, sqlalchemy.sql.expression.HasSuffixes, sqlalchemy.sql.expression.Alias

Represent a Common Table Expression.

The CTE object is obtained using the SelectBase.cte() method from any selectable. See that method for complete examples.

버전 0.7.6에 추가.

c
inherited from the c attribute of FromClause

An alias for the columns attribute.

columns
inherited from the columns attribute of FromClause

A named-based collection of ColumnElement objects maintained by this FromClause.

The columns, or c collection, is the gateway to the construction of SQL expressions using table-bound or other selectable-bound columns:

select([mytable]).where(mytable.c.somecolumn == 5)
compare(other, **kw)
inherited from the compare() method of ClauseElement

Compare this ClauseElement to the given ClauseElement.

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

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

compile(bind=None, dialect=None, **kw)
inherited from the compile() method of ClauseElement

Compile this SQL expression.

The return value is a Compiled object. Calling str() or unicode() on the returned value will yield a string representation of the result. The Compiled object also can return a dictionary of bind parameter names and values using the params accessor.

매개 변수:
  • bind – An Engine or Connection from which a Compiled will be acquired. This argument takes precedence over this ClauseElement‘s bound engine, if any.
  • column_keys – Used for INSERT and UPDATE statements, a list of column names which should be present in the VALUES clause of the compiled statement. If None, all columns from the target table object are rendered.
  • dialect – A Dialect instance from which a Compiled will be acquired. This argument takes precedence over the bind argument as well as this ClauseElement‘s bound engine, if any.
  • inline – Used for INSERT statements, for a dialect which does not support inline retrieval of newly generated primary key columns, will force the expression used to create the new primary key value to be rendered inline within the INSERT statement’s VALUES clause. This typically refers to Sequence execution but may also refer to any server-side default generation function associated with a primary key Column.
  • compile_kwargs

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

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

    버전 0.9.0에 추가.

correspond_on_equivalents(column, equivalents)
inherited from the correspond_on_equivalents() method of FromClause

Return corresponding_column for the given column, or if None search for a match in the given dictionary.

corresponding_column(column, require_embedded=False)
inherited from the corresponding_column() method of FromClause

Given a ColumnElement, return the exported ColumnElement object from this Selectable which corresponds to that original Column via a common ancestor column.

매개 변수:
  • column – the target ColumnElement to be matched
  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this FromClause. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this FromClause.
count(whereclause=None, **params)
inherited from the count() method of FromClause

return a SELECT COUNT generated against this FromClause.

foreign_keys
inherited from the foreign_keys attribute of FromClause

Return the collection of ForeignKey objects which this FromClause references.

join(right, onclause=None, isouter=False, full=False)
inherited from the join() method of FromClause

Return a Join from this FromClause to another FromClause.

E.g.:

from sqlalchemy import join

j = user_table.join(address_table,
                user_table.c.id == address_table.c.user_id)
stmt = select([user_table]).select_from(j)

would emit SQL along the lines of:

SELECT user.id, user.name FROM user
JOIN address ON user.id = address.user_id
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • isouter – if True, render a LEFT OUTER JOIN, instead of JOIN.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN. Implies FromClause.join.isouter.

    버전 1.1에 추가.

더 보기

join() - standalone function

Join - the type of object produced

lateral(name=None)
inherited from the lateral() method of FromClause

Return a LATERAL alias of this FromClause.

The return value is the Lateral construct also provided by the top-level lateral() function.

버전 1.1에 추가.

더 보기

LATERAL correlation - overview of usage.

outerjoin(right, onclause=None, full=False)
inherited from the outerjoin() method of FromClause

Return a Join from this FromClause to another FromClause, with the “isouter” flag set to True.

E.g.:

from sqlalchemy import outerjoin

j = user_table.outerjoin(address_table,
                user_table.c.id == address_table.c.user_id)

The above is equivalent to:

j = user_table.join(
    address_table,
    user_table.c.id == address_table.c.user_id,
    isouter=True)
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN.

    버전 1.1에 추가.

더 보기

FromClause.join()

Join

params(*optionaldict, **kwargs)
inherited from the params() method of ClauseElement

Return a copy with bindparam() elements replaced.

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

>>> clause = column('x') + bindparam('foo')
>>> print clause.compile().params
{'foo':None}
>>> print clause.params({'foo':7}).compile().params
{'foo':7}
primary_key
inherited from the primary_key attribute of FromClause

Return the collection of Column objects which comprise the primary key of this FromClause.

replace_selectable(old, alias)
inherited from the replace_selectable() method of FromClause

replace all occurrences of FromClause ‘old’ with the given Alias object, returning a copy of this FromClause.

select(whereclause=None, **params)
inherited from the select() method of FromClause

return a SELECT of this FromClause.

더 보기

select() - general purpose method which allows for arbitrary column lists.

suffix_with(*expr, **kw)
inherited from the suffix_with() method of HasSuffixes

Add one or more expressions following the statement as a whole.

This is used to support backend-specific suffix keywords on certain constructs.

E.g.:

stmt = select([col1, col2]).cte().suffix_with(
    "cycle empno set y_cycle to 1 default 0", dialect="oracle")

Multiple suffixes can be specified by multiple calls to suffix_with().

매개 변수:
  • *expr – textual or ClauseElement construct which will be rendered following the target clause.
  • **kw – A single keyword ‘dialect’ is accepted. This is an optional string dialect name which will limit rendering of this suffix to only that dialect.
unique_params(*optionaldict, **kwargs)
inherited from the unique_params() method of ClauseElement

Return a copy with bindparam() elements replaced.

Same functionality as params(), except adds unique=True to affected bind parameters so that multiple statements can be used.

class sqlalchemy.sql.expression.Executable

Bases: sqlalchemy.sql.expression.Generative

Mark a ClauseElement as supporting execution.

Executable is a superclass for all “statement” types of objects, including select(), delete(), update(), insert(), text().

bind

Returns the Engine or Connection to which this Executable is bound, or None if none found.

This is a traversal which checks locally, then checks among the “from” clauses of associated objects until a bound engine or connection is found.

execute(*multiparams, **params)

Compile and execute this Executable.

execution_options(**kw)

Set non-SQL options for the statement which take effect during execution.

Execution options can be set on a per-statement or per Connection basis. Additionally, the Engine and ORM Query objects provide access to execution options which they in turn configure upon connections.

The execution_options() method is generative. A new instance of this statement is returned that contains the options:

statement = select([table.c.x, table.c.y])
statement = statement.execution_options(autocommit=True)

Note that only a subset of possible execution options can be applied to a statement - these include “autocommit” and “stream_results”, but not “isolation_level” or “compiled_cache”. See Connection.execution_options() for a full list of possible options.

scalar(*multiparams, **params)

Compile and execute this Executable, returning the result’s scalar representation.

class sqlalchemy.sql.expression.FromClause

Bases: sqlalchemy.sql.expression.Selectable

Represent an element that can be used within the FROM clause of a SELECT statement.

The most common forms of FromClause are the Table and the select() constructs. Key features common to all FromClause objects include:

alias(name=None, flat=False)

return an alias of this FromClause.

This is shorthand for calling:

from sqlalchemy import alias
a = alias(self, name=name)

See alias() for details.

c

An alias for the columns attribute.

columns

A named-based collection of ColumnElement objects maintained by this FromClause.

The columns, or c collection, is the gateway to the construction of SQL expressions using table-bound or other selectable-bound columns:

select([mytable]).where(mytable.c.somecolumn == 5)
correspond_on_equivalents(column, equivalents)

Return corresponding_column for the given column, or if None search for a match in the given dictionary.

corresponding_column(column, require_embedded=False)

Given a ColumnElement, return the exported ColumnElement object from this Selectable which corresponds to that original Column via a common ancestor column.

매개 변수:
  • column – the target ColumnElement to be matched
  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this FromClause. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this FromClause.
count(whereclause=None, **params)

return a SELECT COUNT generated against this FromClause.

description

a brief description of this FromClause.

Used primarily for error message formatting.

foreign_keys

Return the collection of ForeignKey objects which this FromClause references.

is_derived_from(fromclause)

Return True if this FromClause is ‘derived’ from the given FromClause.

An example would be an Alias of a Table is derived from that Table.

join(right, onclause=None, isouter=False, full=False)

Return a Join from this FromClause to another FromClause.

E.g.:

from sqlalchemy import join

j = user_table.join(address_table,
                user_table.c.id == address_table.c.user_id)
stmt = select([user_table]).select_from(j)

would emit SQL along the lines of:

SELECT user.id, user.name FROM user
JOIN address ON user.id = address.user_id
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • isouter – if True, render a LEFT OUTER JOIN, instead of JOIN.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN. Implies FromClause.join.isouter.

    버전 1.1에 추가.

더 보기

join() - standalone function

Join - the type of object produced

lateral(name=None)

Return a LATERAL alias of this FromClause.

The return value is the Lateral construct also provided by the top-level lateral() function.

버전 1.1에 추가.

더 보기

LATERAL correlation - overview of usage.

outerjoin(right, onclause=None, full=False)

Return a Join from this FromClause to another FromClause, with the “isouter” flag set to True.

E.g.:

from sqlalchemy import outerjoin

j = user_table.outerjoin(address_table,
                user_table.c.id == address_table.c.user_id)

The above is equivalent to:

j = user_table.join(
    address_table,
    user_table.c.id == address_table.c.user_id,
    isouter=True)
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN.

    버전 1.1에 추가.

더 보기

FromClause.join()

Join

primary_key

Return the collection of Column objects which comprise the primary key of this FromClause.

replace_selectable(old, alias)

replace all occurrences of FromClause ‘old’ with the given Alias object, returning a copy of this FromClause.

schema = None

Define the ‘schema’ attribute for this FromClause.

This is typically None for most objects except that of Table, where it is taken as the value of the Table.schema argument.

select(whereclause=None, **params)

return a SELECT of this FromClause.

더 보기

select() - general purpose method which allows for arbitrary column lists.

class sqlalchemy.sql.expression.GenerativeSelect(use_labels=False, for_update=False, limit=None, offset=None, order_by=None, group_by=None, bind=None, autocommit=None)

Bases: sqlalchemy.sql.expression.SelectBase

Base class for SELECT statements where additional elements can be added.

This serves as the base for Select and CompoundSelect where elements such as ORDER BY, GROUP BY can be added and column rendering can be controlled. Compare to TextAsFrom, which, while it subclasses SelectBase and is also a SELECT construct, represents a fixed textual string which cannot be altered at this level, only wrapped as a subquery.

버전 0.9.0에 추가: GenerativeSelect was added to provide functionality specific to Select and CompoundSelect while allowing SelectBase to be used for other SELECT-like objects, e.g. TextAsFrom.

alias(name=None, flat=False)
inherited from the alias() method of FromClause

return an alias of this FromClause.

This is shorthand for calling:

from sqlalchemy import alias
a = alias(self, name=name)

See alias() for details.

append_group_by(*clauses)

Append the given GROUP BY criterion applied to this selectable.

The criterion will be appended to any pre-existing GROUP BY criterion.

This is an in-place mutation method; the group_by() method is preferred, as it provides standard method chaining.

append_order_by(*clauses)

Append the given ORDER BY criterion applied to this selectable.

The criterion will be appended to any pre-existing ORDER BY criterion.

This is an in-place mutation method; the order_by() method is preferred, as it provides standard method chaining.

apply_labels()

return a new selectable with the ‘use_labels’ flag set to True.

This will result in column expressions being generated using labels against their table name, such as “SELECT somecolumn AS tablename_somecolumn”. This allows selectables which contain multiple FROM clauses to produce a unique set of column names regardless of name conflicts among the individual FROM clauses.

as_scalar()
inherited from the as_scalar() method of SelectBase

return a ‘scalar’ representation of this selectable, which can be used as a column expression.

Typically, a select statement which has only one column in its columns clause is eligible to be used as a scalar expression.

The returned object is an instance of ScalarSelect.

autocommit()
inherited from the autocommit() method of SelectBase

return a new selectable with the ‘autocommit’ flag set to True.

버전 0.6 폐지: autocommit() is deprecated. Use Executable.execution_options() with the ‘autocommit’ flag.

bind
inherited from the bind attribute of Executable

Returns the Engine or Connection to which this Executable is bound, or None if none found.

This is a traversal which checks locally, then checks among the “from” clauses of associated objects until a bound engine or connection is found.

c
inherited from the c attribute of FromClause

An alias for the columns attribute.

columns
inherited from the columns attribute of FromClause

A named-based collection of ColumnElement objects maintained by this FromClause.

The columns, or c collection, is the gateway to the construction of SQL expressions using table-bound or other selectable-bound columns:

select([mytable]).where(mytable.c.somecolumn == 5)
compare(other, **kw)
inherited from the compare() method of ClauseElement

Compare this ClauseElement to the given ClauseElement.

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

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

compile(bind=None, dialect=None, **kw)
inherited from the compile() method of ClauseElement

Compile this SQL expression.

The return value is a Compiled object. Calling str() or unicode() on the returned value will yield a string representation of the result. The Compiled object also can return a dictionary of bind parameter names and values using the params accessor.

매개 변수:
  • bind – An Engine or Connection from which a Compiled will be acquired. This argument takes precedence over this ClauseElement‘s bound engine, if any.
  • column_keys – Used for INSERT and UPDATE statements, a list of column names which should be present in the VALUES clause of the compiled statement. If None, all columns from the target table object are rendered.
  • dialect – A Dialect instance from which a Compiled will be acquired. This argument takes precedence over the bind argument as well as this ClauseElement‘s bound engine, if any.
  • inline – Used for INSERT statements, for a dialect which does not support inline retrieval of newly generated primary key columns, will force the expression used to create the new primary key value to be rendered inline within the INSERT statement’s VALUES clause. This typically refers to Sequence execution but may also refer to any server-side default generation function associated with a primary key Column.
  • compile_kwargs

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

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

    버전 0.9.0에 추가.

correspond_on_equivalents(column, equivalents)
inherited from the correspond_on_equivalents() method of FromClause

Return corresponding_column for the given column, or if None search for a match in the given dictionary.

corresponding_column(column, require_embedded=False)
inherited from the corresponding_column() method of FromClause

Given a ColumnElement, return the exported ColumnElement object from this Selectable which corresponds to that original Column via a common ancestor column.

매개 변수:
  • column – the target ColumnElement to be matched
  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this FromClause. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this FromClause.
count(whereclause=None, **params)
inherited from the count() method of FromClause

return a SELECT COUNT generated against this FromClause.

cte(name=None, recursive=False)
inherited from the cte() method of HasCTE

Return a new CTE, or Common Table Expression instance.

Common table expressions are a SQL standard whereby SELECT statements can draw upon secondary statements specified along with the primary statement, using a clause called “WITH”. Special semantics regarding UNION can also be employed to allow “recursive” queries, where a SELECT statement can draw upon the set of rows that have previously been selected.

CTEs can also be applied to DML constructs UPDATE, INSERT and DELETE on some databases, both as a source of CTE rows when combined with RETURNING, as well as a consumer of CTE rows.

SQLAlchemy detects CTE objects, which are treated similarly to Alias objects, as special elements to be delivered to the FROM clause of the statement as well as to a WITH clause at the top of the statement.

버전 1.1으로 변경: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.

매개 변수:
  • name – name given to the common table expression. Like _FromClause.alias(), the name can be left as None in which case an anonymous symbol will be used at query compile time.
  • recursive – if True, will render WITH RECURSIVE. A recursive common table expression is intended to be used in conjunction with UNION ALL in order to derive rows from those already selected.

The following examples include two from Postgresql’s documentation at http://www.postgresql.org/docs/current/static/queries-with.html, as well as additional examples.

Example 1, non recursive:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

orders = Table('orders', metadata,
    Column('region', String),
    Column('amount', Integer),
    Column('product', String),
    Column('quantity', Integer)
)

regional_sales = select([
                    orders.c.region,
                    func.sum(orders.c.amount).label('total_sales')
                ]).group_by(orders.c.region).cte("regional_sales")


top_regions = select([regional_sales.c.region]).\
        where(
            regional_sales.c.total_sales >
            select([
                func.sum(regional_sales.c.total_sales)/10
            ])
        ).cte("top_regions")

statement = select([
            orders.c.region,
            orders.c.product,
            func.sum(orders.c.quantity).label("product_units"),
            func.sum(orders.c.amount).label("product_sales")
    ]).where(orders.c.region.in_(
        select([top_regions.c.region])
    )).group_by(orders.c.region, orders.c.product)

result = conn.execute(statement).fetchall()

Example 2, WITH RECURSIVE:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

parts = Table('parts', metadata,
    Column('part', String),
    Column('sub_part', String),
    Column('quantity', Integer),
)

included_parts = select([
                    parts.c.sub_part,
                    parts.c.part,
                    parts.c.quantity]).\
                    where(parts.c.part=='our part').\
                    cte(recursive=True)


incl_alias = included_parts.alias()
parts_alias = parts.alias()
included_parts = included_parts.union_all(
    select([
        parts_alias.c.sub_part,
        parts_alias.c.part,
        parts_alias.c.quantity
    ]).
        where(parts_alias.c.part==incl_alias.c.sub_part)
)

statement = select([
            included_parts.c.sub_part,
            func.sum(included_parts.c.quantity).
              label('total_quantity')
        ]).\
        group_by(included_parts.c.sub_part)

result = conn.execute(statement).fetchall()

Example 3, an upsert using UPDATE and INSERT with CTEs:

orders = table(
    'orders',
    column('region'),
    column('amount'),
    column('product'),
    column('quantity')
)

upsert = (
    orders.update()
    .where(orders.c.region == 'Region1')
    .values(amount=1.0, product='Product1', quantity=1)
    .returning(*(orders.c._all_columns)).cte('upsert'))

insert = orders.insert().from_select(
    orders.c.keys(),
    select([
        literal('Region1'), literal(1.0),
        literal('Product1'), literal(1)
    ).where(exists(upsert.select()))
)

connection.execute(insert)

더 보기

orm.query.Query.cte() - ORM version of HasCTE.cte().

description
inherited from the description attribute of FromClause

a brief description of this FromClause.

Used primarily for error message formatting.

execute(*multiparams, **params)
inherited from the execute() method of Executable

Compile and execute this Executable.

execution_options(**kw)
inherited from the execution_options() method of Executable

Set non-SQL options for the statement which take effect during execution.

Execution options can be set on a per-statement or per Connection basis. Additionally, the Engine and ORM Query objects provide access to execution options which they in turn configure upon connections.

The execution_options() method is generative. A new instance of this statement is returned that contains the options:

statement = select([table.c.x, table.c.y])
statement = statement.execution_options(autocommit=True)

Note that only a subset of possible execution options can be applied to a statement - these include “autocommit” and “stream_results”, but not “isolation_level” or “compiled_cache”. See Connection.execution_options() for a full list of possible options.

for_update

Provide legacy dialect support for the for_update attribute.

foreign_keys
inherited from the foreign_keys attribute of FromClause

Return the collection of ForeignKey objects which this FromClause references.

get_children(**kwargs)
inherited from the get_children() method of ClauseElement

Return immediate child elements of this ClauseElement.

This is used for visit traversal.

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

group_by(*clauses)

return a new selectable with the given list of GROUP BY criterion applied.

The criterion will be appended to any pre-existing GROUP BY criterion.

is_derived_from(fromclause)
inherited from the is_derived_from() method of FromClause

Return True if this FromClause is ‘derived’ from the given FromClause.

An example would be an Alias of a Table is derived from that Table.

join(right, onclause=None, isouter=False, full=False)
inherited from the join() method of FromClause

Return a Join from this FromClause to another FromClause.

E.g.:

from sqlalchemy import join

j = user_table.join(address_table,
                user_table.c.id == address_table.c.user_id)
stmt = select([user_table]).select_from(j)

would emit SQL along the lines of:

SELECT user.id, user.name FROM user
JOIN address ON user.id = address.user_id
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • isouter – if True, render a LEFT OUTER JOIN, instead of JOIN.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN. Implies FromClause.join.isouter.

    버전 1.1에 추가.

더 보기

join() - standalone function

Join - the type of object produced

label(name)
inherited from the label() method of SelectBase

return a ‘scalar’ representation of this selectable, embedded as a subquery with a label.

더 보기

as_scalar().

lateral(name=None)
inherited from the lateral() method of FromClause

Return a LATERAL alias of this FromClause.

The return value is the Lateral construct also provided by the top-level lateral() function.

버전 1.1에 추가.

더 보기

LATERAL correlation - overview of usage.

limit(limit)

return a new selectable with the given LIMIT criterion applied.

This is a numerical value which usually renders as a LIMIT expression in the resulting select. Backends that don’t support LIMIT will attempt to provide similar functionality.

버전 1.0.0으로 변경: - Select.limit() can now accept arbitrary SQL expressions as well as integer values.

매개 변수:limit – an integer LIMIT parameter, or a SQL expression that provides an integer result.
offset(offset)

return a new selectable with the given OFFSET criterion applied.

This is a numeric value which usually renders as an OFFSET expression in the resulting select. Backends that don’t support OFFSET will attempt to provide similar functionality.

버전 1.0.0으로 변경: - Select.offset() can now accept arbitrary SQL expressions as well as integer values.

매개 변수:offset – an integer OFFSET parameter, or a SQL expression that provides an integer result.
order_by(*clauses)

return a new selectable with the given list of ORDER BY criterion applied.

The criterion will be appended to any pre-existing ORDER BY criterion.

outerjoin(right, onclause=None, full=False)
inherited from the outerjoin() method of FromClause

Return a Join from this FromClause to another FromClause, with the “isouter” flag set to True.

E.g.:

from sqlalchemy import outerjoin

j = user_table.outerjoin(address_table,
                user_table.c.id == address_table.c.user_id)

The above is equivalent to:

j = user_table.join(
    address_table,
    user_table.c.id == address_table.c.user_id,
    isouter=True)
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN.

    버전 1.1에 추가.

더 보기

FromClause.join()

Join

params(*optionaldict, **kwargs)
inherited from the params() method of ClauseElement

Return a copy with bindparam() elements replaced.

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

>>> clause = column('x') + bindparam('foo')
>>> print clause.compile().params
{'foo':None}
>>> print clause.params({'foo':7}).compile().params
{'foo':7}
primary_key
inherited from the primary_key attribute of FromClause

Return the collection of Column objects which comprise the primary key of this FromClause.

replace_selectable(old, alias)
inherited from the replace_selectable() method of FromClause

replace all occurrences of FromClause ‘old’ with the given Alias object, returning a copy of this FromClause.

scalar(*multiparams, **params)
inherited from the scalar() method of Executable

Compile and execute this Executable, returning the result’s scalar representation.

select(whereclause=None, **params)
inherited from the select() method of FromClause

return a SELECT of this FromClause.

더 보기

select() - general purpose method which allows for arbitrary column lists.

self_group(against=None)
inherited from the self_group() method of ClauseElement

Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a “grouping” construct, i.e. parenthesis. In particular it’s used by “binary” expressions to provide a grouping around themselves when placed into a larger expression, as well as by select() constructs when placed into the FROM clause of another select(). (Note that subqueries should be normally created using the Select.alias() method, as many platforms require nested SELECT statements to be named).

As expressions are composed together, the application of self_group() is automatic - end-user code should never need to use this method directly. Note that SQLAlchemy’s clause constructs take operator precedence into account - so parenthesis might not be needed, for example, in an expression like x OR (y AND z) - AND takes precedence over OR.

The base self_group() method of ClauseElement just returns self.

unique_params(*optionaldict, **kwargs)
inherited from the unique_params() method of ClauseElement

Return a copy with bindparam() elements replaced.

Same functionality as params(), except adds unique=True to affected bind parameters so that multiple statements can be used.

with_for_update(nowait=False, read=False, of=None)

Specify a FOR UPDATE clause for this GenerativeSelect.

E.g.:

stmt = select([table]).with_for_update(nowait=True)

On a database like Postgresql or Oracle, the above would render a statement like:

SELECT table.a, table.b FROM table FOR UPDATE NOWAIT

on other backends, the nowait option is ignored and instead would produce:

SELECT table.a, table.b FROM table FOR UPDATE

When called with no arguments, the statement will render with the suffix FOR UPDATE. Additional arguments can then be provided which allow for common database-specific variants.

매개 변수:
  • nowait – boolean; will render FOR UPDATE NOWAIT on Oracle and Postgresql dialects.
  • read – boolean; will render LOCK IN SHARE MODE on MySQL, FOR SHARE on Postgresql. On Postgresql, when combined with nowait, will render FOR SHARE NOWAIT.
  • of – SQL expression or list of SQL expression elements (typically Column objects or a compatible expression) which will render into a FOR UPDATE OF clause; supported by PostgreSQL and Oracle. May render as a table or as a column depending on backend.

버전 0.9.0에 추가.

class sqlalchemy.sql.expression.HasCTE

Mixin that declares a class to include CTE support.

버전 1.1에 추가.

cte(name=None, recursive=False)

Return a new CTE, or Common Table Expression instance.

Common table expressions are a SQL standard whereby SELECT statements can draw upon secondary statements specified along with the primary statement, using a clause called “WITH”. Special semantics regarding UNION can also be employed to allow “recursive” queries, where a SELECT statement can draw upon the set of rows that have previously been selected.

CTEs can also be applied to DML constructs UPDATE, INSERT and DELETE on some databases, both as a source of CTE rows when combined with RETURNING, as well as a consumer of CTE rows.

SQLAlchemy detects CTE objects, which are treated similarly to Alias objects, as special elements to be delivered to the FROM clause of the statement as well as to a WITH clause at the top of the statement.

버전 1.1으로 변경: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.

매개 변수:
  • name – name given to the common table expression. Like _FromClause.alias(), the name can be left as None in which case an anonymous symbol will be used at query compile time.
  • recursive – if True, will render WITH RECURSIVE. A recursive common table expression is intended to be used in conjunction with UNION ALL in order to derive rows from those already selected.

The following examples include two from Postgresql’s documentation at http://www.postgresql.org/docs/current/static/queries-with.html, as well as additional examples.

Example 1, non recursive:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

orders = Table('orders', metadata,
    Column('region', String),
    Column('amount', Integer),
    Column('product', String),
    Column('quantity', Integer)
)

regional_sales = select([
                    orders.c.region,
                    func.sum(orders.c.amount).label('total_sales')
                ]).group_by(orders.c.region).cte("regional_sales")


top_regions = select([regional_sales.c.region]).\
        where(
            regional_sales.c.total_sales >
            select([
                func.sum(regional_sales.c.total_sales)/10
            ])
        ).cte("top_regions")

statement = select([
            orders.c.region,
            orders.c.product,
            func.sum(orders.c.quantity).label("product_units"),
            func.sum(orders.c.amount).label("product_sales")
    ]).where(orders.c.region.in_(
        select([top_regions.c.region])
    )).group_by(orders.c.region, orders.c.product)

result = conn.execute(statement).fetchall()

Example 2, WITH RECURSIVE:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

parts = Table('parts', metadata,
    Column('part', String),
    Column('sub_part', String),
    Column('quantity', Integer),
)

included_parts = select([
                    parts.c.sub_part,
                    parts.c.part,
                    parts.c.quantity]).\
                    where(parts.c.part=='our part').\
                    cte(recursive=True)


incl_alias = included_parts.alias()
parts_alias = parts.alias()
included_parts = included_parts.union_all(
    select([
        parts_alias.c.sub_part,
        parts_alias.c.part,
        parts_alias.c.quantity
    ]).
        where(parts_alias.c.part==incl_alias.c.sub_part)
)

statement = select([
            included_parts.c.sub_part,
            func.sum(included_parts.c.quantity).
              label('total_quantity')
        ]).\
        group_by(included_parts.c.sub_part)

result = conn.execute(statement).fetchall()

Example 3, an upsert using UPDATE and INSERT with CTEs:

orders = table(
    'orders',
    column('region'),
    column('amount'),
    column('product'),
    column('quantity')
)

upsert = (
    orders.update()
    .where(orders.c.region == 'Region1')
    .values(amount=1.0, product='Product1', quantity=1)
    .returning(*(orders.c._all_columns)).cte('upsert'))

insert = orders.insert().from_select(
    orders.c.keys(),
    select([
        literal('Region1'), literal(1.0),
        literal('Product1'), literal(1)
    ).where(exists(upsert.select()))
)

connection.execute(insert)

더 보기

orm.query.Query.cte() - ORM version of HasCTE.cte().

class sqlalchemy.sql.expression.HasPrefixes
prefix_with(*expr, **kw)

Add one or more expressions following the statement keyword, i.e. SELECT, INSERT, UPDATE, or DELETE. Generative.

This is used to support backend-specific prefix keywords such as those provided by MySQL.

E.g.:

stmt = table.insert().prefix_with("LOW_PRIORITY", dialect="mysql")

Multiple prefixes can be specified by multiple calls to prefix_with().

매개 변수:
  • *expr – textual or ClauseElement construct which will be rendered following the INSERT, UPDATE, or DELETE keyword.
  • **kw – A single keyword ‘dialect’ is accepted. This is an optional string dialect name which will limit rendering of this prefix to only that dialect.
class sqlalchemy.sql.expression.HasSuffixes
suffix_with(*expr, **kw)

Add one or more expressions following the statement as a whole.

This is used to support backend-specific suffix keywords on certain constructs.

E.g.:

stmt = select([col1, col2]).cte().suffix_with(
    "cycle empno set y_cycle to 1 default 0", dialect="oracle")

Multiple suffixes can be specified by multiple calls to suffix_with().

매개 변수:
  • *expr – textual or ClauseElement construct which will be rendered following the target clause.
  • **kw – A single keyword ‘dialect’ is accepted. This is an optional string dialect name which will limit rendering of this suffix to only that dialect.
class sqlalchemy.sql.expression.Join(left, right, onclause=None, isouter=False, full=False)

Bases: sqlalchemy.sql.expression.FromClause

represent a JOIN construct between two FromClause elements.

The public constructor function for Join is the module-level join() function, as well as the FromClause.join() method of any FromClause (e.g. such as Table).

__init__(left, right, onclause=None, isouter=False, full=False)

Construct a new Join.

The usual entrypoint here is the join() function or the FromClause.join() method of any FromClause object.

alias(name=None, flat=False)

return an alias of this Join.

The default behavior here is to first produce a SELECT construct from this Join, then to produce an Alias from that. So given a join of the form:

j = table_a.join(table_b, table_a.c.id == table_b.c.a_id)

The JOIN by itself would look like:

table_a JOIN table_b ON table_a.id = table_b.a_id

Whereas the alias of the above, j.alias(), would in a SELECT context look like:

(SELECT table_a.id AS table_a_id, table_b.id AS table_b_id,
    table_b.a_id AS table_b_a_id
    FROM table_a
    JOIN table_b ON table_a.id = table_b.a_id) AS anon_1

The equivalent long-hand form, given a Join object j, is:

from sqlalchemy import select, alias
j = alias(
    select([j.left, j.right]).\
        select_from(j).\
        with_labels(True).\
        correlate(False),
    name=name
)

The selectable produced by Join.alias() features the same columns as that of the two individual selectables presented under a single name - the individual columns are “auto-labeled”, meaning the .c. collection of the resulting Alias represents the names of the individual columns using a <tablename>_<columname> scheme:

j.c.table_a_id
j.c.table_b_a_id

Join.alias() also features an alternate option for aliasing joins which produces no enclosing SELECT and does not normally apply labels to the column names. The flat=True option will call FromClause.alias() against the left and right sides individually. Using this option, no new SELECT is produced; we instead, from a construct as below:

j = table_a.join(table_b, table_a.c.id == table_b.c.a_id)
j = j.alias(flat=True)

we get a result like this:

table_a AS table_a_1 JOIN table_b AS table_b_1 ON
table_a_1.id = table_b_1.a_id

The flat=True argument is also propagated to the contained selectables, so that a composite join such as:

j = table_a.join(
        table_b.join(table_c,
                table_b.c.id == table_c.c.b_id),
        table_b.c.a_id == table_a.c.id
    ).alias(flat=True)

Will produce an expression like:

table_a AS table_a_1 JOIN (
        table_b AS table_b_1 JOIN table_c AS table_c_1
        ON table_b_1.id = table_c_1.b_id
) ON table_a_1.id = table_b_1.a_id

The standalone alias() function as well as the base FromClause.alias() method also support the flat=True argument as a no-op, so that the argument can be passed to the alias() method of any selectable.

버전 0.9.0에 추가: Added the flat=True option to create “aliases” of joins without enclosing inside of a SELECT subquery.

매개 변수:
  • name – name given to the alias.
  • flat

    if True, produce an alias of the left and right sides of this Join and return the join of those two selectables. This produces join expression that does not include an enclosing SELECT.

    버전 0.9.0에 추가.

더 보기

alias()

c
inherited from the c attribute of FromClause

An alias for the columns attribute.

columns
inherited from the columns attribute of FromClause

A named-based collection of ColumnElement objects maintained by this FromClause.

The columns, or c collection, is the gateway to the construction of SQL expressions using table-bound or other selectable-bound columns:

select([mytable]).where(mytable.c.somecolumn == 5)
compare(other, **kw)
inherited from the compare() method of ClauseElement

Compare this ClauseElement to the given ClauseElement.

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

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

compile(bind=None, dialect=None, **kw)
inherited from the compile() method of ClauseElement

Compile this SQL expression.

The return value is a Compiled object. Calling str() or unicode() on the returned value will yield a string representation of the result. The Compiled object also can return a dictionary of bind parameter names and values using the params accessor.

매개 변수:
  • bind – An Engine or Connection from which a Compiled will be acquired. This argument takes precedence over this ClauseElement‘s bound engine, if any.
  • column_keys – Used for INSERT and UPDATE statements, a list of column names which should be present in the VALUES clause of the compiled statement. If None, all columns from the target table object are rendered.
  • dialect – A Dialect instance from which a Compiled will be acquired. This argument takes precedence over the bind argument as well as this ClauseElement‘s bound engine, if any.
  • inline – Used for INSERT statements, for a dialect which does not support inline retrieval of newly generated primary key columns, will force the expression used to create the new primary key value to be rendered inline within the INSERT statement’s VALUES clause. This typically refers to Sequence execution but may also refer to any server-side default generation function associated with a primary key Column.
  • compile_kwargs

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

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

    버전 0.9.0에 추가.

correspond_on_equivalents(column, equivalents)
inherited from the correspond_on_equivalents() method of FromClause

Return corresponding_column for the given column, or if None search for a match in the given dictionary.

corresponding_column(column, require_embedded=False)
inherited from the corresponding_column() method of FromClause

Given a ColumnElement, return the exported ColumnElement object from this Selectable which corresponds to that original Column via a common ancestor column.

매개 변수:
  • column – the target ColumnElement to be matched
  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this FromClause. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this FromClause.
count(whereclause=None, **params)
inherited from the count() method of FromClause

return a SELECT COUNT generated against this FromClause.

foreign_keys
inherited from the foreign_keys attribute of FromClause

Return the collection of ForeignKey objects which this FromClause references.

join(right, onclause=None, isouter=False, full=False)
inherited from the join() method of FromClause

Return a Join from this FromClause to another FromClause.

E.g.:

from sqlalchemy import join

j = user_table.join(address_table,
                user_table.c.id == address_table.c.user_id)
stmt = select([user_table]).select_from(j)

would emit SQL along the lines of:

SELECT user.id, user.name FROM user
JOIN address ON user.id = address.user_id
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • isouter – if True, render a LEFT OUTER JOIN, instead of JOIN.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN. Implies FromClause.join.isouter.

    버전 1.1에 추가.

더 보기

join() - standalone function

Join - the type of object produced

lateral(name=None)
inherited from the lateral() method of FromClause

Return a LATERAL alias of this FromClause.

The return value is the Lateral construct also provided by the top-level lateral() function.

버전 1.1에 추가.

더 보기

LATERAL correlation - overview of usage.

outerjoin(right, onclause=None, full=False)
inherited from the outerjoin() method of FromClause

Return a Join from this FromClause to another FromClause, with the “isouter” flag set to True.

E.g.:

from sqlalchemy import outerjoin

j = user_table.outerjoin(address_table,
                user_table.c.id == address_table.c.user_id)

The above is equivalent to:

j = user_table.join(
    address_table,
    user_table.c.id == address_table.c.user_id,
    isouter=True)
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN.

    버전 1.1에 추가.

더 보기

FromClause.join()

Join

params(*optionaldict, **kwargs)
inherited from the params() method of ClauseElement

Return a copy with bindparam() elements replaced.

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

>>> clause = column('x') + bindparam('foo')
>>> print clause.compile().params
{'foo':None}
>>> print clause.params({'foo':7}).compile().params
{'foo':7}
primary_key
inherited from the primary_key attribute of FromClause

Return the collection of Column objects which comprise the primary key of this FromClause.

replace_selectable(old, alias)
inherited from the replace_selectable() method of FromClause

replace all occurrences of FromClause ‘old’ with the given Alias object, returning a copy of this FromClause.

select(whereclause=None, **kwargs)

Create a Select from this Join.

The equivalent long-hand form, given a Join object j, is:

from sqlalchemy import select
j = select([j.left, j.right], **kw).\
            where(whereclause).\
            select_from(j)
매개 변수:
  • whereclause – the WHERE criterion that will be sent to the select() function
  • **kwargs – all other kwargs are sent to the underlying select() function.
unique_params(*optionaldict, **kwargs)
inherited from the unique_params() method of ClauseElement

Return a copy with bindparam() elements replaced.

Same functionality as params(), except adds unique=True to affected bind parameters so that multiple statements can be used.

class sqlalchemy.sql.expression.Lateral(selectable, name=None)

Bases: sqlalchemy.sql.expression.Alias

Represent a LATERAL subquery.

This object is constructed from the lateral() module level function as well as the FromClause.lateral() method available on all FromClause subclasses.

While LATERAL is part of the SQL standard, curently only more recent Postgresql versions provide support for this keyword.

버전 1.1에 추가.

더 보기

LATERAL correlation - overview of usage.

class sqlalchemy.sql.expression.ScalarSelect(element)

Bases: sqlalchemy.sql.expression.Generative, sqlalchemy.sql.expression.Grouping

where(crit)

Apply a WHERE clause to the SELECT statement referred to by this ScalarSelect.

class sqlalchemy.sql.expression.Select(columns=None, whereclause=None, from_obj=None, distinct=False, having=None, correlate=True, prefixes=None, suffixes=None, **kwargs)

Bases: sqlalchemy.sql.expression.HasPrefixes, sqlalchemy.sql.expression.HasSuffixes, sqlalchemy.sql.expression.GenerativeSelect

Represents a SELECT statement.

__init__(columns=None, whereclause=None, from_obj=None, distinct=False, having=None, correlate=True, prefixes=None, suffixes=None, **kwargs)

Construct a new Select object.

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

alias(name=None, flat=False)
inherited from the alias() method of FromClause

return an alias of this FromClause.

This is shorthand for calling:

from sqlalchemy import alias
a = alias(self, name=name)

See alias() for details.

append_column(column)

append the given column expression to the columns clause of this select() construct.

This is an in-place mutation method; the column() method is preferred, as it provides standard method chaining.

append_correlation(fromclause)

append the given correlation expression to this select() construct.

This is an in-place mutation method; the correlate() method is preferred, as it provides standard method chaining.

append_from(fromclause)

append the given FromClause expression to this select() construct’s FROM clause.

This is an in-place mutation method; the select_from() method is preferred, as it provides standard method chaining.

append_group_by(*clauses)
inherited from the append_group_by() method of GenerativeSelect

Append the given GROUP BY criterion applied to this selectable.

The criterion will be appended to any pre-existing GROUP BY criterion.

This is an in-place mutation method; the group_by() method is preferred, as it provides standard method chaining.

append_having(having)

append the given expression to this select() construct’s HAVING criterion.

The expression will be joined to existing HAVING criterion via AND.

This is an in-place mutation method; the having() method is preferred, as it provides standard method chaining.

append_order_by(*clauses)
inherited from the append_order_by() method of GenerativeSelect

Append the given ORDER BY criterion applied to this selectable.

The criterion will be appended to any pre-existing ORDER BY criterion.

This is an in-place mutation method; the order_by() method is preferred, as it provides standard method chaining.

append_prefix(clause)

append the given columns clause prefix expression to this select() construct.

This is an in-place mutation method; the prefix_with() method is preferred, as it provides standard method chaining.

append_whereclause(whereclause)

append the given expression to this select() construct’s WHERE criterion.

The expression will be joined to existing WHERE criterion via AND.

This is an in-place mutation method; the where() method is preferred, as it provides standard method chaining.

apply_labels()
inherited from the apply_labels() method of GenerativeSelect

return a new selectable with the ‘use_labels’ flag set to True.

This will result in column expressions being generated using labels against their table name, such as “SELECT somecolumn AS tablename_somecolumn”. This allows selectables which contain multiple FROM clauses to produce a unique set of column names regardless of name conflicts among the individual FROM clauses.

as_scalar()
inherited from the as_scalar() method of SelectBase

return a ‘scalar’ representation of this selectable, which can be used as a column expression.

Typically, a select statement which has only one column in its columns clause is eligible to be used as a scalar expression.

The returned object is an instance of ScalarSelect.

autocommit()
inherited from the autocommit() method of SelectBase

return a new selectable with the ‘autocommit’ flag set to True.

버전 0.6 폐지: autocommit() is deprecated. Use Executable.execution_options() with the ‘autocommit’ flag.

c
inherited from the c attribute of FromClause

An alias for the columns attribute.

column(column)

return a new select() construct with the given column expression added to its columns clause.

columns
inherited from the columns attribute of FromClause

A named-based collection of ColumnElement objects maintained by this FromClause.

The columns, or c collection, is the gateway to the construction of SQL expressions using table-bound or other selectable-bound columns:

select([mytable]).where(mytable.c.somecolumn == 5)
compare(other, **kw)
inherited from the compare() method of ClauseElement

Compare this ClauseElement to the given ClauseElement.

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

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

compile(bind=None, dialect=None, **kw)
inherited from the compile() method of ClauseElement

Compile this SQL expression.

The return value is a Compiled object. Calling str() or unicode() on the returned value will yield a string representation of the result. The Compiled object also can return a dictionary of bind parameter names and values using the params accessor.

매개 변수:
  • bind – An Engine or Connection from which a Compiled will be acquired. This argument takes precedence over this ClauseElement‘s bound engine, if any.
  • column_keys – Used for INSERT and UPDATE statements, a list of column names which should be present in the VALUES clause of the compiled statement. If None, all columns from the target table object are rendered.
  • dialect – A Dialect instance from which a Compiled will be acquired. This argument takes precedence over the bind argument as well as this ClauseElement‘s bound engine, if any.
  • inline – Used for INSERT statements, for a dialect which does not support inline retrieval of newly generated primary key columns, will force the expression used to create the new primary key value to be rendered inline within the INSERT statement’s VALUES clause. This typically refers to Sequence execution but may also refer to any server-side default generation function associated with a primary key Column.
  • compile_kwargs

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

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

    버전 0.9.0에 추가.

correlate(*fromclauses)

return a new Select which will correlate the given FROM clauses to that of an enclosing Select.

Calling this method turns off the Select object’s default behavior of “auto-correlation”. Normally, FROM elements which appear in a Select that encloses this one via its WHERE clause, ORDER BY, HAVING or columns clause will be omitted from this Select object’s FROM clause. Setting an explicit correlation collection using the Select.correlate() method provides a fixed list of FROM objects that can potentially take place in this process.

When Select.correlate() is used to apply specific FROM clauses for correlation, the FROM elements become candidates for correlation regardless of how deeply nested this Select object is, relative to an enclosing Select which refers to the same FROM object. This is in contrast to the behavior of “auto-correlation” which only correlates to an immediate enclosing Select. Multi-level correlation ensures that the link between enclosed and enclosing Select is always via at least one WHERE/ORDER BY/HAVING/columns clause in order for correlation to take place.

If None is passed, the Select object will correlate none of its FROM entries, and all will render unconditionally in the local FROM clause.

매개 변수:*fromclauses

a list of one or more FromClause constructs, or other compatible constructs (i.e. ORM-mapped classes) to become part of the correlate collection.

버전 0.8.0으로 변경: ORM-mapped classes are accepted by Select.correlate().

버전 0.8.0으로 변경: The Select.correlate() method no longer unconditionally removes entries from the FROM clause; instead, the candidate FROM entries must also be matched by a FROM entry located in an enclosing Select, which ultimately encloses this one as present in the WHERE clause, ORDER BY clause, HAVING clause, or columns clause of an enclosing Select().

버전 0.8.2으로 변경: explicit correlation takes place via any level of nesting of Select objects; in previous 0.8 versions, correlation would only occur relative to the immediate enclosing Select construct.

correlate_except(*fromclauses)

return a new Select which will omit the given FROM clauses from the auto-correlation process.

Calling Select.correlate_except() turns off the Select object’s default behavior of “auto-correlation” for the given FROM elements. An element specified here will unconditionally appear in the FROM list, while all other FROM elements remain subject to normal auto-correlation behaviors.

버전 0.8.2으로 변경: The Select.correlate_except() method was improved to fully prevent FROM clauses specified here from being omitted from the immediate FROM clause of this Select.

If None is passed, the Select object will correlate all of its FROM entries.

버전 0.8.2으로 변경: calling correlate_except(None) will correctly auto-correlate all FROM clauses.

매개 변수:*fromclauses – a list of one or more FromClause constructs, or other compatible constructs (i.e. ORM-mapped classes) to become part of the correlate-exception collection.
correspond_on_equivalents(column, equivalents)
inherited from the correspond_on_equivalents() method of FromClause

Return corresponding_column for the given column, or if None search for a match in the given dictionary.

corresponding_column(column, require_embedded=False)
inherited from the corresponding_column() method of FromClause

Given a ColumnElement, return the exported ColumnElement object from this Selectable which corresponds to that original Column via a common ancestor column.

매개 변수:
  • column – the target ColumnElement to be matched
  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this FromClause. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this FromClause.
count(whereclause=None, **params)
inherited from the count() method of FromClause

return a SELECT COUNT generated against this FromClause.

cte(name=None, recursive=False)
inherited from the cte() method of HasCTE

Return a new CTE, or Common Table Expression instance.

Common table expressions are a SQL standard whereby SELECT statements can draw upon secondary statements specified along with the primary statement, using a clause called “WITH”. Special semantics regarding UNION can also be employed to allow “recursive” queries, where a SELECT statement can draw upon the set of rows that have previously been selected.

CTEs can also be applied to DML constructs UPDATE, INSERT and DELETE on some databases, both as a source of CTE rows when combined with RETURNING, as well as a consumer of CTE rows.

SQLAlchemy detects CTE objects, which are treated similarly to Alias objects, as special elements to be delivered to the FROM clause of the statement as well as to a WITH clause at the top of the statement.

버전 1.1으로 변경: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.

매개 변수:
  • name – name given to the common table expression. Like _FromClause.alias(), the name can be left as None in which case an anonymous symbol will be used at query compile time.
  • recursive – if True, will render WITH RECURSIVE. A recursive common table expression is intended to be used in conjunction with UNION ALL in order to derive rows from those already selected.

The following examples include two from Postgresql’s documentation at http://www.postgresql.org/docs/current/static/queries-with.html, as well as additional examples.

Example 1, non recursive:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

orders = Table('orders', metadata,
    Column('region', String),
    Column('amount', Integer),
    Column('product', String),
    Column('quantity', Integer)
)

regional_sales = select([
                    orders.c.region,
                    func.sum(orders.c.amount).label('total_sales')
                ]).group_by(orders.c.region).cte("regional_sales")


top_regions = select([regional_sales.c.region]).\
        where(
            regional_sales.c.total_sales >
            select([
                func.sum(regional_sales.c.total_sales)/10
            ])
        ).cte("top_regions")

statement = select([
            orders.c.region,
            orders.c.product,
            func.sum(orders.c.quantity).label("product_units"),
            func.sum(orders.c.amount).label("product_sales")
    ]).where(orders.c.region.in_(
        select([top_regions.c.region])
    )).group_by(orders.c.region, orders.c.product)

result = conn.execute(statement).fetchall()

Example 2, WITH RECURSIVE:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

parts = Table('parts', metadata,
    Column('part', String),
    Column('sub_part', String),
    Column('quantity', Integer),
)

included_parts = select([
                    parts.c.sub_part,
                    parts.c.part,
                    parts.c.quantity]).\
                    where(parts.c.part=='our part').\
                    cte(recursive=True)


incl_alias = included_parts.alias()
parts_alias = parts.alias()
included_parts = included_parts.union_all(
    select([
        parts_alias.c.sub_part,
        parts_alias.c.part,
        parts_alias.c.quantity
    ]).
        where(parts_alias.c.part==incl_alias.c.sub_part)
)

statement = select([
            included_parts.c.sub_part,
            func.sum(included_parts.c.quantity).
              label('total_quantity')
        ]).\
        group_by(included_parts.c.sub_part)

result = conn.execute(statement).fetchall()

Example 3, an upsert using UPDATE and INSERT with CTEs:

orders = table(
    'orders',
    column('region'),
    column('amount'),
    column('product'),
    column('quantity')
)

upsert = (
    orders.update()
    .where(orders.c.region == 'Region1')
    .values(amount=1.0, product='Product1', quantity=1)
    .returning(*(orders.c._all_columns)).cte('upsert'))

insert = orders.insert().from_select(
    orders.c.keys(),
    select([
        literal('Region1'), literal(1.0),
        literal('Product1'), literal(1)
    ).where(exists(upsert.select()))
)

connection.execute(insert)

더 보기

orm.query.Query.cte() - ORM version of HasCTE.cte().

description
inherited from the description attribute of FromClause

a brief description of this FromClause.

Used primarily for error message formatting.

distinct(*expr)

Return a new select() construct which will apply DISTINCT to its columns clause.

매개 변수:*expr – optional column expressions. When present, the Postgresql dialect will render a DISTINCT ON (<expressions>>) construct.
except_(other, **kwargs)

return a SQL EXCEPT of this select() construct against the given selectable.

except_all(other, **kwargs)

return a SQL EXCEPT ALL of this select() construct against the given selectable.

execute(*multiparams, **params)
inherited from the execute() method of Executable

Compile and execute this Executable.

execution_options(**kw)
inherited from the execution_options() method of Executable

Set non-SQL options for the statement which take effect during execution.

Execution options can be set on a per-statement or per Connection basis. Additionally, the Engine and ORM Query objects provide access to execution options which they in turn configure upon connections.

The execution_options() method is generative. A new instance of this statement is returned that contains the options:

statement = select([table.c.x, table.c.y])
statement = statement.execution_options(autocommit=True)

Note that only a subset of possible execution options can be applied to a statement - these include “autocommit” and “stream_results”, but not “isolation_level” or “compiled_cache”. See Connection.execution_options() for a full list of possible options.

for_update
inherited from the for_update attribute of GenerativeSelect

Provide legacy dialect support for the for_update attribute.

foreign_keys
inherited from the foreign_keys attribute of FromClause

Return the collection of ForeignKey objects which this FromClause references.

froms

Return the displayed list of FromClause elements.

get_children(column_collections=True, **kwargs)

return child elements as per the ClauseElement specification.

group_by(*clauses)
inherited from the group_by() method of GenerativeSelect

return a new selectable with the given list of GROUP BY criterion applied.

The criterion will be appended to any pre-existing GROUP BY criterion.

having(having)

return a new select() construct with the given expression added to its HAVING clause, joined to the existing clause via AND, if any.

inner_columns

an iterator of all ColumnElement expressions which would be rendered into the columns clause of the resulting SELECT statement.

intersect(other, **kwargs)

return a SQL INTERSECT of this select() construct against the given selectable.

intersect_all(other, **kwargs)

return a SQL INTERSECT ALL of this select() construct against the given selectable.

join(right, onclause=None, isouter=False, full=False)
inherited from the join() method of FromClause

Return a Join from this FromClause to another FromClause.

E.g.:

from sqlalchemy import join

j = user_table.join(address_table,
                user_table.c.id == address_table.c.user_id)
stmt = select([user_table]).select_from(j)

would emit SQL along the lines of:

SELECT user.id, user.name FROM user
JOIN address ON user.id = address.user_id
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • isouter – if True, render a LEFT OUTER JOIN, instead of JOIN.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN. Implies FromClause.join.isouter.

    버전 1.1에 추가.

더 보기

join() - standalone function

Join - the type of object produced

label(name)
inherited from the label() method of SelectBase

return a ‘scalar’ representation of this selectable, embedded as a subquery with a label.

더 보기

as_scalar().

lateral(name=None)
inherited from the lateral() method of FromClause

Return a LATERAL alias of this FromClause.

The return value is the Lateral construct also provided by the top-level lateral() function.

버전 1.1에 추가.

더 보기

LATERAL correlation - overview of usage.

limit(limit)
inherited from the limit() method of GenerativeSelect

return a new selectable with the given LIMIT criterion applied.

This is a numerical value which usually renders as a LIMIT expression in the resulting select. Backends that don’t support LIMIT will attempt to provide similar functionality.

버전 1.0.0으로 변경: - Select.limit() can now accept arbitrary SQL expressions as well as integer values.

매개 변수:limit – an integer LIMIT parameter, or a SQL expression that provides an integer result.
locate_all_froms(*args, **kw)

return a Set of all FromClause elements referenced by this Select.

This set is a superset of that returned by the froms property, which is specifically for those FromClause elements that would actually be rendered.

offset(offset)
inherited from the offset() method of GenerativeSelect

return a new selectable with the given OFFSET criterion applied.

This is a numeric value which usually renders as an OFFSET expression in the resulting select. Backends that don’t support OFFSET will attempt to provide similar functionality.

버전 1.0.0으로 변경: - Select.offset() can now accept arbitrary SQL expressions as well as integer values.

매개 변수:offset – an integer OFFSET parameter, or a SQL expression that provides an integer result.
order_by(*clauses)
inherited from the order_by() method of GenerativeSelect

return a new selectable with the given list of ORDER BY criterion applied.

The criterion will be appended to any pre-existing ORDER BY criterion.

outerjoin(right, onclause=None, full=False)
inherited from the outerjoin() method of FromClause

Return a Join from this FromClause to another FromClause, with the “isouter” flag set to True.

E.g.:

from sqlalchemy import outerjoin

j = user_table.outerjoin(address_table,
                user_table.c.id == address_table.c.user_id)

The above is equivalent to:

j = user_table.join(
    address_table,
    user_table.c.id == address_table.c.user_id,
    isouter=True)
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN.

    버전 1.1에 추가.

더 보기

FromClause.join()

Join

params(*optionaldict, **kwargs)
inherited from the params() method of ClauseElement

Return a copy with bindparam() elements replaced.

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

>>> clause = column('x') + bindparam('foo')
>>> print clause.compile().params
{'foo':None}
>>> print clause.params({'foo':7}).compile().params
{'foo':7}
prefix_with(*expr, **kw)
inherited from the prefix_with() method of HasPrefixes

Add one or more expressions following the statement keyword, i.e. SELECT, INSERT, UPDATE, or DELETE. Generative.

This is used to support backend-specific prefix keywords such as those provided by MySQL.

E.g.:

stmt = table.insert().prefix_with("LOW_PRIORITY", dialect="mysql")

Multiple prefixes can be specified by multiple calls to prefix_with().

매개 변수:
  • *expr – textual or ClauseElement construct which will be rendered following the INSERT, UPDATE, or DELETE keyword.
  • **kw – A single keyword ‘dialect’ is accepted. This is an optional string dialect name which will limit rendering of this prefix to only that dialect.
primary_key
inherited from the primary_key attribute of FromClause

Return the collection of Column objects which comprise the primary key of this FromClause.

reduce_columns(only_synonyms=True)

Return a new :func`.select` construct with redundantly named, equivalently-valued columns removed from the columns clause.

“Redundant” here means two columns where one refers to the other either based on foreign key, or via a simple equality comparison in the WHERE clause of the statement. The primary purpose of this method is to automatically construct a select statement with all uniquely-named columns, without the need to use table-qualified labels as apply_labels() does.

When columns are omitted based on foreign key, the referred-to column is the one that’s kept. When columns are omitted based on WHERE eqivalence, the first column in the columns clause is the one that’s kept.

매개 변수:only_synonyms – when True, limit the removal of columns to those which have the same name as the equivalent. Otherwise, all columns that are equivalent to another are removed.

버전 0.8에 추가.

replace_selectable(old, alias)
inherited from the replace_selectable() method of FromClause

replace all occurrences of FromClause ‘old’ with the given Alias object, returning a copy of this FromClause.

scalar(*multiparams, **params)
inherited from the scalar() method of Executable

Compile and execute this Executable, returning the result’s scalar representation.

select(whereclause=None, **params)
inherited from the select() method of FromClause

return a SELECT of this FromClause.

더 보기

select() - general purpose method which allows for arbitrary column lists.

select_from(fromclause)

return a new select() construct with the given FROM expression merged into its list of FROM objects.

E.g.:

table1 = table('t1', column('a'))
table2 = table('t2', column('b'))
s = select([table1.c.a]).\
    select_from(
        table1.join(table2, table1.c.a==table2.c.b)
    )

The “from” list is a unique set on the identity of each element, so adding an already present Table or other selectable will have no effect. Passing a Join that refers to an already present Table or other selectable will have the effect of concealing the presence of that selectable as an individual element in the rendered FROM list, instead rendering it into a JOIN clause.

While the typical purpose of Select.select_from() is to replace the default, derived FROM clause with a join, it can also be called with individual table elements, multiple times if desired, in the case that the FROM clause cannot be fully derived from the columns clause:

select([func.count('*')]).select_from(table1)
self_group(against=None)

return a ‘grouping’ construct as per the ClauseElement specification.

This produces an element that can be embedded in an expression. Note that this method is called automatically as needed when constructing expressions and should not require explicit use.

suffix_with(*expr, **kw)
inherited from the suffix_with() method of HasSuffixes

Add one or more expressions following the statement as a whole.

This is used to support backend-specific suffix keywords on certain constructs.

E.g.:

stmt = select([col1, col2]).cte().suffix_with(
    "cycle empno set y_cycle to 1 default 0", dialect="oracle")

Multiple suffixes can be specified by multiple calls to suffix_with().

매개 변수:
  • *expr – textual or ClauseElement construct which will be rendered following the target clause.
  • **kw – A single keyword ‘dialect’ is accepted. This is an optional string dialect name which will limit rendering of this suffix to only that dialect.
union(other, **kwargs)

return a SQL UNION of this select() construct against the given selectable.

union_all(other, **kwargs)

return a SQL UNION ALL of this select() construct against the given selectable.

unique_params(*optionaldict, **kwargs)
inherited from the unique_params() method of ClauseElement

Return a copy with bindparam() elements replaced.

Same functionality as params(), except adds unique=True to affected bind parameters so that multiple statements can be used.

where(whereclause)

return a new select() construct with the given expression added to its WHERE clause, joined to the existing clause via AND, if any.

with_for_update(nowait=False, read=False, of=None)
inherited from the with_for_update() method of GenerativeSelect

Specify a FOR UPDATE clause for this GenerativeSelect.

E.g.:

stmt = select([table]).with_for_update(nowait=True)

On a database like Postgresql or Oracle, the above would render a statement like:

SELECT table.a, table.b FROM table FOR UPDATE NOWAIT

on other backends, the nowait option is ignored and instead would produce:

SELECT table.a, table.b FROM table FOR UPDATE

When called with no arguments, the statement will render with the suffix FOR UPDATE. Additional arguments can then be provided which allow for common database-specific variants.

매개 변수:
  • nowait – boolean; will render FOR UPDATE NOWAIT on Oracle and Postgresql dialects.
  • read – boolean; will render LOCK IN SHARE MODE on MySQL, FOR SHARE on Postgresql. On Postgresql, when combined with nowait, will render FOR SHARE NOWAIT.
  • of – SQL expression or list of SQL expression elements (typically Column objects or a compatible expression) which will render into a FOR UPDATE OF clause; supported by PostgreSQL and Oracle. May render as a table or as a column depending on backend.

버전 0.9.0에 추가.

with_hint(selectable, text, dialect_name='*')

Add an indexing or other executional context hint for the given selectable to this Select.

The text of the hint is rendered in the appropriate location for the database backend in use, relative to the given Table or Alias passed as the selectable argument. The dialect implementation typically uses Python string substitution syntax with the token %(name)s to render the name of the table or alias. E.g. when using Oracle, the following:

select([mytable]).\
    with_hint(mytable, "index(%(name)s ix_mytable)")

Would render SQL as:

select /*+ index(mytable ix_mytable) */ ... from mytable

The dialect_name option will limit the rendering of a particular hint to a particular backend. Such as, to add hints for both Oracle and Sybase simultaneously:

select([mytable]).\
    with_hint(mytable, "index(%(name)s ix_mytable)", 'oracle').\
    with_hint(mytable, "WITH INDEX ix_mytable", 'sybase')
with_only_columns(columns)

Return a new select() construct with its columns clause replaced with the given columns.

버전 0.7.3으로 변경: Due to a bug fix, this method has a slight behavioral change as of version 0.7.3. Prior to version 0.7.3, the FROM clause of a select() was calculated upfront and as new columns were added; in 0.7.3 and later it’s calculated at compile time, fixing an issue regarding late binding of columns to parent tables. This changes the behavior of Select.with_only_columns() in that FROM clauses no longer represented in the new list are dropped, but this behavior is more consistent in that the FROM clauses are consistently derived from the current columns clause. The original intent of this method is to allow trimming of the existing columns list to be fewer columns than originally present; the use case of replacing the columns list with an entirely different one hadn’t been anticipated until 0.7.3 was released; the usage guidelines below illustrate how this should be done.

This method is exactly equivalent to as if the original select() had been called with the given columns clause. I.e. a statement:

s = select([table1.c.a, table1.c.b])
s = s.with_only_columns([table1.c.b])

should be exactly equivalent to:

s = select([table1.c.b])

This means that FROM clauses which are only derived from the column list will be discarded if the new column list no longer contains that FROM:

>>> table1 = table('t1', column('a'), column('b'))
>>> table2 = table('t2', column('a'), column('b'))
>>> s1 = select([table1.c.a, table2.c.b])
>>> print s1
SELECT t1.a, t2.b FROM t1, t2
>>> s2 = s1.with_only_columns([table2.c.b])
>>> print s2
SELECT t2.b FROM t1

The preferred way to maintain a specific FROM clause in the construct, assuming it won’t be represented anywhere else (i.e. not in the WHERE clause, etc.) is to set it using Select.select_from():

>>> s1 = select([table1.c.a, table2.c.b]).\
...         select_from(table1.join(table2,
...                 table1.c.a==table2.c.a))
>>> s2 = s1.with_only_columns([table2.c.b])
>>> print s2
SELECT t2.b FROM t1 JOIN t2 ON t1.a=t2.a

Care should also be taken to use the correct set of column objects passed to Select.with_only_columns(). Since the method is essentially equivalent to calling the select() construct in the first place with the given columns, the columns passed to Select.with_only_columns() should usually be a subset of those which were passed to the select() construct, not those which are available from the .c collection of that select(). That is:

s = select([table1.c.a, table1.c.b]).select_from(table1)
s = s.with_only_columns([table1.c.b])

and not:

# usually incorrect
s = s.with_only_columns([s.c.b])

The latter would produce the SQL:

SELECT b
FROM (SELECT t1.a AS a, t1.b AS b
FROM t1), t1

Since the select() construct is essentially being asked to select both from table1 as well as itself.

with_statement_hint(text, dialect_name='*')

add a statement hint to this Select.

This method is similar to Select.with_hint() except that it does not require an individual table, and instead applies to the statement as a whole.

Hints here are specific to the backend database and may include directives such as isolation levels, file directives, fetch directives, etc.

버전 1.0.0에 추가.

더 보기

Select.with_hint()

class sqlalchemy.sql.expression.Selectable

Bases: sqlalchemy.sql.expression.ClauseElement

mark a class as being selectable

class sqlalchemy.sql.expression.SelectBase

Bases: sqlalchemy.sql.expression.HasCTE, sqlalchemy.sql.expression.Executable, sqlalchemy.sql.expression.FromClause

Base class for SELECT statements.

This includes Select, CompoundSelect and TextAsFrom.

as_scalar()

return a ‘scalar’ representation of this selectable, which can be used as a column expression.

Typically, a select statement which has only one column in its columns clause is eligible to be used as a scalar expression.

The returned object is an instance of ScalarSelect.

autocommit()

return a new selectable with the ‘autocommit’ flag set to True.

버전 0.6 폐지: autocommit() is deprecated. Use Executable.execution_options() with the ‘autocommit’ flag.

label(name)

return a ‘scalar’ representation of this selectable, embedded as a subquery with a label.

더 보기

as_scalar().

class sqlalchemy.sql.expression.TableClause(name, *columns)

Bases: sqlalchemy.sql.expression.Immutable, sqlalchemy.sql.expression.FromClause

Represents a minimal “table” construct.

This is a lightweight table object that has only a name and a collection of columns, which are typically produced by the expression.column() function:

from sqlalchemy import table, column

user = table("user",
        column("id"),
        column("name"),
        column("description"),
)

The TableClause construct serves as the base for the more commonly used Table object, providing the usual set of FromClause services including the .c. collection and statement generation methods.

It does not provide all the additional schema-level services of Table, including constraints, references to other tables, or support for MetaData-level services. It’s useful on its own as an ad-hoc construct used to generate quick SQL statements when a more fully fledged Table is not on hand.

__init__(name, *columns)

Construct a new TableClause object.

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

alias(name=None, flat=False)
inherited from the alias() method of FromClause

return an alias of this FromClause.

This is shorthand for calling:

from sqlalchemy import alias
a = alias(self, name=name)

See alias() for details.

c
inherited from the c attribute of FromClause

An alias for the columns attribute.

columns
inherited from the columns attribute of FromClause

A named-based collection of ColumnElement objects maintained by this FromClause.

The columns, or c collection, is the gateway to the construction of SQL expressions using table-bound or other selectable-bound columns:

select([mytable]).where(mytable.c.somecolumn == 5)
compare(other, **kw)
inherited from the compare() method of ClauseElement

Compare this ClauseElement to the given ClauseElement.

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

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

compile(bind=None, dialect=None, **kw)
inherited from the compile() method of ClauseElement

Compile this SQL expression.

The return value is a Compiled object. Calling str() or unicode() on the returned value will yield a string representation of the result. The Compiled object also can return a dictionary of bind parameter names and values using the params accessor.

매개 변수:
  • bind – An Engine or Connection from which a Compiled will be acquired. This argument takes precedence over this ClauseElement‘s bound engine, if any.
  • column_keys – Used for INSERT and UPDATE statements, a list of column names which should be present in the VALUES clause of the compiled statement. If None, all columns from the target table object are rendered.
  • dialect – A Dialect instance from which a Compiled will be acquired. This argument takes precedence over the bind argument as well as this ClauseElement‘s bound engine, if any.
  • inline – Used for INSERT statements, for a dialect which does not support inline retrieval of newly generated primary key columns, will force the expression used to create the new primary key value to be rendered inline within the INSERT statement’s VALUES clause. This typically refers to Sequence execution but may also refer to any server-side default generation function associated with a primary key Column.
  • compile_kwargs

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

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

    버전 0.9.0에 추가.

correspond_on_equivalents(column, equivalents)
inherited from the correspond_on_equivalents() method of FromClause

Return corresponding_column for the given column, or if None search for a match in the given dictionary.

corresponding_column(column, require_embedded=False)
inherited from the corresponding_column() method of FromClause

Given a ColumnElement, return the exported ColumnElement object from this Selectable which corresponds to that original Column via a common ancestor column.

매개 변수:
  • column – the target ColumnElement to be matched
  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this FromClause. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this FromClause.
count(whereclause=None, **params)

return a SELECT COUNT generated against this TableClause.

delete(whereclause=None, **kwargs)

Generate a delete() construct against this TableClause.

E.g.:

table.delete().where(table.c.id==7)

See delete() for argument and usage information.

foreign_keys
inherited from the foreign_keys attribute of FromClause

Return the collection of ForeignKey objects which this FromClause references.

implicit_returning = False

TableClause doesn’t support having a primary key or column -level defaults, so implicit returning doesn’t apply.

insert(values=None, inline=False, **kwargs)

Generate an insert() construct against this TableClause.

E.g.:

table.insert().values(name='foo')

See insert() for argument and usage information.

is_derived_from(fromclause)
inherited from the is_derived_from() method of FromClause

Return True if this FromClause is ‘derived’ from the given FromClause.

An example would be an Alias of a Table is derived from that Table.

join(right, onclause=None, isouter=False, full=False)
inherited from the join() method of FromClause

Return a Join from this FromClause to another FromClause.

E.g.:

from sqlalchemy import join

j = user_table.join(address_table,
                user_table.c.id == address_table.c.user_id)
stmt = select([user_table]).select_from(j)

would emit SQL along the lines of:

SELECT user.id, user.name FROM user
JOIN address ON user.id = address.user_id
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • isouter – if True, render a LEFT OUTER JOIN, instead of JOIN.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN. Implies FromClause.join.isouter.

    버전 1.1에 추가.

더 보기

join() - standalone function

Join - the type of object produced

lateral(name=None)
inherited from the lateral() method of FromClause

Return a LATERAL alias of this FromClause.

The return value is the Lateral construct also provided by the top-level lateral() function.

버전 1.1에 추가.

더 보기

LATERAL correlation - overview of usage.

outerjoin(right, onclause=None, full=False)
inherited from the outerjoin() method of FromClause

Return a Join from this FromClause to another FromClause, with the “isouter” flag set to True.

E.g.:

from sqlalchemy import outerjoin

j = user_table.outerjoin(address_table,
                user_table.c.id == address_table.c.user_id)

The above is equivalent to:

j = user_table.join(
    address_table,
    user_table.c.id == address_table.c.user_id,
    isouter=True)
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN.

    버전 1.1에 추가.

더 보기

FromClause.join()

Join

primary_key
inherited from the primary_key attribute of FromClause

Return the collection of Column objects which comprise the primary key of this FromClause.

replace_selectable(old, alias)
inherited from the replace_selectable() method of FromClause

replace all occurrences of FromClause ‘old’ with the given Alias object, returning a copy of this FromClause.

select(whereclause=None, **params)
inherited from the select() method of FromClause

return a SELECT of this FromClause.

더 보기

select() - general purpose method which allows for arbitrary column lists.

self_group(against=None)
inherited from the self_group() method of ClauseElement

Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a “grouping” construct, i.e. parenthesis. In particular it’s used by “binary” expressions to provide a grouping around themselves when placed into a larger expression, as well as by select() constructs when placed into the FROM clause of another select(). (Note that subqueries should be normally created using the Select.alias() method, as many platforms require nested SELECT statements to be named).

As expressions are composed together, the application of self_group() is automatic - end-user code should never need to use this method directly. Note that SQLAlchemy’s clause constructs take operator precedence into account - so parenthesis might not be needed, for example, in an expression like x OR (y AND z) - AND takes precedence over OR.

The base self_group() method of ClauseElement just returns self.

update(whereclause=None, values=None, inline=False, **kwargs)

Generate an update() construct against this TableClause.

E.g.:

table.update().where(table.c.id==7).values(name='foo')

See update() for argument and usage information.

class sqlalchemy.sql.expression.TextAsFrom(text, columns, positional=False)

Bases: sqlalchemy.sql.expression.SelectBase

Wrap a TextClause construct within a SelectBase interface.

This allows the TextClause object to gain a .c collection and other FROM-like capabilities such as FromClause.alias(), SelectBase.cte(), etc.

The TextAsFrom construct is produced via the TextClause.columns() method - see that method for details.

버전 0.9.0에 추가.

alias(name=None, flat=False)
inherited from the alias() method of FromClause

return an alias of this FromClause.

This is shorthand for calling:

from sqlalchemy import alias
a = alias(self, name=name)

See alias() for details.

as_scalar()
inherited from the as_scalar() method of SelectBase

return a ‘scalar’ representation of this selectable, which can be used as a column expression.

Typically, a select statement which has only one column in its columns clause is eligible to be used as a scalar expression.

The returned object is an instance of ScalarSelect.

autocommit()
inherited from the autocommit() method of SelectBase

return a new selectable with the ‘autocommit’ flag set to True.

버전 0.6 폐지: autocommit() is deprecated. Use Executable.execution_options() with the ‘autocommit’ flag.

bind
inherited from the bind attribute of Executable

Returns the Engine or Connection to which this Executable is bound, or None if none found.

This is a traversal which checks locally, then checks among the “from” clauses of associated objects until a bound engine or connection is found.

c
inherited from the c attribute of FromClause

An alias for the columns attribute.

columns
inherited from the columns attribute of FromClause

A named-based collection of ColumnElement objects maintained by this FromClause.

The columns, or c collection, is the gateway to the construction of SQL expressions using table-bound or other selectable-bound columns:

select([mytable]).where(mytable.c.somecolumn == 5)
compare(other, **kw)
inherited from the compare() method of ClauseElement

Compare this ClauseElement to the given ClauseElement.

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

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

compile(bind=None, dialect=None, **kw)
inherited from the compile() method of ClauseElement

Compile this SQL expression.

The return value is a Compiled object. Calling str() or unicode() on the returned value will yield a string representation of the result. The Compiled object also can return a dictionary of bind parameter names and values using the params accessor.

매개 변수:
  • bind – An Engine or Connection from which a Compiled will be acquired. This argument takes precedence over this ClauseElement‘s bound engine, if any.
  • column_keys – Used for INSERT and UPDATE statements, a list of column names which should be present in the VALUES clause of the compiled statement. If None, all columns from the target table object are rendered.
  • dialect – A Dialect instance from which a Compiled will be acquired. This argument takes precedence over the bind argument as well as this ClauseElement‘s bound engine, if any.
  • inline – Used for INSERT statements, for a dialect which does not support inline retrieval of newly generated primary key columns, will force the expression used to create the new primary key value to be rendered inline within the INSERT statement’s VALUES clause. This typically refers to Sequence execution but may also refer to any server-side default generation function associated with a primary key Column.
  • compile_kwargs

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

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

    버전 0.9.0에 추가.

correspond_on_equivalents(column, equivalents)
inherited from the correspond_on_equivalents() method of FromClause

Return corresponding_column for the given column, or if None search for a match in the given dictionary.

corresponding_column(column, require_embedded=False)
inherited from the corresponding_column() method of FromClause

Given a ColumnElement, return the exported ColumnElement object from this Selectable which corresponds to that original Column via a common ancestor column.

매개 변수:
  • column – the target ColumnElement to be matched
  • require_embedded – only return corresponding columns for the given ColumnElement, if the given ColumnElement is actually present within a sub-element of this FromClause. Normally the column will match if it merely shares a common ancestor with one of the exported columns of this FromClause.
count(whereclause=None, **params)
inherited from the count() method of FromClause

return a SELECT COUNT generated against this FromClause.

cte(name=None, recursive=False)
inherited from the cte() method of HasCTE

Return a new CTE, or Common Table Expression instance.

Common table expressions are a SQL standard whereby SELECT statements can draw upon secondary statements specified along with the primary statement, using a clause called “WITH”. Special semantics regarding UNION can also be employed to allow “recursive” queries, where a SELECT statement can draw upon the set of rows that have previously been selected.

CTEs can also be applied to DML constructs UPDATE, INSERT and DELETE on some databases, both as a source of CTE rows when combined with RETURNING, as well as a consumer of CTE rows.

SQLAlchemy detects CTE objects, which are treated similarly to Alias objects, as special elements to be delivered to the FROM clause of the statement as well as to a WITH clause at the top of the statement.

버전 1.1으로 변경: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.

매개 변수:
  • name – name given to the common table expression. Like _FromClause.alias(), the name can be left as None in which case an anonymous symbol will be used at query compile time.
  • recursive – if True, will render WITH RECURSIVE. A recursive common table expression is intended to be used in conjunction with UNION ALL in order to derive rows from those already selected.

The following examples include two from Postgresql’s documentation at http://www.postgresql.org/docs/current/static/queries-with.html, as well as additional examples.

Example 1, non recursive:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

orders = Table('orders', metadata,
    Column('region', String),
    Column('amount', Integer),
    Column('product', String),
    Column('quantity', Integer)
)

regional_sales = select([
                    orders.c.region,
                    func.sum(orders.c.amount).label('total_sales')
                ]).group_by(orders.c.region).cte("regional_sales")


top_regions = select([regional_sales.c.region]).\
        where(
            regional_sales.c.total_sales >
            select([
                func.sum(regional_sales.c.total_sales)/10
            ])
        ).cte("top_regions")

statement = select([
            orders.c.region,
            orders.c.product,
            func.sum(orders.c.quantity).label("product_units"),
            func.sum(orders.c.amount).label("product_sales")
    ]).where(orders.c.region.in_(
        select([top_regions.c.region])
    )).group_by(orders.c.region, orders.c.product)

result = conn.execute(statement).fetchall()

Example 2, WITH RECURSIVE:

from sqlalchemy import (Table, Column, String, Integer,
                        MetaData, select, func)

metadata = MetaData()

parts = Table('parts', metadata,
    Column('part', String),
    Column('sub_part', String),
    Column('quantity', Integer),
)

included_parts = select([
                    parts.c.sub_part,
                    parts.c.part,
                    parts.c.quantity]).\
                    where(parts.c.part=='our part').\
                    cte(recursive=True)


incl_alias = included_parts.alias()
parts_alias = parts.alias()
included_parts = included_parts.union_all(
    select([
        parts_alias.c.sub_part,
        parts_alias.c.part,
        parts_alias.c.quantity
    ]).
        where(parts_alias.c.part==incl_alias.c.sub_part)
)

statement = select([
            included_parts.c.sub_part,
            func.sum(included_parts.c.quantity).
              label('total_quantity')
        ]).\
        group_by(included_parts.c.sub_part)

result = conn.execute(statement).fetchall()

Example 3, an upsert using UPDATE and INSERT with CTEs:

orders = table(
    'orders',
    column('region'),
    column('amount'),
    column('product'),
    column('quantity')
)

upsert = (
    orders.update()
    .where(orders.c.region == 'Region1')
    .values(amount=1.0, product='Product1', quantity=1)
    .returning(*(orders.c._all_columns)).cte('upsert'))

insert = orders.insert().from_select(
    orders.c.keys(),
    select([
        literal('Region1'), literal(1.0),
        literal('Product1'), literal(1)
    ).where(exists(upsert.select()))
)

connection.execute(insert)

더 보기

orm.query.Query.cte() - ORM version of HasCTE.cte().

description
inherited from the description attribute of FromClause

a brief description of this FromClause.

Used primarily for error message formatting.

execute(*multiparams, **params)
inherited from the execute() method of Executable

Compile and execute this Executable.

execution_options(**kw)
inherited from the execution_options() method of Executable

Set non-SQL options for the statement which take effect during execution.

Execution options can be set on a per-statement or per Connection basis. Additionally, the Engine and ORM Query objects provide access to execution options which they in turn configure upon connections.

The execution_options() method is generative. A new instance of this statement is returned that contains the options:

statement = select([table.c.x, table.c.y])
statement = statement.execution_options(autocommit=True)

Note that only a subset of possible execution options can be applied to a statement - these include “autocommit” and “stream_results”, but not “isolation_level” or “compiled_cache”. See Connection.execution_options() for a full list of possible options.

foreign_keys
inherited from the foreign_keys attribute of FromClause

Return the collection of ForeignKey objects which this FromClause references.

get_children(**kwargs)
inherited from the get_children() method of ClauseElement

Return immediate child elements of this ClauseElement.

This is used for visit traversal.

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

is_derived_from(fromclause)
inherited from the is_derived_from() method of FromClause

Return True if this FromClause is ‘derived’ from the given FromClause.

An example would be an Alias of a Table is derived from that Table.

join(right, onclause=None, isouter=False, full=False)
inherited from the join() method of FromClause

Return a Join from this FromClause to another FromClause.

E.g.:

from sqlalchemy import join

j = user_table.join(address_table,
                user_table.c.id == address_table.c.user_id)
stmt = select([user_table]).select_from(j)

would emit SQL along the lines of:

SELECT user.id, user.name FROM user
JOIN address ON user.id = address.user_id
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • isouter – if True, render a LEFT OUTER JOIN, instead of JOIN.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN. Implies FromClause.join.isouter.

    버전 1.1에 추가.

더 보기

join() - standalone function

Join - the type of object produced

label(name)
inherited from the label() method of SelectBase

return a ‘scalar’ representation of this selectable, embedded as a subquery with a label.

더 보기

as_scalar().

lateral(name=None)
inherited from the lateral() method of FromClause

Return a LATERAL alias of this FromClause.

The return value is the Lateral construct also provided by the top-level lateral() function.

버전 1.1에 추가.

더 보기

LATERAL correlation - overview of usage.

outerjoin(right, onclause=None, full=False)
inherited from the outerjoin() method of FromClause

Return a Join from this FromClause to another FromClause, with the “isouter” flag set to True.

E.g.:

from sqlalchemy import outerjoin

j = user_table.outerjoin(address_table,
                user_table.c.id == address_table.c.user_id)

The above is equivalent to:

j = user_table.join(
    address_table,
    user_table.c.id == address_table.c.user_id,
    isouter=True)
매개 변수:
  • right – the right side of the join; this is any FromClause object such as a Table object, and may also be a selectable-compatible object such as an ORM-mapped class.
  • onclause – a SQL expression representing the ON clause of the join. If left at None, FromClause.join() will attempt to join the two tables based on a foreign key relationship.
  • full

    if True, render a FULL OUTER JOIN, instead of LEFT OUTER JOIN.

    버전 1.1에 추가.

더 보기

FromClause.join()

Join

params(*optionaldict, **kwargs)
inherited from the params() method of ClauseElement

Return a copy with bindparam() elements replaced.

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

>>> clause = column('x') + bindparam('foo')
>>> print clause.compile().params
{'foo':None}
>>> print clause.params({'foo':7}).compile().params
{'foo':7}
primary_key
inherited from the primary_key attribute of FromClause

Return the collection of Column objects which comprise the primary key of this FromClause.

replace_selectable(old, alias)
inherited from the replace_selectable() method of FromClause

replace all occurrences of FromClause ‘old’ with the given Alias object, returning a copy of this FromClause.

scalar(*multiparams, **params)
inherited from the scalar() method of Executable

Compile and execute this Executable, returning the result’s scalar representation.

select(whereclause=None, **params)
inherited from the select() method of FromClause

return a SELECT of this FromClause.

더 보기

select() - general purpose method which allows for arbitrary column lists.

self_group(against=None)
inherited from the self_group() method of ClauseElement

Apply a ‘grouping’ to this ClauseElement.

This method is overridden by subclasses to return a “grouping” construct, i.e. parenthesis. In particular it’s used by “binary” expressions to provide a grouping around themselves when placed into a larger expression, as well as by select() constructs when placed into the FROM clause of another select(). (Note that subqueries should be normally created using the Select.alias() method, as many platforms require nested SELECT statements to be named).

As expressions are composed together, the application of self_group() is automatic - end-user code should never need to use this method directly. Note that SQLAlchemy’s clause constructs take operator precedence into account - so parenthesis might not be needed, for example, in an expression like x OR (y AND z) - AND takes precedence over OR.

The base self_group() method of ClauseElement just returns self.

unique_params(*optionaldict, **kwargs)
inherited from the unique_params() method of ClauseElement

Return a copy with bindparam() elements replaced.

Same functionality as params(), except adds unique=True to affected bind parameters so that multiple statements can be used.