You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
- The version_id_generator parameter of Mapper can now be specified
to rely upon server generated version identifiers, using triggers
or other database-provided versioning features, by passing the value
``False``. The ORM will use RETURNING when available to immediately
load the new version identifier, else it will emit a second SELECT.
[ticket:2793]
- The ``eager_defaults`` flag of :class:`.Mapper` will now allow the
newly generated default values to be fetched using an inline
RETURNING clause, rather than a second SELECT statement, for backends
that support RETURNING.
- Added a new variant to :meth:`.ValuesBase.returning` called
:meth:`.ValuesBase.return_defaults`; this allows arbitrary columns
to be added to the RETURNING clause of the statement without interfering
with the compilers usual "implicit returning" feature, which is used to
efficiently fetch newly generated primary key values. For supporting
backends, a dictionary of all fetched values is present at
:attr:`.ResultProxy.returned_defaults`.
- add a glossary entry for RETURNING
- add documentation for version id generation, [ticket:867]
Copy file name to clipboardExpand all lines: doc/build/orm/mapper_config.rst
+196Lines changed: 196 additions & 0 deletions
Original file line number
Diff line number
Diff line change
@@ -1115,6 +1115,202 @@ of these events.
1115
1115
1116
1116
.. autofunction:: reconstructor
1117
1117
1118
+
1119
+
.. _mapper_version_counter:
1120
+
1121
+
Configuring a Version Counter
1122
+
=============================
1123
+
1124
+
The :class:`.Mapper` supports management of a :term:`version id column`, which
1125
+
is a single table column that increments or otherwise updates its value
1126
+
each time an ``UPDATE`` to the mapped table occurs. This value is checked each
1127
+
time the ORM emits an ``UPDATE`` or ``DELETE`` against the row to ensure that
1128
+
the value held in memory matches the database value.
1129
+
1130
+
The purpose of this feature is to detect when two concurrent transactions
1131
+
are modifying the same row at roughly the same time, or alternatively to provide
1132
+
a guard against the usage of a "stale" row in a system that might be re-using
1133
+
data from a previous transaction without refreshing (e.g. if one sets ``expire_on_commit=False``
1134
+
with a :class:`.Session`, it is possible to re-use the data from a previous
1135
+
transaction).
1136
+
1137
+
.. topic:: Concurrent transaction updates
1138
+
1139
+
When detecting concurrent updates within transactions, it is typically the
1140
+
case that the database's transaction isolation level is below the level of
1141
+
:term:`repeatable read`; otherwise, the transaction will not be exposed
1142
+
to a new row value created by a concurrent update which conflicts with
1143
+
the locally updated value. In this case, the SQLAlchemy versioning
1144
+
feature will typically not be useful for in-transaction conflict detection,
1145
+
though it still can be used for cross-transaction staleness detection.
1146
+
1147
+
The database that enforces repeatable reads will typically either have locked the
1148
+
target row against a concurrent update, or is employing some form
1149
+
of multi version concurrency control such that it will emit an error
1150
+
when the transaction is committed. SQLAlchemy's version_id_col is an alternative
1151
+
which allows version tracking to occur for specific tables within a transaction
1152
+
that otherwise might not have this isolation level set.
1153
+
1154
+
.. seealso::
1155
+
1156
+
`Repeatable Read Isolation Level <http://www.postgresql.org/docs/9.1/static/transaction-iso.html#XACT-REPEATABLE-READ>`_ - Postgresql's implementation of repeatable read, including a description of the error condition.
1157
+
1158
+
Simple Version Counting
1159
+
-----------------------
1160
+
1161
+
The most straightforward way to track versions is to add an integer column
1162
+
to the mapped table, then establish it as the ``version_id_col`` within the
1163
+
mapper options::
1164
+
1165
+
class User(Base):
1166
+
__tablename__ = 'user'
1167
+
1168
+
id = Column(Integer, primary_key=True)
1169
+
version_id = Column(Integer, nullable=False)
1170
+
name = Column(String(50), nullable=False)
1171
+
1172
+
__mapper_args__ = {
1173
+
"version_id_col": version_id
1174
+
}
1175
+
1176
+
Above, the ``User`` mapping tracks integer versions using the column
1177
+
``version_id``. When an object of type ``User`` is first flushed, the
1178
+
``version_id`` column will be given a value of "1". Then, an UPDATE
1179
+
of the table later on will always be emitted in a manner similar to the
1180
+
following::
1181
+
1182
+
UPDATE user SET version_id=:version_id, name=:name
1183
+
WHERE user.id = :user_id AND user.version_id = :user_version_id
1184
+
{"name": "new name", "version_id": 2, "user_id": 1, "user_version_id": 1}
1185
+
1186
+
The above UPDATE statement is updating the row that not only matches
1187
+
``user.id = 1``, it also is requiring that ``user.version_id = 1``, where "1"
1188
+
is the last version identifier we've been known to use on this object.
1189
+
If a transaction elsewhere has modifed the row independently, this version id
1190
+
will no longer match, and the UPDATE statement will report that no rows matched;
1191
+
this is the condition that SQLAlchemy tests, that exactly one row matched our
1192
+
UPDATE (or DELETE) statement. If zero rows match, that indicates our version
1193
+
of the data is stale, and a :class:`.StaleDataError` is raised.
1194
+
1195
+
.. _custom_version_counter:
1196
+
1197
+
Custom Version Counters / Types
1198
+
-------------------------------
1199
+
1200
+
Other kinds of values or counters can be used for versioning. Common types include
1201
+
dates and GUIDs. When using an alternate type or counter scheme, SQLAlchemy
1202
+
provides a hook for this scheme using the ``version_id_generator`` argument,
1203
+
which accepts a version generation callable. This callable is passed the value of the current
1204
+
known version, and is expected to return the subsequent version.
1205
+
1206
+
For example, if we wanted to track the versioning of our ``User`` class
1207
+
using a randomly generated GUID, we could do this (note that some backends
1208
+
support a native GUID type, but we illustrate here using a simple string)::
The persistence engine will call upon ``uuid.uuid4()`` each time a
1225
+
``User`` object is subject to an INSERT or an UPDATE. In this case, our
1226
+
version generation function can disregard the incoming value of ``version``,
1227
+
as the ``uuid4()`` function
1228
+
generates identifiers without any prerequisite value. If we were using
1229
+
a sequential versioning scheme such as numeric or a special character system,
1230
+
we could make use of the given ``version`` in order to help determine the
1231
+
subsequent value.
1232
+
1233
+
.. seealso::
1234
+
1235
+
:ref:`custom_guid_type`
1236
+
1237
+
.. _server_side_version_counter:
1238
+
1239
+
Server Side Version Counters
1240
+
-----------------------------
1241
+
1242
+
The ``version_id_generator`` can also be configured to rely upon a value
1243
+
that is generated by the database. In this case, the database would need
1244
+
some means of generating new identifiers when a row is subject to an INSERT
1245
+
as well as with an UPDATE. For the UPDATE case, typically an update trigger
1246
+
is needed, unless the database in question supports some other native
1247
+
version identifier. The Postgresql database in particular supports a system
1248
+
column called `xmin <http://www.postgresql.org/docs/9.1/static/ddl-system-columns.html>`_
1249
+
which provides UPDATE versioning. We can make use
1250
+
of the Postgresql ``xmin`` column to version our ``User``
1251
+
class as follows::
1252
+
1253
+
class User(Base):
1254
+
__tablename__ = 'user'
1255
+
1256
+
id = Column(Integer, primary_key=True)
1257
+
name = Column(String(50), nullable=False)
1258
+
xmin = Column("xmin", Integer, system=True)
1259
+
1260
+
__mapper_args__ = {
1261
+
'version_id_col': xmin,
1262
+
'version_id_generator': False
1263
+
}
1264
+
1265
+
With the above mapping, the ORM will rely upon the ``xmin`` column for
1266
+
automatically providing the new value of the version id counter.
1267
+
1268
+
.. topic:: creating tables that refer to system columns
1269
+
1270
+
In the above scenario, as ``xmin`` is a system column provided by Postgresql,
1271
+
we use the ``system=True`` argument to mark it as a system-provided
1272
+
column, omitted from the ``CREATE TABLE`` statement.
1273
+
1274
+
1275
+
The ORM typically does not actively fetch the values of database-generated
1276
+
values when it emits an INSERT or UPDATE, instead leaving these columns as
1277
+
"expired" and to be fetched when they are next accessed. However, when a
1278
+
server side version column is used, the ORM needs to actively fetch the newly
1279
+
generated value. This is so that the version counter is set up *before*
1280
+
any concurrent transaction may update it again. This fetching is also
1281
+
best done simultaneously within the INSERT or UPDATE statement using :term:`RETURNING`,
1282
+
otherwise if emitting a SELECT statement afterwards, there is still a potential
1283
+
race condition where the version counter may change before it can be fetched.
1284
+
1285
+
When the target database supports RETURNING, an INSERT statement for our ``User`` class will look
1286
+
like this::
1287
+
1288
+
INSERT INTO "user" (name) VALUES (%(name)s) RETURNING "user".id, "user".xmin
1289
+
{'name': 'ed'}
1290
+
1291
+
Where above, the ORM can acquire any newly generated primary key values along
1292
+
with server-generated version identifiers in one statement. When the backend
1293
+
does not support RETURNING, an additional SELECT must be emitted for **every**
1294
+
INSERT, which is much less efficient, and also introduces the possibility of
1295
+
missed version counters::
1296
+
1297
+
INSERT INTO "user" (name) VALUES (%(name)s) RETURNING "user".id, "user".version_id
1298
+
{'name': 'ed'}
1299
+
1300
+
SELECT "user".version_id AS user_version_id FROM "user" where
1301
+
"user".id = :param_1
1302
+
{"param_1": 1}
1303
+
1304
+
It is *strongly recommended* that server side version counters only be used
1305
+
when absolutely necessary and only on backends that support :term:`RETURNING`,
1306
+
e.g. Postgresql, Oracle, SQL Server (though SQL Server has
1307
+
`major caveats <http://blogs.msdn.com/b/sqlprogrammability/archive/2008/07/11/update-with-output-clause-triggers-and-sqlmoreresults.aspx>`_ when triggers are used), Firebird.
1308
+
1309
+
.. versionadded:: 0.9.0
1310
+
1311
+
Support for server side version identifier tracking.
0 commit comments