Case 4: primary key, RETURNING or equivalent is not supported
--------------------------------------------------------------
-In this area we are generating rows for a database such as SQLite or
-more typically MySQL where some means of generating a default is occurring
-on the server, but is outside of the database's usual autoincrement routine.
-In this case, we have to make sure SQLAlchemy can "pre-execute" the default,
-which means it has to be an explicit SQL expression. Again using the example
-of TIMESTAMP for MySQL, we unfortunately need to use our own explicit default::
+In this area we are generating rows for a database such as SQLite or MySQL
+where some means of generating a default is occurring on the server, but is
+outside of the database's usual autoincrement routine. In this case, we have to
+make sure SQLAlchemy can "pre-execute" the default, which means it has to be an
+explicit SQL expression.
+
+.. note:: This section will will illustrate multiple recipes involving
+ datetime values for MySQL and SQLite, since the datetime datatypes on these
+ two backends have additional idiosyncratic requirements that are useful to
+ illustrate. Keep in mind however that SQLite and MySQL require an explicit
+ "pre-executed" default generator for *any* auto-generated datatype used as
+ the primary key other than the usual single-column autoincrementing integer
+ value.
+
+MySQL with DateTime primary key
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+Using the example of a :class:`.DateTime` column for MySQL, we add an explicit
+pre-execute-supported default using the "NOW()" SQL function::
class MyModel(Base):
__tablename__ = 'my_table'
- timestamp = Column(TIMESTAMP(), default=func.cast(func.now(), Binary), primary_key=True)
+ timestamp = Column(DateTime(), default=func.now(), primary_key=True)
-Where above, we select the "NOW()" function and also cast to binary to
-be used with MySQL's TIMESTAMP column, that is in fact a binary datatype.
-The SQL generated by the above is:
+Where above, we select the "NOW()" function to deliver a datetime value
+to the column. The SQL generated by the above is:
+
+.. sourcecode:: sql
+
+ SELECT now() AS anon_1
+ INSERT INTO my_table (timestamp) VALUES (%s)
+ ('2018-08-09 13:08:46',)
+
+MySQL with TIMESTAMP primary key
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+When using the :class:`.TIMESTAMP` datatype with MySQL, MySQL ordinarily
+associates a server-side default with this datatype automatically. However
+when we use one as a primary key, the Core cannot retrieve the newly generated
+value unless we execute the function ourselves. As :class:`.TIMESTAMP` on
+MySQL actually stores a binary value, we need to add an additional "CAST" to our
+usage of "NOW()" so that we retrieve a binary value that can be persisted
+into the column::
+
+ from sqlalchemy import cast, Binary
+
+ class MyModel(Base):
+ __tablename__ = 'my_table'
+
+ timestamp = Column(
+ TIMESTAMP(),
+ default=cast(func.now(), Binary),
+ primary_key=True)
+
+Above, in addition to selecting the "NOW()" function, we additionally make
+use of the :class:`.Binary` datatype in conjunction with :func:`.cast` so that
+the returned value is binary. SQL rendered from the above within an
+INSERT looks like:
.. sourcecode:: sql
INSERT INTO my_table (timestamp) VALUES (%s)
(b'2018-08-09 13:08:46',)
-The Core currently does not support a means of fetching the timestamp value
-after the fact without using RETURNING, so on MySQL must run a SELECT ahead of
-time to pre-select the value.
+SQLite with DateTime primary key
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+For SQLite, new timestamps can be generated using the SQL function
+``datetime('now', 'localtime')`` (or specify ``'utc'`` for UTC),
+however making things more complicated is that this returns a string
+value, which is then incompatible with SQLAlchemy's :class:`.DateTime`
+datatype (even though the datatype converts the information back into a
+string for the SQLite backend, it must be passed through as a Python datetime).
+We therefore must also specify that we'd like to coerce the return value to
+:class:`.DateTime` when it is returned from the function, which we achieve
+by passing this as the ``type_`` parameter::
+
+ class MyModel(Base):
+ __tablename__ = 'my_table'
+
+ timestamp = Column(
+ DateTime,
+ default=func.datetime('now', 'localtime', type_=DateTime),
+ primary_key=True)
+
+The above mapping upon INSERT will look like:
+
+.. sourcecode:: sql
+
+ SELECT datetime(?, ?) AS datetime_1
+ ('now', 'localtime')
+ INSERT INTO my_table (timestamp) VALUES (?)
+ ('2018-10-02 13:37:33.000000',)
+
.. seealso::