INSERT, UPDATE and DELETE statements build on a hierarchy starting
with UpdateBase
. The Insert
and Update
constructs build on the intermediary ValuesBase
.
sqlalchemy.sql.expression.
delete
(table, whereclause=None, bind=None, returning=None, prefixes=None, **dialect_kw)¶Construct Delete
object.
Similar functionality is available via the
delete()
method on
Table
.
Parameters: |
|
---|
See also
Deletes - SQL Expression Tutorial
sqlalchemy.sql.expression.
insert
(table, values=None, inline=False, bind=None, prefixes=None, returning=None, return_defaults=False, **dialect_kw)¶Construct an Insert
object.
Similar functionality is available via the
insert()
method on
Table
.
Parameters: |
|
---|
If both values and compile-time bind parameters are present, the compile-time bind parameters override the information specified within values on a per-key basis.
The keys within values can be either
Column
objects or their string
identifiers. Each key may reference one of:
If a SELECT
statement is specified which references this
INSERT
statement’s table, the statement will be correlated
against the INSERT
statement.
See also
Insert Expressions - SQL Expression Tutorial
Inserts, Updates and Deletes - SQL Expression Tutorial
sqlalchemy.sql.expression.
update
(table, whereclause=None, values=None, inline=False, bind=None, prefixes=None, returning=None, return_defaults=False, preserve_parameter_order=False, **dialect_kw)¶Construct an Update
object.
E.g.:
from sqlalchemy import update
stmt = update(users).where(users.c.id==5).\
values(name='user #5')
Similar functionality is available via the
update()
method on
Table
:
stmt = users.update().\
where(users.c.id==5).\
values(name='user #5')
Parameters: |
|
---|
If both values
and compile-time bind parameters are present, the
compile-time bind parameters override the information specified
within values
on a per-key basis.
The keys within values
can be either Column
objects or their string identifiers (specifically the “key” of the
Column
, normally but not necessarily equivalent to
its “name”). Normally, the
Column
objects used here are expected to be
part of the target Table
that is the table
to be updated. However when using MySQL, a multiple-table
UPDATE statement can refer to columns from any of
the tables referred to in the WHERE clause.
The values referred to in values
are typically:
Column
,
a scalar-returning select()
construct,
etc.When combining select()
constructs within the values
clause of an update()
construct,
the subquery represented by the select()
should be
correlated to the parent table, that is, providing criterion
which links the table inside the subquery to the outer table
being updated:
users.update().values(
name=select([addresses.c.email_address]).\
where(addresses.c.user_id==users.c.id).\
as_scalar()
)
See also
Inserts, Updates and Deletes - SQL Expression Language Tutorial
sqlalchemy.sql.expression.
Delete
(table, whereclause=None, bind=None, returning=None, prefixes=None, **dialect_kw)¶Bases: sqlalchemy.sql.expression.UpdateBase
Represent a DELETE construct.
The Delete
object is created using the delete()
function.
__eq__
¶__eq__
attribute of object
Return self==value.
__init__
(table, whereclause=None, bind=None, returning=None, prefixes=None, **dialect_kw)¶Construct a new Delete
object.
This constructor is mirrored as a public API function; see delete()
for a full usage and argument description.
__le__
¶__le__
attribute of object
Return self<=value.
__lt__
¶__lt__
attribute of object
Return self<value.
__ne__
¶__ne__
attribute of object
Return self!=value.
argument_for
(dialect_name, argument_name, default)¶argument_for()
method of DialectKWArgs
Add a new kind of dialect-specific keyword argument for this class.
E.g.:
Index.argument_for("mydialect", "length", None)
some_index = Index('a', 'b', mydialect_length=5)
The DialectKWArgs.argument_for()
method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments
dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a data member of the dialect class. The use case for ad-hoc addition of argument names is typically for end-user code that is also using a custom compilation scheme which consumes the additional arguments.
Parameters: |
|
---|
New in version 0.9.4.
bind
¶bind
attribute of UpdateBase
Return a ‘bind’ linked to this UpdateBase
or a Table
associated with it.
compare
(other, **kw)¶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
(default, bind=None, dialect=None, **kw)¶compile()
method of ClauseElement
Compile this SQL expression.
The return value is a Compiled
object.
Calling str()
or unicode()
on the returned value will yield a
string representation of the result. The
Compiled
object also can return a
dictionary of bind parameter names and values
using the params
accessor.
Parameters: |
|
---|
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.
Changed in version 1.1: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.
Parameters: |
|
---|
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:
from datetime import date
from sqlalchemy import (MetaData, Table, Column, Integer,
Date, select, literal, and_, exists)
metadata = MetaData()
visitors = Table('visitors', metadata,
Column('product_id', Integer, primary_key=True),
Column('date', Date, primary_key=True),
Column('count', Integer),
)
# add 5 visitors for the product_id == 1
product_id = 1
day = date.today()
count = 5
update_cte = (
visitors.update()
.where(and_(visitors.c.product_id == product_id,
visitors.c.date == day))
.values(count=visitors.c.count + count)
.returning(literal(1))
.cte('update_cte')
)
upsert = visitors.insert().from_select(
[visitors.c.product_id, visitors.c.date, visitors.c.count],
select([literal(product_id), literal(day), literal(count)])
.where(~exists(update_cte.select()))
)
connection.execute(upsert)
See also
orm.query.Query.cte()
- ORM version of
HasCTE.cte()
.
dialect_kwargs
¶dialect_kwargs
attribute of DialectKWArgs
A collection of keyword arguments specified as dialect-specific options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options
collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg>
where the value will be assembled
into the list of options.
New in version 0.9.2.
Changed in version 0.9.4: The DialectKWArgs.dialect_kwargs
collection is now writable.
See also
DialectKWArgs.dialect_options
- nested dictionary form
dialect_options
¶dialect_options
attribute of DialectKWArgs
A collection of keyword arguments specified as dialect-specific options to this construct.
This is a two-level nested registry, keyed to <dialect_name>
and <argument_name>
. For example, the postgresql_where
argument would be locatable as:
arg = my_object.dialect_options['postgresql']['where']
New in version 0.9.2.
See also
DialectKWArgs.dialect_kwargs
- flat dictionary form
execute
(*multiparams, **params)¶execute()
method of Executable
Compile and execute this Executable
.
execution_options
(**kw)¶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.
get_children
(**kwargs)¶Return immediate child elements of this ClauseElement
.
This is used for visit traversal.
**kwargs may contain flags that change the collection that is returned, for example to return a subset of items in order to cut down on larger traversals, or to return child items from a different context (such as schema-level collections instead of clause-level).
get_execution_options
()¶get_execution_options()
method of Executable
Get the non-SQL options which will take effect during execution.
New in version 1.3.
See also
kwargs
¶kwargs
attribute of DialectKWArgs
A synonym for DialectKWArgs.dialect_kwargs
.
params
(*arg, **kw)¶params()
method of UpdateBase
Set the parameters for the statement.
This method raises NotImplementedError
on the base class,
and is overridden by ValuesBase
to provide the
SET/VALUES clause of UPDATE and INSERT.
prefix_with
(*expr, **kw)¶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")
# MySQL 5.7 optimizer hints
stmt = select([table]).prefix_with(
"/*+ BKA(t1) */", dialect="mysql")
Multiple prefixes can be specified by multiple calls
to prefix_with()
.
Parameters: |
|
---|
returning
(*cols)¶returning()
method of UpdateBase
Add a RETURNING or equivalent clause to this statement.
e.g.:
stmt = table.update().\
where(table.c.data == 'value').\
values(status='X').\
returning(table.c.server_flag,
table.c.updated_timestamp)
for server_flag, updated_timestamp in connection.execute(stmt):
print(server_flag, updated_timestamp)
The given collection of column expressions should be derived from
the table that is
the target of the INSERT, UPDATE, or DELETE. While Column
objects are typical, the elements can also be expressions:
stmt = table.insert().returning(
(table.c.first_name + " " + table.c.last_name).
label('fullname'))
Upon compilation, a RETURNING clause, or database equivalent, will be rendered within the statement. For INSERT and UPDATE, the values are the newly inserted/updated values. For DELETE, the values are those of the rows which were deleted.
Upon execution, the values of the columns to be returned are made
available via the result set and can be iterated using
ResultProxy.fetchone()
and similar. For DBAPIs which do not
natively support returning values (i.e. cx_oracle), SQLAlchemy will
approximate this behavior at the result level so that a reasonable
amount of behavioral neutrality is provided.
Note that not all databases/DBAPIs support RETURNING. For those backends with no support, an exception is raised upon compilation and/or execution. For those who do support it, the functionality across backends varies greatly, including restrictions on executemany() and other statements which return multiple rows. Please read the documentation notes for the database in use in order to determine the availability of RETURNING.
See also
ValuesBase.return_defaults()
- an alternative method tailored
towards efficient fetching of server-side defaults and triggers
for single-row INSERTs or UPDATEs.
scalar
(*multiparams, **params)¶scalar()
method of Executable
Compile and execute this Executable
, returning the
result’s scalar representation.
self_group
(against=None)¶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)¶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)¶Add the given WHERE clause to a newly returned delete construct.
with_hint
(text, selectable=None, dialect_name='*')¶with_hint()
method of UpdateBase
Add a table hint for a single table to this INSERT/UPDATE/DELETE statement.
Note
UpdateBase.with_hint()
currently applies only to
Microsoft SQL Server. For MySQL INSERT/UPDATE/DELETE hints, use
UpdateBase.prefix_with()
.
The text of the hint is rendered in the appropriate
location for the database backend in use, relative
to the Table
that is the subject of this
statement, or optionally to that of the given
Table
passed as the selectable
argument.
The dialect_name
option will limit the rendering of a particular
hint to a particular backend. Such as, to add a hint
that only takes effect for SQL Server:
mytable.insert().with_hint("WITH (PAGLOCK)", dialect_name="mssql")
Parameters: |
|
---|
sqlalchemy.sql.expression.
Insert
(table, values=None, inline=False, bind=None, prefixes=None, returning=None, return_defaults=False, **dialect_kw)¶Bases: sqlalchemy.sql.expression.ValuesBase
Represent an INSERT construct.
The Insert
object is created using the
insert()
function.
See also
__eq__
¶__eq__
attribute of object
Return self==value.
__init__
(table, values=None, inline=False, bind=None, prefixes=None, returning=None, return_defaults=False, **dialect_kw)¶Construct a new Insert
object.
This constructor is mirrored as a public API function; see insert()
for a full usage and argument description.
__le__
¶__le__
attribute of object
Return self<=value.
__lt__
¶__lt__
attribute of object
Return self<value.
__ne__
¶__ne__
attribute of object
Return self!=value.
argument_for
(dialect_name, argument_name, default)¶argument_for()
method of DialectKWArgs
Add a new kind of dialect-specific keyword argument for this class.
E.g.:
Index.argument_for("mydialect", "length", None)
some_index = Index('a', 'b', mydialect_length=5)
The DialectKWArgs.argument_for()
method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments
dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a data member of the dialect class. The use case for ad-hoc addition of argument names is typically for end-user code that is also using a custom compilation scheme which consumes the additional arguments.
Parameters: |
|
---|
New in version 0.9.4.
bind
¶bind
attribute of UpdateBase
Return a ‘bind’ linked to this UpdateBase
or a Table
associated with it.
compare
(other, **kw)¶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
(default, bind=None, dialect=None, **kw)¶compile()
method of ClauseElement
Compile this SQL expression.
The return value is a Compiled
object.
Calling str()
or unicode()
on the returned value will yield a
string representation of the result. The
Compiled
object also can return a
dictionary of bind parameter names and values
using the params
accessor.
Parameters: |
|
---|
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.
Changed in version 1.1: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.
Parameters: |
|
---|
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:
from datetime import date
from sqlalchemy import (MetaData, Table, Column, Integer,
Date, select, literal, and_, exists)
metadata = MetaData()
visitors = Table('visitors', metadata,
Column('product_id', Integer, primary_key=True),
Column('date', Date, primary_key=True),
Column('count', Integer),
)
# add 5 visitors for the product_id == 1
product_id = 1
day = date.today()
count = 5
update_cte = (
visitors.update()
.where(and_(visitors.c.product_id == product_id,
visitors.c.date == day))
.values(count=visitors.c.count + count)
.returning(literal(1))
.cte('update_cte')
)
upsert = visitors.insert().from_select(
[visitors.c.product_id, visitors.c.date, visitors.c.count],
select([literal(product_id), literal(day), literal(count)])
.where(~exists(update_cte.select()))
)
connection.execute(upsert)
See also
orm.query.Query.cte()
- ORM version of
HasCTE.cte()
.
dialect_kwargs
¶dialect_kwargs
attribute of DialectKWArgs
A collection of keyword arguments specified as dialect-specific options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options
collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg>
where the value will be assembled
into the list of options.
New in version 0.9.2.
Changed in version 0.9.4: The DialectKWArgs.dialect_kwargs
collection is now writable.
See also
DialectKWArgs.dialect_options
- nested dictionary form
dialect_options
¶dialect_options
attribute of DialectKWArgs
A collection of keyword arguments specified as dialect-specific options to this construct.
This is a two-level nested registry, keyed to <dialect_name>
and <argument_name>
. For example, the postgresql_where
argument would be locatable as:
arg = my_object.dialect_options['postgresql']['where']
New in version 0.9.2.
See also
DialectKWArgs.dialect_kwargs
- flat dictionary form
execute
(*multiparams, **params)¶execute()
method of Executable
Compile and execute this Executable
.
execution_options
(**kw)¶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.
from_select
(names, select, include_defaults=True)¶Return a new Insert
construct which represents
an INSERT...FROM SELECT
statement.
e.g.:
sel = select([table1.c.a, table1.c.b]).where(table1.c.c > 5)
ins = table2.insert().from_select(['a', 'b'], sel)
Parameters: |
|
---|
Changed in version 1.0.0: an INSERT that uses FROM SELECT
implies that the insert.inline
flag is set to
True, indicating that the statement will not attempt to fetch
the “last inserted primary key” or other defaults. The statement
deals with an arbitrary number of rows, so the
ResultProxy.inserted_primary_key
accessor does not apply.
get_children
(**kwargs)¶Return immediate child elements of this ClauseElement
.
This is used for visit traversal.
**kwargs may contain flags that change the collection that is returned, for example to return a subset of items in order to cut down on larger traversals, or to return child items from a different context (such as schema-level collections instead of clause-level).
get_execution_options
()¶get_execution_options()
method of Executable
Get the non-SQL options which will take effect during execution.
New in version 1.3.
See also
kwargs
¶kwargs
attribute of DialectKWArgs
A synonym for DialectKWArgs.dialect_kwargs
.
params
(*arg, **kw)¶params()
method of UpdateBase
Set the parameters for the statement.
This method raises NotImplementedError
on the base class,
and is overridden by ValuesBase
to provide the
SET/VALUES clause of UPDATE and INSERT.
prefix_with
(*expr, **kw)¶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")
# MySQL 5.7 optimizer hints
stmt = select([table]).prefix_with(
"/*+ BKA(t1) */", dialect="mysql")
Multiple prefixes can be specified by multiple calls
to prefix_with()
.
Parameters: |
|
---|
return_defaults
(*cols)¶return_defaults()
method of ValuesBase
Make use of a RETURNING clause for the purpose of fetching server-side expressions and defaults.
E.g.:
stmt = table.insert().values(data='newdata').return_defaults()
result = connection.execute(stmt)
server_created_at = result.returned_defaults['created_at']
When used against a backend that supports RETURNING, all column
values generated by SQL expression or server-side-default will be
added to any existing RETURNING clause, provided that
UpdateBase.returning()
is not used simultaneously. The column
values will then be available on the result using the
ResultProxy.returned_defaults
accessor as a dictionary,
referring to values keyed to the Column
object as well as
its .key
.
This method differs from UpdateBase.returning()
in these ways:
ValuesBase.return_defaults()
is only intended for use with
an INSERT or an UPDATE statement that matches exactly one row.
While the RETURNING construct in the general sense supports
multiple rows for a multi-row UPDATE or DELETE statement, or for
special cases of INSERT that return multiple rows (e.g. INSERT from
SELECT, multi-valued VALUES clause),
ValuesBase.return_defaults()
is intended only for an
“ORM-style” single-row INSERT/UPDATE statement. The row returned
by the statement is also consumed implicitly when
ValuesBase.return_defaults()
is used. By contrast,
UpdateBase.returning()
leaves the RETURNING result-set
intact with a collection of any number of rows.UpdateBase.returning()
method circumvents this behavior,
ValuesBase.return_defaults()
leaves it intact.ResultProxy.returned_defaults
will be None
ValuesBase.return_defaults()
is used by the ORM to provide
an efficient implementation for the eager_defaults
feature of
mapper()
.
Parameters: | cols¶ – optional list of column key names or Column
objects. If omitted, all column expressions evaluated on the server
are added to the returning list. |
---|
New in version 0.9.0.
returning
(*cols)¶returning()
method of UpdateBase
Add a RETURNING or equivalent clause to this statement.
e.g.:
stmt = table.update().\
where(table.c.data == 'value').\
values(status='X').\
returning(table.c.server_flag,
table.c.updated_timestamp)
for server_flag, updated_timestamp in connection.execute(stmt):
print(server_flag, updated_timestamp)
The given collection of column expressions should be derived from
the table that is
the target of the INSERT, UPDATE, or DELETE. While Column
objects are typical, the elements can also be expressions:
stmt = table.insert().returning(
(table.c.first_name + " " + table.c.last_name).
label('fullname'))
Upon compilation, a RETURNING clause, or database equivalent, will be rendered within the statement. For INSERT and UPDATE, the values are the newly inserted/updated values. For DELETE, the values are those of the rows which were deleted.
Upon execution, the values of the columns to be returned are made
available via the result set and can be iterated using
ResultProxy.fetchone()
and similar. For DBAPIs which do not
natively support returning values (i.e. cx_oracle), SQLAlchemy will
approximate this behavior at the result level so that a reasonable
amount of behavioral neutrality is provided.
Note that not all databases/DBAPIs support RETURNING. For those backends with no support, an exception is raised upon compilation and/or execution. For those who do support it, the functionality across backends varies greatly, including restrictions on executemany() and other statements which return multiple rows. Please read the documentation notes for the database in use in order to determine the availability of RETURNING.
See also
ValuesBase.return_defaults()
- an alternative method tailored
towards efficient fetching of server-side defaults and triggers
for single-row INSERTs or UPDATEs.
scalar
(*multiparams, **params)¶scalar()
method of Executable
Compile and execute this Executable
, returning the
result’s scalar representation.
self_group
(against=None)¶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)¶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.
values
(*args, **kwargs)¶values()
method of ValuesBase
specify a fixed VALUES clause for an INSERT statement, or the SET clause for an UPDATE.
Note that the Insert
and Update
constructs support
per-execution time formatting of the VALUES and/or SET clauses,
based on the arguments passed to Connection.execute()
.
However, the ValuesBase.values()
method can be used to “fix” a
particular set of parameters into the statement.
Multiple calls to ValuesBase.values()
will produce a new
construct, each one with the parameter list modified to include
the new parameters sent. In the typical case of a single
dictionary of parameters, the newly passed keys will replace
the same keys in the previous construct. In the case of a list-based
“multiple values” construct, each new list of values is extended
onto the existing list of values.
Parameters: |
|
---|
See also
Inserts, Updates and Deletes - SQL Expression Language Tutorial
insert()
- produce an INSERT
statement
update()
- produce an UPDATE
statement
with_hint
(text, selectable=None, dialect_name='*')¶with_hint()
method of UpdateBase
Add a table hint for a single table to this INSERT/UPDATE/DELETE statement.
Note
UpdateBase.with_hint()
currently applies only to
Microsoft SQL Server. For MySQL INSERT/UPDATE/DELETE hints, use
UpdateBase.prefix_with()
.
The text of the hint is rendered in the appropriate
location for the database backend in use, relative
to the Table
that is the subject of this
statement, or optionally to that of the given
Table
passed as the selectable
argument.
The dialect_name
option will limit the rendering of a particular
hint to a particular backend. Such as, to add a hint
that only takes effect for SQL Server:
mytable.insert().with_hint("WITH (PAGLOCK)", dialect_name="mssql")
Parameters: |
|
---|
sqlalchemy.sql.expression.
Update
(table, whereclause=None, values=None, inline=False, bind=None, prefixes=None, returning=None, return_defaults=False, preserve_parameter_order=False, **dialect_kw)¶Bases: sqlalchemy.sql.expression.ValuesBase
Represent an Update construct.
The Update
object is created using the update()
function.
__eq__
¶__eq__
attribute of object
Return self==value.
__init__
(table, whereclause=None, values=None, inline=False, bind=None, prefixes=None, returning=None, return_defaults=False, preserve_parameter_order=False, **dialect_kw)¶Construct a new Update
object.
This constructor is mirrored as a public API function; see update()
for a full usage and argument description.
__le__
¶__le__
attribute of object
Return self<=value.
__lt__
¶__lt__
attribute of object
Return self<value.
__ne__
¶__ne__
attribute of object
Return self!=value.
argument_for
(dialect_name, argument_name, default)¶argument_for()
method of DialectKWArgs
Add a new kind of dialect-specific keyword argument for this class.
E.g.:
Index.argument_for("mydialect", "length", None)
some_index = Index('a', 'b', mydialect_length=5)
The DialectKWArgs.argument_for()
method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments
dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a data member of the dialect class. The use case for ad-hoc addition of argument names is typically for end-user code that is also using a custom compilation scheme which consumes the additional arguments.
Parameters: |
|
---|
New in version 0.9.4.
bind
¶bind
attribute of UpdateBase
Return a ‘bind’ linked to this UpdateBase
or a Table
associated with it.
compare
(other, **kw)¶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
(default, bind=None, dialect=None, **kw)¶compile()
method of ClauseElement
Compile this SQL expression.
The return value is a Compiled
object.
Calling str()
or unicode()
on the returned value will yield a
string representation of the result. The
Compiled
object also can return a
dictionary of bind parameter names and values
using the params
accessor.
Parameters: |
|
---|
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.
Changed in version 1.1: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.
Parameters: |
|
---|
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:
from datetime import date
from sqlalchemy import (MetaData, Table, Column, Integer,
Date, select, literal, and_, exists)
metadata = MetaData()
visitors = Table('visitors', metadata,
Column('product_id', Integer, primary_key=True),
Column('date', Date, primary_key=True),
Column('count', Integer),
)
# add 5 visitors for the product_id == 1
product_id = 1
day = date.today()
count = 5
update_cte = (
visitors.update()
.where(and_(visitors.c.product_id == product_id,
visitors.c.date == day))
.values(count=visitors.c.count + count)
.returning(literal(1))
.cte('update_cte')
)
upsert = visitors.insert().from_select(
[visitors.c.product_id, visitors.c.date, visitors.c.count],
select([literal(product_id), literal(day), literal(count)])
.where(~exists(update_cte.select()))
)
connection.execute(upsert)
See also
orm.query.Query.cte()
- ORM version of
HasCTE.cte()
.
dialect_kwargs
¶dialect_kwargs
attribute of DialectKWArgs
A collection of keyword arguments specified as dialect-specific options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options
collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg>
where the value will be assembled
into the list of options.
New in version 0.9.2.
Changed in version 0.9.4: The DialectKWArgs.dialect_kwargs
collection is now writable.
See also
DialectKWArgs.dialect_options
- nested dictionary form
dialect_options
¶dialect_options
attribute of DialectKWArgs
A collection of keyword arguments specified as dialect-specific options to this construct.
This is a two-level nested registry, keyed to <dialect_name>
and <argument_name>
. For example, the postgresql_where
argument would be locatable as:
arg = my_object.dialect_options['postgresql']['where']
New in version 0.9.2.
See also
DialectKWArgs.dialect_kwargs
- flat dictionary form
execute
(*multiparams, **params)¶execute()
method of Executable
Compile and execute this Executable
.
execution_options
(**kw)¶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.
get_children
(**kwargs)¶Return immediate child elements of this ClauseElement
.
This is used for visit traversal.
**kwargs may contain flags that change the collection that is returned, for example to return a subset of items in order to cut down on larger traversals, or to return child items from a different context (such as schema-level collections instead of clause-level).
get_execution_options
()¶get_execution_options()
method of Executable
Get the non-SQL options which will take effect during execution.
New in version 1.3.
See also
kwargs
¶kwargs
attribute of DialectKWArgs
A synonym for DialectKWArgs.dialect_kwargs
.
params
(*arg, **kw)¶params()
method of UpdateBase
Set the parameters for the statement.
This method raises NotImplementedError
on the base class,
and is overridden by ValuesBase
to provide the
SET/VALUES clause of UPDATE and INSERT.
prefix_with
(*expr, **kw)¶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")
# MySQL 5.7 optimizer hints
stmt = select([table]).prefix_with(
"/*+ BKA(t1) */", dialect="mysql")
Multiple prefixes can be specified by multiple calls
to prefix_with()
.
Parameters: |
|
---|
return_defaults
(*cols)¶return_defaults()
method of ValuesBase
Make use of a RETURNING clause for the purpose of fetching server-side expressions and defaults.
E.g.:
stmt = table.insert().values(data='newdata').return_defaults()
result = connection.execute(stmt)
server_created_at = result.returned_defaults['created_at']
When used against a backend that supports RETURNING, all column
values generated by SQL expression or server-side-default will be
added to any existing RETURNING clause, provided that
UpdateBase.returning()
is not used simultaneously. The column
values will then be available on the result using the
ResultProxy.returned_defaults
accessor as a dictionary,
referring to values keyed to the Column
object as well as
its .key
.
This method differs from UpdateBase.returning()
in these ways:
ValuesBase.return_defaults()
is only intended for use with
an INSERT or an UPDATE statement that matches exactly one row.
While the RETURNING construct in the general sense supports
multiple rows for a multi-row UPDATE or DELETE statement, or for
special cases of INSERT that return multiple rows (e.g. INSERT from
SELECT, multi-valued VALUES clause),
ValuesBase.return_defaults()
is intended only for an
“ORM-style” single-row INSERT/UPDATE statement. The row returned
by the statement is also consumed implicitly when
ValuesBase.return_defaults()
is used. By contrast,
UpdateBase.returning()
leaves the RETURNING result-set
intact with a collection of any number of rows.UpdateBase.returning()
method circumvents this behavior,
ValuesBase.return_defaults()
leaves it intact.ResultProxy.returned_defaults
will be None
ValuesBase.return_defaults()
is used by the ORM to provide
an efficient implementation for the eager_defaults
feature of
mapper()
.
Parameters: | cols¶ – optional list of column key names or Column
objects. If omitted, all column expressions evaluated on the server
are added to the returning list. |
---|
New in version 0.9.0.
returning
(*cols)¶returning()
method of UpdateBase
Add a RETURNING or equivalent clause to this statement.
e.g.:
stmt = table.update().\
where(table.c.data == 'value').\
values(status='X').\
returning(table.c.server_flag,
table.c.updated_timestamp)
for server_flag, updated_timestamp in connection.execute(stmt):
print(server_flag, updated_timestamp)
The given collection of column expressions should be derived from
the table that is
the target of the INSERT, UPDATE, or DELETE. While Column
objects are typical, the elements can also be expressions:
stmt = table.insert().returning(
(table.c.first_name + " " + table.c.last_name).
label('fullname'))
Upon compilation, a RETURNING clause, or database equivalent, will be rendered within the statement. For INSERT and UPDATE, the values are the newly inserted/updated values. For DELETE, the values are those of the rows which were deleted.
Upon execution, the values of the columns to be returned are made
available via the result set and can be iterated using
ResultProxy.fetchone()
and similar. For DBAPIs which do not
natively support returning values (i.e. cx_oracle), SQLAlchemy will
approximate this behavior at the result level so that a reasonable
amount of behavioral neutrality is provided.
Note that not all databases/DBAPIs support RETURNING. For those backends with no support, an exception is raised upon compilation and/or execution. For those who do support it, the functionality across backends varies greatly, including restrictions on executemany() and other statements which return multiple rows. Please read the documentation notes for the database in use in order to determine the availability of RETURNING.
See also
ValuesBase.return_defaults()
- an alternative method tailored
towards efficient fetching of server-side defaults and triggers
for single-row INSERTs or UPDATEs.
scalar
(*multiparams, **params)¶scalar()
method of Executable
Compile and execute this Executable
, returning the
result’s scalar representation.
self_group
(against=None)¶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)¶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.
values
(*args, **kwargs)¶values()
method of ValuesBase
specify a fixed VALUES clause for an INSERT statement, or the SET clause for an UPDATE.
Note that the Insert
and Update
constructs support
per-execution time formatting of the VALUES and/or SET clauses,
based on the arguments passed to Connection.execute()
.
However, the ValuesBase.values()
method can be used to “fix” a
particular set of parameters into the statement.
Multiple calls to ValuesBase.values()
will produce a new
construct, each one with the parameter list modified to include
the new parameters sent. In the typical case of a single
dictionary of parameters, the newly passed keys will replace
the same keys in the previous construct. In the case of a list-based
“multiple values” construct, each new list of values is extended
onto the existing list of values.
Parameters: |
|
---|
See also
Inserts, Updates and Deletes - SQL Expression Language Tutorial
insert()
- produce an INSERT
statement
update()
- produce an UPDATE
statement
where
(whereclause)¶return a new update() construct with the given expression added to its WHERE clause, joined to the existing clause via AND, if any.
with_hint
(text, selectable=None, dialect_name='*')¶with_hint()
method of UpdateBase
Add a table hint for a single table to this INSERT/UPDATE/DELETE statement.
Note
UpdateBase.with_hint()
currently applies only to
Microsoft SQL Server. For MySQL INSERT/UPDATE/DELETE hints, use
UpdateBase.prefix_with()
.
The text of the hint is rendered in the appropriate
location for the database backend in use, relative
to the Table
that is the subject of this
statement, or optionally to that of the given
Table
passed as the selectable
argument.
The dialect_name
option will limit the rendering of a particular
hint to a particular backend. Such as, to add a hint
that only takes effect for SQL Server:
mytable.insert().with_hint("WITH (PAGLOCK)", dialect_name="mssql")
Parameters: |
|
---|
sqlalchemy.sql.expression.
UpdateBase
¶Bases: sqlalchemy.sql.expression.HasCTE
, sqlalchemy.sql.base.DialectKWArgs
, sqlalchemy.sql.expression.HasPrefixes
, sqlalchemy.sql.expression.Executable
, sqlalchemy.sql.expression.ClauseElement
Form the base for INSERT
, UPDATE
, and DELETE
statements.
__eq__
¶__eq__
attribute of object
Return self==value.
__init__
¶__init__
attribute of object
Initialize self. See help(type(self)) for accurate signature.
__le__
¶__le__
attribute of object
Return self<=value.
__lt__
¶__lt__
attribute of object
Return self<value.
__ne__
¶__ne__
attribute of object
Return self!=value.
argument_for
(dialect_name, argument_name, default)¶argument_for()
method of DialectKWArgs
Add a new kind of dialect-specific keyword argument for this class.
E.g.:
Index.argument_for("mydialect", "length", None)
some_index = Index('a', 'b', mydialect_length=5)
The DialectKWArgs.argument_for()
method is a per-argument
way adding extra arguments to the
DefaultDialect.construct_arguments
dictionary. This
dictionary provides a list of argument names accepted by various
schema-level constructs on behalf of a dialect.
New dialects should typically specify this dictionary all at once as a data member of the dialect class. The use case for ad-hoc addition of argument names is typically for end-user code that is also using a custom compilation scheme which consumes the additional arguments.
Parameters: |
|
---|
New in version 0.9.4.
bind
¶Return a ‘bind’ linked to this UpdateBase
or a Table
associated with it.
compare
(other, **kw)¶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
(default, bind=None, dialect=None, **kw)¶compile()
method of ClauseElement
Compile this SQL expression.
The return value is a Compiled
object.
Calling str()
or unicode()
on the returned value will yield a
string representation of the result. The
Compiled
object also can return a
dictionary of bind parameter names and values
using the params
accessor.
Parameters: |
|
---|
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.
Changed in version 1.1: Added support for UPDATE/INSERT/DELETE as CTE, CTEs added to UPDATE/INSERT/DELETE.
Parameters: |
|
---|
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:
from datetime import date
from sqlalchemy import (MetaData, Table, Column, Integer,
Date, select, literal, and_, exists)
metadata = MetaData()
visitors = Table('visitors', metadata,
Column('product_id', Integer, primary_key=True),
Column('date', Date, primary_key=True),
Column('count', Integer),
)
# add 5 visitors for the product_id == 1
product_id = 1
day = date.today()
count = 5
update_cte = (
visitors.update()
.where(and_(visitors.c.product_id == product_id,
visitors.c.date == day))
.values(count=visitors.c.count + count)
.returning(literal(1))
.cte('update_cte')
)
upsert = visitors.insert().from_select(
[visitors.c.product_id, visitors.c.date, visitors.c.count],
select([literal(product_id), literal(day), literal(count)])
.where(~exists(update_cte.select()))
)
connection.execute(upsert)
See also
orm.query.Query.cte()
- ORM version of
HasCTE.cte()
.
dialect_kwargs
¶dialect_kwargs
attribute of DialectKWArgs
A collection of keyword arguments specified as dialect-specific options to this construct.
The arguments are present here in their original <dialect>_<kwarg>
format. Only arguments that were actually passed are included;
unlike the DialectKWArgs.dialect_options
collection, which
contains all options known by this dialect including defaults.
The collection is also writable; keys are accepted of the
form <dialect>_<kwarg>
where the value will be assembled
into the list of options.
New in version 0.9.2.
Changed in version 0.9.4: The DialectKWArgs.dialect_kwargs
collection is now writable.
See also
DialectKWArgs.dialect_options
- nested dictionary form
dialect_options
¶dialect_options
attribute of DialectKWArgs
A collection of keyword arguments specified as dialect-specific options to this construct.
This is a two-level nested registry, keyed to <dialect_name>
and <argument_name>
. For example, the postgresql_where
argument would be locatable as:
arg = my_object.dialect_options['postgresql']['where']
New in version 0.9.2.
See also
DialectKWArgs.dialect_kwargs
- flat dictionary form
execute
(*multiparams, **params)¶execute()
method of Executable
Compile and execute this Executable
.
execution_options
(**kw)¶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.
get_children
(**kwargs)¶get_children()
method of ClauseElement
Return immediate child elements of this ClauseElement
.
This is used for visit traversal.
**kwargs may contain flags that change the collection that is returned, for example to return a subset of items in order to cut down on larger traversals, or to return child items from a different context (such as schema-level collections instead of clause-level).
get_execution_options
()¶get_execution_options()
method of Executable
Get the non-SQL options which will take effect during execution.
New in version 1.3.
See also
kwargs
¶kwargs
attribute of DialectKWArgs
A synonym for DialectKWArgs.dialect_kwargs
.
params
(*arg, **kw)¶Set the parameters for the statement.
This method raises NotImplementedError
on the base class,
and is overridden by ValuesBase
to provide the
SET/VALUES clause of UPDATE and INSERT.
prefix_with
(*expr, **kw)¶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")
# MySQL 5.7 optimizer hints
stmt = select([table]).prefix_with(
"/*+ BKA(t1) */", dialect="mysql")
Multiple prefixes can be specified by multiple calls
to prefix_with()
.
Parameters: |
|
---|
returning
(*cols)¶Add a RETURNING or equivalent clause to this statement.
e.g.:
stmt = table.update().\
where(table.c.data == 'value').\
values(status='X').\
returning(table.c.server_flag,
table.c.updated_timestamp)
for server_flag, updated_timestamp in connection.execute(stmt):
print(server_flag, updated_timestamp)
The given collection of column expressions should be derived from
the table that is
the target of the INSERT, UPDATE, or DELETE. While Column
objects are typical, the elements can also be expressions:
stmt = table.insert().returning(
(table.c.first_name + " " + table.c.last_name).
label('fullname'))
Upon compilation, a RETURNING clause, or database equivalent, will be rendered within the statement. For INSERT and UPDATE, the values are the newly inserted/updated values. For DELETE, the values are those of the rows which were deleted.
Upon execution, the values of the columns to be returned are made
available via the result set and can be iterated using
ResultProxy.fetchone()
and similar. For DBAPIs which do not
natively support returning values (i.e. cx_oracle), SQLAlchemy will
approximate this behavior at the result level so that a reasonable
amount of behavioral neutrality is provided.
Note that not all databases/DBAPIs support RETURNING. For those backends with no support, an exception is raised upon compilation and/or execution. For those who do support it, the functionality across backends varies greatly, including restrictions on executemany() and other statements which return multiple rows. Please read the documentation notes for the database in use in order to determine the availability of RETURNING.
See also
ValuesBase.return_defaults()
- an alternative method tailored
towards efficient fetching of server-side defaults and triggers
for single-row INSERTs or UPDATEs.
scalar
(*multiparams, **params)¶scalar()
method of Executable
Compile and execute this Executable
, returning the
result’s scalar representation.
self_group
(against=None)¶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)¶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_hint
(text, selectable=None, dialect_name='*')¶Add a table hint for a single table to this INSERT/UPDATE/DELETE statement.
Note
UpdateBase.with_hint()
currently applies only to
Microsoft SQL Server. For MySQL INSERT/UPDATE/DELETE hints, use
UpdateBase.prefix_with()
.
The text of the hint is rendered in the appropriate
location for the database backend in use, relative
to the Table
that is the subject of this
statement, or optionally to that of the given
Table
passed as the selectable
argument.
The dialect_name
option will limit the rendering of a particular
hint to a particular backend. Such as, to add a hint
that only takes effect for SQL Server:
mytable.insert().with_hint("WITH (PAGLOCK)", dialect_name="mssql")
Parameters: |
|
---|
sqlalchemy.sql.expression.
ValuesBase
(table, values, prefixes)¶Bases: sqlalchemy.sql.expression.UpdateBase
Supplies support for ValuesBase.values()
to
INSERT and UPDATE constructs.
return_defaults
(*cols)¶Make use of a RETURNING clause for the purpose of fetching server-side expressions and defaults.
E.g.:
stmt = table.insert().values(data='newdata').return_defaults()
result = connection.execute(stmt)
server_created_at = result.returned_defaults['created_at']
When used against a backend that supports RETURNING, all column
values generated by SQL expression or server-side-default will be
added to any existing RETURNING clause, provided that
UpdateBase.returning()
is not used simultaneously. The column
values will then be available on the result using the
ResultProxy.returned_defaults
accessor as a dictionary,
referring to values keyed to the Column
object as well as
its .key
.
This method differs from UpdateBase.returning()
in these ways:
ValuesBase.return_defaults()
is only intended for use with
an INSERT or an UPDATE statement that matches exactly one row.
While the RETURNING construct in the general sense supports
multiple rows for a multi-row UPDATE or DELETE statement, or for
special cases of INSERT that return multiple rows (e.g. INSERT from
SELECT, multi-valued VALUES clause),
ValuesBase.return_defaults()
is intended only for an
“ORM-style” single-row INSERT/UPDATE statement. The row returned
by the statement is also consumed implicitly when
ValuesBase.return_defaults()
is used. By contrast,
UpdateBase.returning()
leaves the RETURNING result-set
intact with a collection of any number of rows.UpdateBase.returning()
method circumvents this behavior,
ValuesBase.return_defaults()
leaves it intact.ResultProxy.returned_defaults
will be None
ValuesBase.return_defaults()
is used by the ORM to provide
an efficient implementation for the eager_defaults
feature of
mapper()
.
Parameters: | cols¶ – optional list of column key names or Column
objects. If omitted, all column expressions evaluated on the server
are added to the returning list. |
---|
New in version 0.9.0.
values
(*args, **kwargs)¶specify a fixed VALUES clause for an INSERT statement, or the SET clause for an UPDATE.
Note that the Insert
and Update
constructs support
per-execution time formatting of the VALUES and/or SET clauses,
based on the arguments passed to Connection.execute()
.
However, the ValuesBase.values()
method can be used to “fix” a
particular set of parameters into the statement.
Multiple calls to ValuesBase.values()
will produce a new
construct, each one with the parameter list modified to include
the new parameters sent. In the typical case of a single
dictionary of parameters, the newly passed keys will replace
the same keys in the previous construct. In the case of a list-based
“multiple values” construct, each new list of values is extended
onto the existing list of values.
Parameters: |
|
---|
See also
Inserts, Updates and Deletes - SQL Expression Language Tutorial
insert()
- produce an INSERT
statement
update()
- produce an UPDATE
statement