sqlnet.log
/mapping_setup.py
/test.py
+/.cache/
.. changelog::
:version: 1.0.10
+ .. change::
+ :tags: feature, sql
+ :versions: 1.1.0b1
+ :pullreq: github:200
+
+ Added support for parameter-ordered SET clauses in an UPDATE
+ statement. This feature is available by passing the
+ :paramref:`~.sqlalchemy.sql.expression.update.preserve_parameter_order`
+ flag either to the core :class:`.Update` construct or alternatively
+ adding it to the :paramref:`.Query.update.update_args` dictionary at
+ the ORM-level, also passing the parameters themselves as a list of 2-tuples.
+ Thanks to Gorka Eguileor for implementation and tests.
+
+ .. seealso::
+
+ :ref:`updates_order_parameters`
+
.. change::
:tags: bug, orm
:versions: 1.1.0b1
when multiple tables are present, and the statement will be rejected
by the database if this syntax is not supported.
+.. _updates_order_parameters:
+
+Parameter-Ordered Updates
+--------------------------
+
+The default behavior of the :func:`.update` construct when rendering the SET
+clauses is to render them using the column ordering given in the
+originating :class:`.Table` object.
+This is an important behavior, since it means that the rendering of a
+particular UPDATE statement with particular columns
+will be rendered the same each time, which has an impact on query caching systems
+that rely on the form of the statement, either client side or server side.
+Since the parameters themselves are passed to the :meth:`.Update.values`
+method as Python dictionary keys, there is no other fixed ordering
+available.
+
+However in some cases, the order of parameters rendered in the SET clause of an
+UPDATE statement can be significant. The main example of this is when using
+MySQL and providing updates to column values based on that of other
+column values. The end result of the following statement::
+
+ UPDATE some_table SET x = y + 10, y = 20
+
+Will have a different result than::
+
+ UPDATE some_table SET y = 20, x = y + 10
+
+This because on MySQL, the individual SET clauses are fully evaluated on
+a per-value basis, as opposed to on a per-row basis, and as each SET clause
+is evaluated, the values embedded in the row are changing.
+
+To suit this specific use case, the
+:paramref:`~sqlalchemy.sql.expression.update.preserve_parameter_order`
+flag may be used. When using this flag, we supply a **Python list of 2-tuples**
+as the argument to the :meth:`.Update.values` method::
+
+ stmt = some_table.update(preserve_parameter_order=True).\
+ values([(some_table.c.y, 20), (some_table.c.x, some_table.c.y + 10)])
+
+The list of 2-tuples is essentially the same structure as a Python dictionary
+except it is ordered. Using the above form, we are assured that the
+"y" column's SET clause will render first, then the "x" column's SET clause.
+
+.. versionadded:: 1.0.10 Added support for explicit ordering of UPDATE
+ parameters using the :paramref:`~sqlalchemy.sql.expression.update.preserve_parameter_order` flag.
+
+
.. _deletes:
Deletes
"Invalid expression type: %r" % key)
def _do_exec(self):
- values = dict(
+
+ values = [
(self._resolve_string_to_expr(k), v)
- for k, v in self.values.items()
- )
+ for k, v in (
+ self.values.items() if hasattr(self.values, 'items')
+ else self.values)
+ ]
+ if not self.update_kwargs.get('preserve_parameter_order', False):
+ values = dict(values)
+
update_stmt = sql.update(self.primary_table,
self.context.whereclause, values,
**self.update_kwargs)
def _additional_evaluators(self, evaluator_compiler):
self.value_evaluators = {}
- for key, value in self.values.items():
+ values = (self.values.items() if hasattr(self.values, 'items')
+ else self.values)
+ for key, value in values:
key = self._resolve_key_to_attrname(key)
if key is not None:
self.value_evaluators[key] = evaluator_compiler.process(
:param values: a dictionary with attributes names, or alternatively
mapped attributes or SQL expressions, as keys, and literal
- values or sql expressions as values.
+ values or sql expressions as values. If :ref:`parameter-ordered
+ mode <updates_order_parameters>` is desired, the values can be
+ passed as a list of 2-tuples;
+ this requires that the :paramref:`~sqlalchemy.sql.expression.update.preserve_parameter_order`
+ flag is passed to the :paramref:`.Query.update.update_args` dictionary
+ as well.
.. versionchanged:: 1.0.0 - string names in the values dictionary
are now resolved against the mapped entity; previously, these
:param update_args: Optional dictionary, if present will be passed
to the underlying :func:`.update` construct as the ``**kw`` for
the object. May be used to pass dialect-specific arguments such
- as ``mysql_limit``.
+ as ``mysql_limit``, as well as other special arguments such as
+ :paramref:`~sqlalchemy.sql.expression.update.preserve_parameter_order`.
.. versionadded:: 1.0.0
implicit_return_defaults, postfetch_lastrowid = \
_get_returning_modifiers(compiler, stmt)
- cols = stmt.table.columns
+ if stmt._parameter_ordering:
+ parameter_ordering = [
+ _column_as_key(key) for key in stmt._parameter_ordering
+ ]
+ ordered_keys = set(parameter_ordering)
+ cols = [
+ stmt.table.c[key] for key in parameter_ordering
+ ] + [
+ c for c in stmt.table.c if c.key not in ordered_keys
+ ]
+ else:
+ cols = stmt.table.columns
for c in cols:
col_key = _getattr_col_key(c)
_execution_options = \
Executable._execution_options.union({'autocommit': True})
_hints = util.immutabledict()
+ _parameter_ordering = None
_prefixes = ()
def _process_colparams(self, parameters):
else:
return p
+ if self._preserve_parameter_order and parameters is not None:
+ if not isinstance(parameters, list) or \
+ (parameters and not isinstance(parameters[0], tuple)):
+ raise ValueError(
+ "When preserve_parameter_order is True, "
+ "values() only accepts a list of 2-tuples")
+ self._parameter_ordering = [key for key, value in parameters]
+
+ return dict(parameters), False
+
if (isinstance(parameters, (list, tuple)) and parameters and
isinstance(parameters[0], (list, tuple, dict))):
_supports_multi_parameters = False
_has_multi_parameters = False
+ _preserve_parameter_order = False
select = None
def __init__(self, table, values, prefixes):
users.update().where(users.c.id==5).values(name="some name")
- :param \*args: Alternatively, 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 single dictionary form
- works the same as the kwargs form::
+ :param \*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 :class:`.Insert` or an :class:`.Update`
+ construct.
+
+ For either an :class:`.Insert` or :class:`.Update` construct, a
+ single dictionary can be passed, which works the same as that of
+ the kwargs form::
users.insert().values({"name": "some name"})
- If a tuple is passed, the tuple should contain the same number
- of columns as the target :class:`.Table`::
+ users.update().values({"name": "some new name"})
+
+ Also for either form but more typically for the :class:`.Insert`
+ construct, a tuple that contains an entry for every column in the
+ table is also accepted::
users.insert().values((5, "some name"))
- The :class:`.Insert` construct also supports multiply-rendered VALUES
- construct, for those backends which support this SQL syntax
- (SQLite, Postgresql, MySQL). This mode is indicated by passing a
- list of one or more dictionaries/tuples::
+ The :class:`.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": "yet another name"},
])
- In the case of an :class:`.Update`
- construct, only the single dictionary/tuple form is accepted,
- else an exception is raised. It is also an exception case to
- attempt to mix the single-/multiple- value styles together,
- either through multiple :meth:`.ValuesBase.values` calls
- or by sending a list + kwargs at the same time.
-
- .. note::
-
- Passing a multiple values list is *not* the same
- as passing a multiple values list to the
- :meth:`.Connection.execute` method. Passing a list of parameter
- sets to :meth:`.ValuesBase.values` produces a construct of this
- form::
-
- INSERT INTO table (col1, col2, col3) VALUES
- (col1_0, col2_0, col3_0),
- (col1_1, col2_1, col3_1),
- ...
-
- whereas a multiple list passed to :meth:`.Connection.execute`
- has the effect of using the DBAPI
- `executemany() <http://www.python.org/dev/peps/pep-0249/#id18>`_
- method, which provides a high-performance system of invoking
- a single-row INSERT or single-criteria UPDATE or DELETE statement
- many times against a series
- of parameter sets. The "executemany" style is supported by
- all database backends, and works equally well for INSERT,
- UPDATE, and DELETE, as it does not depend on a special SQL
- syntax. See :ref:`execute_multiple` for an introduction to
- the traditional Core method of multiple parameter set invocation
- using this system.
-
- .. versionadded:: 0.8
- Support for multiple-VALUES INSERT statements.
-
- .. versionchanged:: 1.0.0 an INSERT that uses a multiple-VALUES
- clause, even a list of length one,
- implies that the :paramref:`.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
- :attr:`.ResultProxy.inserted_primary_key` accessor does not apply.
-
- .. versionchanged:: 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 :ref:`bug_3288`
- for other details.
+ 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 mutliple rows, the normal method is
+ to pass a mutiple values list to the :meth:`.Connection.execute`
+ method, which is supported by all database backends and is generally
+ more efficient for a very large number of parameters.
+
+ .. seealso::
+
+ :ref:`execute_multiple` - an introduction to
+ the traditional Core method of multiple parameter set
+ invocation for INSERTs and other statements.
+
+ .. versionchanged:: 1.0.0 an INSERT that uses a multiple-VALUES
+ clause, even a list of length one,
+ implies that the :paramref:`.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
+ :attr:`.ResultProxy.inserted_primary_key` accessor does not
+ apply.
+
+ .. versionchanged:: 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 :ref:`bug_3288`
+ for other details.
+
+ The :class:`.Update` construct supports a special form which is a
+ list of 2-tuples, which when provided must be passed in conjunction
+ with the
+ :paramref:`~sqlalchemy.sql.expression.update.preserve_parameter_order`
+ parameter.
+ This form causes the UPDATE statement to render the SET clauses
+ using the order of parameters given to :meth:`.Update.values`, rather
+ than the ordering of columns given in the :class:`.Table`.
+
+ .. versionadded:: 1.0.10 - added support for parameter-ordered
+ UPDATE statements via the
+ :paramref:`~sqlalchemy.sql.expression.update.preserve_parameter_order`
+ flag.
+
+ .. seealso::
+
+ :ref:`updates_order_parameters` - full example of the
+ :paramref:`~sqlalchemy.sql.expression.update.preserve_parameter_order`
+ flag
.. seealso::
prefixes=None,
returning=None,
return_defaults=False,
+ preserve_parameter_order=False,
**dialect_kw):
"""Construct an :class:`.Update` object.
be available in the dictionary returned from
:meth:`.ResultProxy.last_updated_params`.
+ :param preserve_parameter_order: if True, the update statement is
+ expected to receive parameters **only** via the :meth:`.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.
+
+ .. versionadded:: 1.0.10
+
+ .. seealso::
+
+ :ref:`updates_order_parameters` - full example of the
+ :paramref:`~sqlalchemy.sql.expression.update.preserve_parameter_order` flag
+
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.
"""
+ self._preserve_parameter_order = preserve_parameter_order
ValuesBase.__init__(self, table, values, prefixes)
self._bind = bind
self._returning = returning
return pairs
-
class ClauseAdapter(visitors.ReplacingCloningVisitor):
"""Clones and modifies clauses based on column correspondence.
testing.db,
sess.flush,
CompiledSQL(
- "UPDATE parent SET c1_id=:c1_id, c2_id=:c2_id, "
- "c3_id=:c3_id WHERE parent.id = :parent_id",
- lambda ctx: {'c2_id': c23.id, 'parent_id': p1.id, 'c1_id': c12.id, 'c3_id': c31.id}
+ "UPDATE parent SET c1_id=:c1_id, c2_id=:c2_id, c3_id=:c3_id "
+ "WHERE parent.id = :parent_id",
+ lambda ctx: {'c2_id': c23.id, 'parent_id': p1.id,
+ 'c1_id': c12.id, 'c3_id': c31.id}
)
)
testing.db,
sess.flush,
CompiledSQL(
- "UPDATE parent SET c1_id=:c1_id, c2_id=:c2_id, "
- "c3_id=:c3_id WHERE parent.id = :parent_id",
- lambda ctx: {'c2_id': None, 'parent_id': p1.id, 'c1_id': None, 'c3_id': None}
+ "UPDATE parent SET c1_id=:c1_id, c2_id=:c2_id, c3_id=:c3_id "
+ "WHERE parent.id = :parent_id",
+ lambda ctx: {'c2_id': None, 'parent_id': p1.id,
+ 'c1_id': None, 'c3_id': None}
)
)
-from sqlalchemy.testing import eq_, assert_raises, assert_raises_message
+from sqlalchemy.testing import eq_, assert_raises, assert_raises_message, is_
from sqlalchemy.testing import fixtures
from sqlalchemy import Integer, String, ForeignKey, or_, exc, \
select, func, Boolean, case, text, column
from sqlalchemy.orm import mapper, relationship, backref, Session, \
joinedload, synonym, query
from sqlalchemy import testing
+from sqlalchemy.testing import mock
from sqlalchemy.testing.schema import Table, Column
synchronize_session='fetch')
assert john not in sess
+ def test_update_unordered_dict(self):
+ User = self.classes.User
+ session = Session()
+
+ # Do an update using unordered dict and check that the parameters used
+ # are ordered in table order
+ with mock.patch.object(session, "execute") as exec_:
+ session.query(User).filter(User.id == 15).update(
+ {'name': 'foob', 'id': 123})
+ # Confirm that parameters are a dict instead of tuple or list
+ params_type = type(exec_.mock_calls[0][1][0].parameters)
+ is_(params_type, dict)
+
+ def test_update_preserve_parameter_order(self):
+ User = self.classes.User
+ session = Session()
+
+ # Do update using a tuple and check that order is preserved
+ with mock.patch.object(session, "execute") as exec_:
+ session.query(User).filter(User.id == 15).update(
+ (('id', 123), ('name', 'foob')),
+ update_args={"preserve_parameter_order": True})
+ cols = [c.key
+ for c in exec_.mock_calls[0][1][0]._parameter_ordering]
+ eq_(['id', 'name'], cols)
+
+ # Now invert the order and use a list instead, and check that order is
+ # also preserved
+ with mock.patch.object(session, "execute") as exec_:
+ session.query(User).filter(User.id == 15).update(
+ [('name', 'foob'), ('id', 123)],
+ update_args={"preserve_parameter_order": True})
+ cols = [c.key
+ for c in exec_.mock_calls[0][1][0]._parameter_ordering]
+ eq_(['name', 'id'], cols)
+
class UpdateDeleteIgnoresLoadersTest(fixtures.MappedTest):
from sqlalchemy.engine import default
from sqlalchemy.testing import AssertsCompiledSQL, eq_, fixtures
from sqlalchemy.testing.schema import Table, Column
+from sqlalchemy import util
class _UpdateFromTestBase(object):
test_needs_autoincrement=True),
Column('address_id', None, ForeignKey('addresses.id')),
Column('data', String(30)))
+ Table('update_w_default', metadata,
+ Column('id', Integer, primary_key=True),
+ Column('x', Integer),
+ Column('ycol', Integer, key='y'),
+ Column('data', String(30), onupdate=lambda: "hi"))
@classmethod
def fixtures(cls):
table1.c.name: table1.c.name + 'lala',
table1.c.myid: func.do_stuff(table1.c.myid, literal('hoho'))
}
+
+ self.assert_compile(
+ update(
+ table1,
+ (table1.c.myid == func.hoho(4)) & (
+ table1.c.name == literal('foo') +
+ table1.c.name +
+ literal('lala')),
+ values=values),
+ 'UPDATE mytable '
+ 'SET '
+ 'myid=do_stuff(mytable.myid, :param_1), '
+ 'name=(mytable.name || :name_1) '
+ 'WHERE '
+ 'mytable.myid = hoho(:hoho_1) AND '
+ 'mytable.name = :param_2 || mytable.name || :param_3')
+
+ def test_update_ordered_parameters_1(self):
+ table1 = self.tables.mytable
+
+ # Confirm that we can pass values as list value pairs
+ # note these are ordered *differently* from table.c
+ values = [
+ (table1.c.name, table1.c.name + 'lala'),
+ (table1.c.myid, func.do_stuff(table1.c.myid, literal('hoho'))),
+ ]
+ self.assert_compile(
+ update(
+ table1,
+ (table1.c.myid == func.hoho(4)) & (
+ table1.c.name == literal('foo') +
+ table1.c.name +
+ literal('lala')),
+ preserve_parameter_order=True,
+ values=values),
+ 'UPDATE mytable '
+ 'SET '
+ 'name=(mytable.name || :name_1), '
+ 'myid=do_stuff(mytable.myid, :param_1) '
+ 'WHERE '
+ 'mytable.myid = hoho(:hoho_1) AND '
+ 'mytable.name = :param_2 || mytable.name || :param_3')
+
+ def test_update_ordered_parameters_2(self):
+ table1 = self.tables.mytable
+
+ # Confirm that we can pass values as list value pairs
+ # note these are ordered *differently* from table.c
+ values = [
+ (table1.c.name, table1.c.name + 'lala'),
+ ('description', 'some desc'),
+ (table1.c.myid, func.do_stuff(table1.c.myid, literal('hoho')))
+ ]
+ self.assert_compile(
+ update(
+ table1,
+ (table1.c.myid == func.hoho(4)) & (
+ table1.c.name == literal('foo') +
+ table1.c.name +
+ literal('lala')),
+ preserve_parameter_order=True).values(values),
+ 'UPDATE mytable '
+ 'SET '
+ 'name=(mytable.name || :name_1), '
+ 'description=:description, '
+ 'myid=do_stuff(mytable.myid, :param_1) '
+ 'WHERE '
+ 'mytable.myid = hoho(:hoho_1) AND '
+ 'mytable.name = :param_2 || mytable.name || :param_3')
+
+ def test_update_ordered_parameters_fire_onupdate(self):
+ table = self.tables.update_w_default
+
+ values = [
+ (table.c.y, table.c.x + 5),
+ ('x', 10)
+ ]
+
+ self.assert_compile(
+ table.update(preserve_parameter_order=True).values(values),
+ "UPDATE update_w_default SET ycol=(update_w_default.x + :x_1), "
+ "x=:x, data=:data"
+ )
+
+ def test_update_ordered_parameters_override_onupdate(self):
+ table = self.tables.update_w_default
+
+ values = [
+ (table.c.y, table.c.x + 5),
+ (table.c.data, table.c.x + 10),
+ ('x', 10)
+ ]
+
+ self.assert_compile(
+ table.update(preserve_parameter_order=True).values(values),
+ "UPDATE update_w_default SET ycol=(update_w_default.x + :x_1), "
+ "data=(update_w_default.x + :x_2), x=:x"
+ )
+
+ def test_update_preserve_order_reqs_listtups(self):
+ table1 = self.tables.mytable
+ testing.assert_raises_message(
+ ValueError,
+ "When preserve_parameter_order is True, values\(\) "
+ "only accepts a list of 2-tuples",
+ table1.update(preserve_parameter_order=True).values,
+ {"description": "foo", "name": "bar"}
+ )
+
+ def test_update_ordereddict(self):
+ table1 = self.tables.mytable
+
+ # Confirm that ordered dicts are treated as normal dicts,
+ # columns sorted in table order
+ values = util.OrderedDict((
+ (table1.c.name, table1.c.name + 'lala'),
+ (table1.c.myid, func.do_stuff(table1.c.myid, literal('hoho')))))
+
self.assert_compile(
update(
table1,