Insert, Updates, Deletes

INSERT, UPDATE and DELETE statements build on a hierarchy starting with UpdateBase. The Insert and Update constructs build on the intermediary ValuesBase.

DML Foundational Constructors

Top level “INSERT”, “UPDATE”, “DELETE” constructors.

Object Name Description

delete(table[, whereclause, bind, returning, ...], **dialect_kw)

Construct Delete object.

insert(table[, values, inline, bind, ...], **dialect_kw)

Construct an Insert object.

update(table[, whereclause, values, inline, ...], **dialect_kw)

Construct an Update object.

function sqlalchemy.sql.expression.delete(table, whereclause=None, bind=None, returning=None, prefixes=None, **dialect_kw)

Construct Delete object.

E.g.:

from sqlalchemy import delete

stmt = (
    delete(user_table).
    where(user_table.c.id == 5)
)

Similar functionality is available via the TableClause.delete() method on Table.

Parameters:
  • table – The table to delete rows from.

  • whereclause

    Optional SQL expression describing the WHERE condition of the DELETE statement; is equivalent to using the more modern Delete.where() method to specify the WHERE clause.

    Deprecated since version 1.4: The delete.whereclause parameter will be removed in SQLAlchemy 2.0. Please refer to the Delete.where() method.

See also

Deletes - SQL Expression Tutorial

function sqlalchemy.sql.expression.insert(table, values=None, inline=False, bind=None, prefixes=None, returning=None, return_defaults=False, **dialect_kw)

Construct an Insert object.

E.g.:

from sqlalchemy import insert

stmt = (
    insert(user_table).
    values(name='username', fullname='Full Username')
)

Similar functionality is available via the TableClause.insert() method on Table.

Parameters:
  • tableTableClause which is the subject of the insert.

  • values

    collection of values to be inserted; see Insert.values() for a description of allowed formats here. Can be omitted entirely; a Insert construct will also dynamically render the VALUES clause at execution time based on the parameters passed to Connection.execute().

    Deprecated since version 1.4: The insert.values parameter will be removed in SQLAlchemy 2.0. Please refer to the Insert.values() method.

  • inline

    if True, no attempt will be made to retrieve the SQL-generated default values to be provided within the statement; in particular, this allows SQL expressions to be rendered ‘inline’ within the statement without the need to pre-execute them beforehand; for backends that support “returning”, this turns off the “implicit returning” feature for the statement.

    Deprecated since version 1.4: The insert.inline parameter will be removed in SQLAlchemy 2.0. Please use the Insert.inline() method.

If both Insert.values and compile-time bind parameters are present, the compile-time bind parameters override the information specified within Insert.values on a per-key basis.

The keys within Insert.values can be either Column objects or their string identifiers. Each key may reference one of:

  • a literal data value (i.e. string, number, etc.);

  • a Column object;

  • a SELECT statement.

If a SELECT statement is specified which references this INSERT statement’s table, the statement will be correlated against the INSERT statement.

function 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(user_table).
    where(user_table.c.id == 5).
    values(name='user #5')
)

Similar functionality is available via the TableClause.update() method on Table.

Parameters:
  • table – A Table object representing the database table to be updated.

  • whereclause

    Optional SQL expression describing the WHERE condition of the UPDATE statement; is equivalent to using the more modern Update.where() method to specify the WHERE clause.

    Deprecated since version 1.4: The update.whereclause parameter will be removed in SQLAlchemy 2.0. Please refer to the Update.where() method.

  • values

    Optional dictionary which specifies the SET conditions of the UPDATE. If left as None, the SET conditions are determined from those parameters passed to the statement during the execution and/or compilation of the statement. When compiled standalone without any parameters, the SET clause generates for all columns.

    Deprecated since version 1.4: The update.values parameter will be removed in SQLAlchemy 2.0. Please refer to the Update.values() method.

    Modern applications may prefer to use the generative Update.values() method to set the values of the UPDATE statement.

  • inline

    if True, SQL defaults present on Column objects via the default keyword will be compiled ‘inline’ into the statement and not pre-executed. This means that their values will not be available in the dictionary returned from CursorResult.last_updated_params().

    Deprecated since version 1.4: The update.inline parameter will be removed in SQLAlchemy 2.0. Please use the Update.inline() method.

  • preserve_parameter_order

    if True, the update statement is expected to receive parameters only via the Update.values() method, and they must be passed as a Python list of 2-tuples. The rendered UPDATE statement will emit the SET clause for each referenced column maintaining this order.

    Deprecated since version 1.4: The update.preserve_parameter_order parameter will be removed in SQLAlchemy 2.0. Use the Update.ordered_values() method with a list of tuples.

    New in version 1.0.10.

    See also

    Parameter-Ordered Updates - illustrates the Update.ordered_values() method.

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:

  • a literal data value (i.e. string, number, etc.)

  • a SQL expression, such as a related 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).\
                scalar_subquery()
    )

See also

Inserts, Updates and Deletes - SQL Expression Language Tutorial

DML Class Documentation Constructors

Class documentation for the constructors listed at DML Foundational Constructors.

Object Name Description

Delete

Represent a DELETE construct.

Insert

Represent an INSERT construct.

Update

Represent an Update construct.

UpdateBase

Form the base for INSERT, UPDATE, and DELETE statements.

ValuesBase

Supplies support for ValuesBase.values() to INSERT and UPDATE constructs.

class sqlalchemy.sql.expression.Delete(table, whereclause=None, bind=None, returning=None, prefixes=None, **dialect_kw)

Represent a DELETE construct.

The Delete object is created using the delete() function.

Class signature

class sqlalchemy.sql.expression.Delete (sqlalchemy.sql.expression.DMLWhereBase, sqlalchemy.sql.expression.UpdateBase)

method sqlalchemy.sql.expression.Delete.where(*whereclause)

inherited from the DMLWhereBase.where() method of DMLWhereBase

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

Both Update.where() and Delete.where() support multiple-table forms, including database-specific UPDATE...FROM as well as DELETE..USING. For backends that don’t have multiple-table support, a backend agnostic approach to using multiple tables is to make use of correlated subqueries. See the linked tutorial sections below for examples.

method sqlalchemy.sql.expression.Delete.returning(*cols)

inherited from the UpdateBase.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)
... )
>>> print(stmt)
UPDATE some_table SET status=:status
WHERE some_table.data = :data_1
RETURNING some_table.server_flag, some_table.updated_timestamp

The method may be invoked multiple times to add new entries to the list of expressions to be returned.

New in version 1.4.0b2: The method may be invoked multiple times to add new entries to the list of expressions to be returned.

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")
... )
>>> print(stmt)
INSERT INTO some_table (first_name, last_name)
VALUES (:first_name, :last_name)
RETURNING some_table.first_name || :first_name_1 || some_table.last_name AS 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 CursorResult.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.

INSERT…RETURNING - in the SQLAlchemy 1.4 / 2.0 Tutorial

method sqlalchemy.sql.expression.Delete.__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 sqlalchemy.sql.expression.delete() for a full usage and argument description.

class sqlalchemy.sql.expression.Insert(table, values=None, inline=False, bind=None, prefixes=None, returning=None, return_defaults=False, **dialect_kw)

Represent an INSERT construct.

The Insert object is created using the insert() function.

method sqlalchemy.sql.expression.Insert.values(*args, **kwargs)

inherited from the ValuesBase.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:
  • **kwargs

    key value pairs representing the string key of a Column mapped to the value to be rendered into the VALUES or SET clause:

    users.insert().values(name="some name")
    
    users.update().where(users.c.id==5).values(name="some name")

  • *args

    As an alternative to passing key/value parameters, a dictionary, tuple, or list of dictionaries or tuples can be passed as a single positional argument in order to form the VALUES or SET clause of the statement. The forms that are accepted vary based on whether this is an Insert or an Update construct.

    For either an Insert or Update construct, a single dictionary can be passed, which works the same as that of the kwargs form:

    users.insert().values({"name": "some name"})
    
    users.update().values({"name": "some new name"})

    Also for either form but more typically for the Insert construct, a tuple that contains an entry for every column in the table is also accepted:

    users.insert().values((5, "some name"))

    The Insert construct also supports being passed a list of dictionaries or full-table-tuples, which on the server will render the less common SQL syntax of “multiple values” - this syntax is supported on backends such as SQLite, PostgreSQL, MySQL, but not necessarily others:

    users.insert().values([
                        {"name": "some name"},
                        {"name": "some other name"},
                        {"name": "yet another name"},
                    ])

    The above form would render a multiple VALUES statement similar to:

    INSERT INTO users (name) VALUES
                    (:name_1),
                    (:name_2),
                    (:name_3)

    It is essential to note that passing multiple values is NOT the same as using traditional executemany() form. The above syntax is a special syntax not typically used. To emit an INSERT statement against multiple rows, the normal method is to pass a multiple values list to the Connection.execute() method, which is supported by all database backends and is generally more efficient for a very large number of parameters.

    See also

    Sending Multiple Parameters - an introduction to the traditional Core method of multiple parameter set invocation for INSERTs and other statements.

    Changed in version 1.0.0: an INSERT that uses a multiple-VALUES clause, even a list of length one, 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 CursorResult.inserted_primary_key accessor does not apply.

    Changed in version 1.0.0: A multiple-VALUES INSERT now supports columns with Python side default values and callables in the same way as that of an “executemany” style of invocation; the callable is invoked for each row. See Python-side defaults invoked for each row individually when using a multivalued insert for other details.

    The UPDATE construct also supports rendering the SET parameters in a specific order. For this feature refer to the Update.ordered_values() method.

method sqlalchemy.sql.expression.Insert.returning(*cols)

inherited from the UpdateBase.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)
... )
>>> print(stmt)
UPDATE some_table SET status=:status
WHERE some_table.data = :data_1
RETURNING some_table.server_flag, some_table.updated_timestamp

The method may be invoked multiple times to add new entries to the list of expressions to be returned.

New in version 1.4.0b2: The method may be invoked multiple times to add new entries to the list of expressions to be returned.

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")
... )
>>> print(stmt)
INSERT INTO some_table (first_name, last_name)
VALUES (:first_name, :last_name)
RETURNING some_table.first_name || :first_name_1 || some_table.last_name AS 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 CursorResult.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.

INSERT…RETURNING - in the SQLAlchemy 1.4 / 2.0 Tutorial

method sqlalchemy.sql.expression.Insert.__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 sqlalchemy.sql.expression.insert() for a full usage and argument description.

method sqlalchemy.sql.expression.Insert.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:
  • names – a sequence of string column names or Column objects representing the target columns.

  • select – a select() construct, FromClause or other construct which resolves into a FromClause, such as an ORM Query object, etc. The order of columns returned from this FROM clause should correspond to the order of columns sent as the names parameter; while this is not checked before passing along to the database, the database would normally raise an exception if these column lists don’t correspond.

  • include_defaults

    if True, non-server default values and SQL expressions as specified on Column objects (as documented in Column INSERT/UPDATE Defaults) not otherwise specified in the list of names will be rendered into the INSERT and SELECT statements, so that these values are also included in the data to be inserted.

    Note

    A Python-side default that uses a Python callable function will only be invoked once for the whole statement, and not per row.

    New in version 1.0.0: - Insert.from_select() now renders Python-side and SQL expression column defaults into the SELECT statement for columns otherwise not included in the list of column names.

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 CursorResult.inserted_primary_key accessor does not apply.

method sqlalchemy.sql.expression.Insert.inline()

Make this Insert construct “inline” .

When set, no attempt will be made to retrieve the SQL-generated default values to be provided within the statement; in particular, this allows SQL expressions to be rendered ‘inline’ within the statement without the need to pre-execute them beforehand; for backends that support “returning”, this turns off the “implicit returning” feature for the statement.

Changed in version 1.4: the Insert.inline parameter is now superseded by the Insert.inline() method.

class 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)

Represent an Update construct.

The Update object is created using the update() function.

Class signature

class sqlalchemy.sql.expression.Update (sqlalchemy.sql.expression.DMLWhereBase, sqlalchemy.sql.expression.ValuesBase)

method sqlalchemy.sql.expression.Update.returning(*cols)

inherited from the UpdateBase.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)
... )
>>> print(stmt)
UPDATE some_table SET status=:status
WHERE some_table.data = :data_1
RETURNING some_table.server_flag, some_table.updated_timestamp

The method may be invoked multiple times to add new entries to the list of expressions to be returned.

New in version 1.4.0b2: The method may be invoked multiple times to add new entries to the list of expressions to be returned.

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")
... )
>>> print(stmt)
INSERT INTO some_table (first_name, last_name)
VALUES (:first_name, :last_name)
RETURNING some_table.first_name || :first_name_1 || some_table.last_name AS 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 CursorResult.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.

INSERT…RETURNING - in the SQLAlchemy 1.4 / 2.0 Tutorial

method sqlalchemy.sql.expression.Update.where(*whereclause)

inherited from the DMLWhereBase.where() method of DMLWhereBase

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

Both Update.where() and Delete.where() support multiple-table forms, including database-specific UPDATE...FROM as well as DELETE..USING. For backends that don’t have multiple-table support, a backend agnostic approach to using multiple tables is to make use of correlated subqueries. See the linked tutorial sections below for examples.

method sqlalchemy.sql.expression.Update.values(*args, **kwargs)

inherited from the ValuesBase.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:
  • **kwargs

    key value pairs representing the string key of a Column mapped to the value to be rendered into the VALUES or SET clause:

    users.insert().values(name="some name")
    
    users.update().where(users.c.id==5).values(name="some name")

  • *args

    As an alternative to passing key/value parameters, a dictionary, tuple, or list of dictionaries or tuples can be passed as a single positional argument in order to form the VALUES or SET clause of the statement. The forms that are accepted vary based on whether this is an Insert or an Update construct.

    For either an Insert or Update construct, a single dictionary can be passed, which works the same as that of the kwargs form:

    users.insert().values({"name": "some name"})
    
    users.update().values({"name": "some new name"})

    Also for either form but more typically for the Insert construct, a tuple that contains an entry for every column in the table is also accepted:

    users.insert().values((5, "some name"))

    The Insert construct also supports being passed a list of dictionaries or full-table-tuples, which on the server will render the less common SQL syntax of “multiple values” - this syntax is supported on backends such as SQLite, PostgreSQL, MySQL, but not necessarily others:

    users.insert().values([
                        {"name": "some name"},
                        {"name": "some other name"},
                        {"name": "yet another name"},
                    ])

    The above form would render a multiple VALUES statement similar to:

    INSERT INTO users (name) VALUES
                    (:name_1),
                    (:name_2),
                    (:name_3)

    It is essential to note that passing multiple values is NOT the same as using traditional executemany() form. The above syntax is a special syntax not typically used. To emit an INSERT statement against multiple rows, the normal method is to pass a multiple values list to the Connection.execute() method, which is supported by all database backends and is generally more efficient for a very large number of parameters.

    See also

    Sending Multiple Parameters - an introduction to the traditional Core method of multiple parameter set invocation for INSERTs and other statements.

    Changed in version 1.0.0: an INSERT that uses a multiple-VALUES clause, even a list of length one, 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 CursorResult.inserted_primary_key accessor does not apply.

    Changed in version 1.0.0: A multiple-VALUES INSERT now supports columns with Python side default values and callables in the same way as that of an “executemany” style of invocation; the callable is invoked for each row. See Python-side defaults invoked for each row individually when using a multivalued insert for other details.

    The UPDATE construct also supports rendering the SET parameters in a specific order. For this feature refer to the Update.ordered_values() method.

method sqlalchemy.sql.expression.Update.__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 sqlalchemy.sql.expression.update() for a full usage and argument description.

method sqlalchemy.sql.expression.Update.inline()

Make this Update construct “inline” .

When set, SQL defaults present on Column objects via the default keyword will be compiled ‘inline’ into the statement and not pre-executed. This means that their values will not be available in the dictionary returned from CursorResult.last_updated_params().

Changed in version 1.4: the update.inline parameter is now superseded by the Update.inline() method.

method sqlalchemy.sql.expression.Update.ordered_values(*args)

Specify the VALUES clause of this UPDATE statement with an explicit parameter ordering that will be maintained in the SET clause of the resulting UPDATE statement.

E.g.:

stmt = table.update().ordered_values(
    ("name", "ed"), ("ident": "foo")
)

See also

Parameter Ordered Updates - full example of the Update.ordered_values() method.

Changed in version 1.4: The Update.ordered_values() method supersedes the update.preserve_parameter_order parameter, which will be removed in SQLAlchemy 2.0.

class sqlalchemy.sql.expression.UpdateBase

Form the base for INSERT, UPDATE, and DELETE statements.

attribute sqlalchemy.sql.expression.UpdateBase.bind

Return a ‘bind’ linked to this UpdateBase or a Table associated with it.

attribute sqlalchemy.sql.expression.UpdateBase.entity_description

Return a plugin-enabled description of the table and/or entity which this DML construct is operating against.

This attribute is generally useful when using the ORM, as an extended structure which includes information about mapped entities is returned. The section Inspecting entities and columns from ORM-enabled SELECT and DML statements contains more background.

For a Core statement, the structure returned by this accessor is derived from the UpdateBase.table attribute, and refers to the Table being inserted, updated, or deleted:

>>> stmt = insert(user_table)
>>> stmt.entity_description
{
    "name": "user_table",
    "table": Table("user_table", ...)
}

New in version 1.4.33.

attribute sqlalchemy.sql.expression.UpdateBase.exported_columns

Return the RETURNING columns as a column collection for this statement.

New in version 1.4.

method sqlalchemy.sql.expression.UpdateBase.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.

method sqlalchemy.sql.expression.UpdateBase.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)
... )
>>> print(stmt)
UPDATE some_table SET status=:status
WHERE some_table.data = :data_1
RETURNING some_table.server_flag, some_table.updated_timestamp

The method may be invoked multiple times to add new entries to the list of expressions to be returned.

New in version 1.4.0b2: The method may be invoked multiple times to add new entries to the list of expressions to be returned.

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")
... )
>>> print(stmt)
INSERT INTO some_table (first_name, last_name)
VALUES (:first_name, :last_name)
RETURNING some_table.first_name || :first_name_1 || some_table.last_name AS 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 CursorResult.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.

INSERT…RETURNING - in the SQLAlchemy 1.4 / 2.0 Tutorial

attribute sqlalchemy.sql.expression.UpdateBase.returning_column_descriptions

Return a plugin-enabled description of the columns which this DML construct is RETURNING against, in other words the expressions established as part of UpdateBase.returning().

This attribute is generally useful when using the ORM, as an extended structure which includes information about mapped entities is returned. The section Inspecting entities and columns from ORM-enabled SELECT and DML statements contains more background.

For a Core statement, the structure returned by this accessor is derived from the same objects that are returned by the UpdateBase.exported_columns accessor:

>>> stmt = insert(user_table).returning(user_table.c.id, user_table.c.name)
>>> stmt.entity_description
[
    {
        "name": "id",
        "type": Integer,
        "expr": Column("id", Integer(), table=<user>, ...)
    },
    {
        "name": "name",
        "type": String(),
        "expr": Column("name", String(), table=<user>, ...)
    },
]

New in version 1.4.33.

method sqlalchemy.sql.expression.UpdateBase.with_dialect_options(**opt)

Add dialect options to this INSERT/UPDATE/DELETE object.

e.g.:

upd = table.update().dialect_options(mysql_limit=10)
method sqlalchemy.sql.expression.UpdateBase.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:
  • text – Text of the hint.

  • selectable – optional Table that specifies an element of the FROM clause within an UPDATE or DELETE to be the subject of the hint - applies only to certain backends.

  • dialect_name – defaults to *, if specified as the name of a particular dialect, will apply these hints only when that dialect is in use.

class sqlalchemy.sql.expression.ValuesBase(table, values, prefixes)

Supplies support for ValuesBase.values() to INSERT and UPDATE constructs.

method sqlalchemy.sql.expression.ValuesBase.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 CursorResult.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:

  1. ValuesBase.return_defaults() is only intended for use with an INSERT or an UPDATE statement that matches exactly one row per parameter set. 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.

  2. It is compatible with the existing logic to fetch auto-generated primary key values, also known as “implicit returning”. Backends that support RETURNING will automatically make use of RETURNING in order to fetch the value of newly generated primary keys; while the UpdateBase.returning() method circumvents this behavior, ValuesBase.return_defaults() leaves it intact.

  3. It can be called against any backend. Backends that don’t support RETURNING will skip the usage of the feature, rather than raising an exception. The return value of CursorResult.returned_defaults will be None

  4. An INSERT statement invoked with executemany() is supported if the backend database driver supports the insert_executemany_returning feature, currently this includes PostgreSQL with psycopg2. When executemany is used, the CursorResult.returned_defaults_rows and CursorResult.inserted_primary_key_rows accessors will return the inserted defaults and primary keys.

    New in version 1.4.

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.

method sqlalchemy.sql.expression.ValuesBase.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:
  • **kwargs

    key value pairs representing the string key of a Column mapped to the value to be rendered into the VALUES or SET clause:

    users.insert().values(name="some name")
    
    users.update().where(users.c.id==5).values(name="some name")

  • *args

    As an alternative to passing key/value parameters, a dictionary, tuple, or list of dictionaries or tuples can be passed as a single positional argument in order to form the VALUES or SET clause of the statement. The forms that are accepted vary based on whether this is an Insert or an Update construct.

    For either an Insert or Update construct, a single dictionary can be passed, which works the same as that of the kwargs form:

    users.insert().values({"name": "some name"})
    
    users.update().values({"name": "some new name"})

    Also for either form but more typically for the Insert construct, a tuple that contains an entry for every column in the table is also accepted:

    users.insert().values((5, "some name"))

    The Insert construct also supports being passed a list of dictionaries or full-table-tuples, which on the server will render the less common SQL syntax of “multiple values” - this syntax is supported on backends such as SQLite, PostgreSQL, MySQL, but not necessarily others:

    users.insert().values([
                        {"name": "some name"},
                        {"name": "some other name"},
                        {"name": "yet another name"},
                    ])

    The above form would render a multiple VALUES statement similar to:

    INSERT INTO users (name) VALUES
                    (:name_1),
                    (:name_2),
                    (:name_3)

    It is essential to note that passing multiple values is NOT the same as using traditional executemany() form. The above syntax is a special syntax not typically used. To emit an INSERT statement against multiple rows, the normal method is to pass a multiple values list to the Connection.execute() method, which is supported by all database backends and is generally more efficient for a very large number of parameters.

    See also

    Sending Multiple Parameters - an introduction to the traditional Core method of multiple parameter set invocation for INSERTs and other statements.

    Changed in version 1.0.0: an INSERT that uses a multiple-VALUES clause, even a list of length one, 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 CursorResult.inserted_primary_key accessor does not apply.

    Changed in version 1.0.0: A multiple-VALUES INSERT now supports columns with Python side default values and callables in the same way as that of an “executemany” style of invocation; the callable is invoked for each row. See Python-side defaults invoked for each row individually when using a multivalued insert for other details.

    The UPDATE construct also supports rendering the SET parameters in a specific order. For this feature refer to the Update.ordered_values() method.