]> git.ipfire.org Git - thirdparty/sqlalchemy/sqlalchemy.git/commitdiff
- The MySQL dialect now renders TIMESTAMP with NULL / NOT NULL in
authorMike Bayer <mike_mp@zzzcomputing.com>
Thu, 5 Feb 2015 21:17:23 +0000 (16:17 -0500)
committerMike Bayer <mike_mp@zzzcomputing.com>
Thu, 5 Feb 2015 21:24:45 +0000 (16:24 -0500)
all cases, so that MySQL 5.6.6 with the
``explicit_defaults_for_timestamp`` flag enabled will
will allow TIMESTAMP to continue to work as expected when
``nullable=False``.  Existing applications are unaffected as
SQLAlchemy has always emitted NULL for a TIMESTAMP column that
is ``nullable=True``.  fixes #3155

doc/build/changelog/changelog_10.rst
doc/build/changelog/migration_10.rst
lib/sqlalchemy/dialects/mysql/base.py
test/dialect/mysql/test_reflection.py
test/dialect/mysql/test_types.py

index 89ef868446341bc00a0a7a62cf1188c83aa6763d..ca0ae4d5260e3b0fc43e057db43a8f25fa2d0511 100644 (file)
@@ -1,4 +1,5 @@
 
+
 ==============
 1.0 Changelog
 ==============
     series as well.  For changes that are specific to 1.0 with an emphasis
     on compatibility concerns, see :doc:`/changelog/migration_10`.
 
+    .. change::
+        :tags: feature, mysql
+        :tickets: 3155
+
+        The MySQL dialect now renders TIMESTAMP with NULL / NOT NULL in
+        all cases, so that MySQL 5.6.6 with the
+        ``explicit_defaults_for_timestamp`` flag enabled will
+        will allow TIMESTAMP to continue to work as expected when
+        ``nullable=False``.  Existing applications are unaffected as
+        SQLAlchemy has always emitted NULL for a TIMESTAMP column that
+        is ``nullable=True``.
+
+        .. seealso::
+
+            :ref:`change_3155`
+
+            :ref:`mysql_timestamp_null`
+
     .. change::
         :tags: bug, schema
         :tickets: 3299, 3067
index 3ba0743f78fa567854e5f5ec651d1a81f6952ca5..efb4b26e59cad0cf26cc1771d1aac2ca52eea322 100644 (file)
@@ -1817,6 +1817,29 @@ Support for the pypy psycopg2cffi dialect is added.
 Dialect Improvements and Changes - MySQL
 =============================================
 
+.. _change_3155:
+
+MySQL TIMESTAMP Type now renders NULL / NOT NULL in all cases
+--------------------------------------------------------------
+
+The MySQL dialect has always worked around MySQL's implicit NOT NULL
+default associated with TIMESTAMP columns by emitting NULL for
+such a type, if the column is set up with ``nullable=True``.   However,
+MySQL 5.6.6 and above features a new flag
+`explicit_defaults_for_timestamp <http://dev.mysql.com/doc/refman/
+5.6/en/server-system-variables.html
+#sysvar_explicit_defaults_for_timestamp>`_ which repairs MySQL's non-standard
+behavior to make it behave like any other type; to accommodate this,
+SQLAlchemy now emits NULL/NOT NULL unconditionally for all TIMESTAMP
+columns.
+
+.. seealso::
+
+    :ref:`mysql_timestamp_null`
+
+:ticket:`3155`
+
+
 .. _change_3283:
 
 MySQL SET Type Overhauled to support empty sets, unicode, blank value handling
index c8e33bfb2895306afa4a60fe5652209dda18cccc..cbb108f5e4be1b889407f3be430a729972698274 100644 (file)
@@ -370,10 +370,11 @@ collection.
 TIMESTAMP Columns and NULL
 --------------------------
 
-MySQL enforces that a column which specifies the TIMESTAMP datatype implicitly
-includes a default value of CURRENT_TIMESTAMP, even though this is not
-stated, and additionally sets the column as NOT NULL, the opposite behavior
-vs. that of all other datatypes::
+MySQL historically enforces that a column which specifies the
+TIMESTAMP datatype implicitly includes a default value of
+CURRENT_TIMESTAMP, even though this is not stated, and additionally
+sets the column as NOT NULL, the opposite behavior vs. that of all
+other datatypes::
 
     mysql> CREATE TABLE ts_test (
         -> a INTEGER,
@@ -400,22 +401,29 @@ with NOT NULL.   But when the column is of type TIMESTAMP, an implicit
 default of CURRENT_TIMESTAMP is generated which also coerces the column
 to be a NOT NULL, even though we did not specify it as such.
 
-Therefore, the usual "NOT NULL" clause *does not apply* to a TIMESTAMP
-column; MySQL selects this implicitly.   SQLAlchemy therefore does not render
-NOT NULL for a TIMESTAMP column on MySQL.   However, it *does* render
-NULL when we specify nullable=True, or if we leave nullable absent, as it
-also defaults to True.  This is to accommodate the essentially
-reverse behavior of the NULL flag for TIMESTAMP::
+This behavior of MySQL can be changed on the MySQL side using the
+`explicit_defaults_for_timestamp
+<http://dev.mysql.com/doc/refman/5.6/en/server-system-variables.html
+#sysvar_explicit_defaults_for_timestamp>`_ configuration flag introduced in
+MySQL 5.6.  With this server setting enabled, TIMESTAMP columns behave like
+any other datatype on the MySQL side with regards to defaults and nullability.
 
-    from sqlalchemy import MetaData, TIMESTAMP, Integer, Table, Column, text
+However, to accommodate the vast majority of MySQL databases that do not
+specify this new flag, SQLAlchemy emits the "NULL" specifier explicitly with
+any TIMESTAMP column that does not specify ``nullable=False``.   In order
+to accommodate newer databases that specify ``explicit_defaults_for_timestamp``,
+SQLAlchemy also emits NOT NULL for TIMESTAMP columns that do specify
+``nullable=False``.   The following example illustrates::
+
+    from sqlalchemy import MetaData, Integer, Table, Column, text
+    from sqlalchemy.dialects.mysql import TIMESTAMP
 
     m = MetaData()
     t = Table('ts_test', m,
             Column('a', Integer),
             Column('b', Integer, nullable=False),
             Column('c', TIMESTAMP),
-            Column('d', TIMESTAMP, nullable=False),
-            Column('e', TIMESTAMP, nullable=True)
+            Column('d', TIMESTAMP, nullable=False)
         )
 
 
@@ -423,35 +431,19 @@ reverse behavior of the NULL flag for TIMESTAMP::
     e = create_engine("mysql://scott:tiger@localhost/test", echo=True)
     m.create_all(e)
 
-In the output, we can see that the TIMESTAMP column receives a different
-treatment for NULL / NOT NULL vs. that of the INTEGER::
+output::
 
     CREATE TABLE ts_test (
         a INTEGER,
         b INTEGER NOT NULL,
         c TIMESTAMP NULL,
-        d TIMESTAMP,
-        e TIMESTAMP NULL
+        d TIMESTAMP NOT NULL
     )
 
-MySQL above receives the NULL/NOT NULL constraint as is stated in our
-original :class:`.Table`::
-
-    mysql> SHOW CREATE TABLE ts_test;
-    +---------+---------------------------
-    | Table   | Create Table
-    +---------+---------------------------
-    | ts_test | CREATE TABLE `ts_test` (
-      `a` int(11) DEFAULT NULL,
-      `b` int(11) NOT NULL,
-      `c` timestamp NULL DEFAULT NULL,
-      `d` timestamp NOT NULL DEFAULT '0000-00-00 00:00:00',
-      `e` timestamp NULL DEFAULT NULL
-    ) ENGINE=MyISAM DEFAULT CHARSET=latin1
-
-Be sure to always favor the ``SHOW CREATE TABLE`` output over the
-SQLAlchemy-emitted DDL when checking table definitions, as MySQL's
-rules can be hard to predict.
+.. versionchanged:: 1.0.0 - SQLAlchemy now renders NULL or NOT NULL in all
+   cases for TIMESTAMP columns, to accommodate
+   ``explicit_defaults_for_timestamp``.  Prior to this version, it will
+   not render "NOT NULL" for a TIMESTAMP column that is ``nullable=False``.
 
 """
 
@@ -1865,19 +1857,20 @@ class MySQLDDLCompiler(compiler.DDLCompiler):
                 column.type, type_expression=column)
         ]
 
-        default = self.get_column_default_string(column)
-        if default is not None:
-            colspec.append('DEFAULT ' + default)
-
         is_timestamp = isinstance(column.type, sqltypes.TIMESTAMP)
-        if not column.nullable and not is_timestamp:
+
+        if not column.nullable:
             colspec.append('NOT NULL')
 
         # see: http://docs.sqlalchemy.org/en/latest/dialects/
         #   mysql.html#mysql_timestamp_null
-        elif column.nullable and is_timestamp and default is None:
+        elif column.nullable and is_timestamp:
             colspec.append('NULL')
 
+        default = self.get_column_default_string(column)
+        if default is not None:
+            colspec.append('DEFAULT ' + default)
+
         if column is column.table._autoincrement_column and \
                 column.server_default is None:
             colspec.append('AUTO_INCREMENT')
@@ -3007,8 +3000,7 @@ class MySQLTableDefinitionParser(object):
         if not spec['full']:
             util.warn("Incomplete reflection of column definition %r" % line)
 
-        name, type_, args, notnull = \
-            spec['name'], spec['coltype'], spec['arg'], spec['notnull']
+        name, type_, args = spec['name'], spec['coltype'], spec['arg']
 
         try:
             col_type = self.dialect.ischema_names[type_]
@@ -3033,7 +3025,6 @@ class MySQLTableDefinitionParser(object):
         for kw in ('charset', 'collate'):
             if spec.get(kw, False):
                 type_kw[kw] = spec[kw]
-
         if issubclass(col_type, _EnumeratedValues):
             type_args = _EnumeratedValues._strip_values(type_args)
 
@@ -3042,11 +3033,12 @@ class MySQLTableDefinitionParser(object):
 
         type_instance = col_type(*type_args, **type_kw)
 
-        col_args, col_kw = [], {}
+        col_kw = {}
 
         # NOT NULL
         col_kw['nullable'] = True
-        if spec.get('notnull', False):
+        # this can be "NULL" in the case of TIMESTAMP
+        if spec.get('notnull', False) == 'NOT NULL':
             col_kw['nullable'] = False
 
         # AUTO_INCREMENT
@@ -3165,7 +3157,7 @@ class MySQLTableDefinitionParser(object):
             r'(?: +(?P<zerofill>ZEROFILL))?'
             r'(?: +CHARACTER SET +(?P<charset>[\w_]+))?'
             r'(?: +COLLATE +(?P<collate>[\w_]+))?'
-            r'(?: +(?P<notnull>NOT NULL))?'
+            r'(?: +(?P<notnull>(?:NOT )?NULL))?'
             r'(?: +DEFAULT +(?P<default>'
             r'(?:NULL|\x27(?:\x27\x27|[^\x27])*\x27|\w+'
             r'(?: +ON UPDATE \w+)?)'
@@ -3185,7 +3177,7 @@ class MySQLTableDefinitionParser(object):
             r'%(iq)s(?P<name>(?:%(esc_fq)s|[^%(fq)s])+)%(fq)s +'
             r'(?P<coltype>\w+)'
             r'(?:\((?P<arg>(?:\d+|\d+,\d+|\x27(?:\x27\x27|[^\x27])+\x27))\))?'
-            r'.*?(?P<notnull>NOT NULL)?'
+            r'.*?(?P<notnull>(?:NOT )NULL)?'
             % quotes
         )
 
index 99733e39774448e4f0244a18331e6aa84ec03215..957a7eb21a472a9b93b4c27247e006d26e26153d 100644 (file)
@@ -7,6 +7,7 @@ from sqlalchemy.dialects.mysql import base as mysql
 from sqlalchemy.testing import fixtures, AssertsExecutionResults
 from sqlalchemy import testing
 
+
 class ReflectionTest(fixtures.TestBase, AssertsExecutionResults):
 
     __only_on__ = 'mysql'
@@ -23,13 +24,12 @@ class ReflectionTest(fixtures.TestBase, AssertsExecutionResults):
                    DefaultClause(''), nullable=False),
             Column('c2', String(10), DefaultClause('0')),
             Column('c3', String(10), DefaultClause('abc')),
-            Column('c4', TIMESTAMP, DefaultClause('2009-04-05 12:00:00'
-                   )),
+            Column('c4', TIMESTAMP, DefaultClause('2009-04-05 12:00:00')),
             Column('c5', TIMESTAMP),
             Column('c6', TIMESTAMP,
                    DefaultClause(sql.text("CURRENT_TIMESTAMP "
                                           "ON UPDATE CURRENT_TIMESTAMP"))),
-            )
+        )
         def_table.create()
         try:
             reflected = Table('mysql_def', MetaData(testing.db),
@@ -283,6 +283,55 @@ class ReflectionTest(fixtures.TestBase, AssertsExecutionResults):
         view_names = dialect.get_view_names(connection, "information_schema")
         self.assert_('TABLES' in view_names)
 
+    @testing.provide_metadata
+    def test_nullable_reflection(self):
+        """test reflection of NULL/NOT NULL, in particular with TIMESTAMP
+        defaults where MySQL is inconsistent in how it reports CREATE TABLE.
+
+        """
+        meta = self.metadata
+        Table('nn_t', meta)
+        testing.db.execute("""
+            CREATE TABLE nn_t (
+                x INTEGER NULL,
+                y INTEGER NOT NULL,
+                z INTEGER,
+                q TIMESTAMP NULL,
+                p TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP,
+                r TIMESTAMP NOT NULL,
+                s TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
+                t TIMESTAMP,
+                u TIMESTAMP DEFAULT CURRENT_TIMESTAMP
+            )
+        """)
+        eq_(
+            [
+                {
+                    "name": d['name'],
+                    "nullable": d['nullable'],
+                    "default": d['default'],
+                }
+                for d in
+                inspect(testing.db).get_columns('nn_t')
+            ],
+            [
+                {'name': 'x', 'nullable': True, 'default': None},
+                {'name': 'y', 'nullable': False, 'default': None},
+                {'name': 'z', 'nullable': True, 'default': None},
+                {'name': 'q', 'nullable': True, 'default': None},
+                {'name': 'p', 'nullable': True,
+                 'default': 'CURRENT_TIMESTAMP'},
+                {'name': 'r', 'nullable': False,
+                 'default': "'0000-00-00 00:00:00'"},
+                {'name': 's', 'nullable': False,
+                 'default': 'CURRENT_TIMESTAMP'},
+                {'name': 't', 'nullable': False,
+                 'default': "'0000-00-00 00:00:00'"},
+                {'name': 'u', 'nullable': False,
+                 'default': 'CURRENT_TIMESTAMP'},
+            ]
+        )
+
     @testing.provide_metadata
     def test_reflection_with_unique_constraint(self):
         insp = inspect(testing.db)
index 13425dc106d38f4da90d75232dacfd8077dd3e13..7c279ffbf664cb9dbfb134c9bcb2727a3424ecc6 100644 (file)
@@ -11,6 +11,7 @@ from sqlalchemy import testing
 import datetime
 import decimal
 
+
 class TypesTest(fixtures.TestBase, AssertsExecutionResults, AssertsCompiledSQL):
     "Test MySQL column types"
 
@@ -416,29 +417,66 @@ class TypesTest(fixtures.TestBase, AssertsExecutionResults, AssertsCompiledSQL):
         """Exercise funky TIMESTAMP default syntax when used in columns."""
 
         columns = [
-            ([TIMESTAMP],
+            ([TIMESTAMP], {},
              'TIMESTAMP NULL'),
-            ([mysql.MSTimeStamp],
+
+            ([mysql.MSTimeStamp], {},
              'TIMESTAMP NULL'),
+
+            ([mysql.MSTimeStamp(),
+              DefaultClause(sql.text('CURRENT_TIMESTAMP'))],
+             {},
+             "TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP"),
+
             ([mysql.MSTimeStamp,
               DefaultClause(sql.text('CURRENT_TIMESTAMP'))],
-             "TIMESTAMP DEFAULT CURRENT_TIMESTAMP"),
+             {'nullable': False},
+             "TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP"),
+
             ([mysql.MSTimeStamp,
               DefaultClause(sql.text("'1999-09-09 09:09:09'"))],
-             "TIMESTAMP DEFAULT '1999-09-09 09:09:09'"),
+             {'nullable': False},
+             "TIMESTAMP NOT NULL DEFAULT '1999-09-09 09:09:09'"),
+
+            ([mysql.MSTimeStamp(),
+              DefaultClause(sql.text("'1999-09-09 09:09:09'"))],
+             {},
+             "TIMESTAMP NULL DEFAULT '1999-09-09 09:09:09'"),
+
+            ([mysql.MSTimeStamp(),
+              DefaultClause(sql.text(
+                  "'1999-09-09 09:09:09' "
+                  "ON UPDATE CURRENT_TIMESTAMP"))],
+             {},
+             "TIMESTAMP NULL DEFAULT '1999-09-09 09:09:09' "
+             "ON UPDATE CURRENT_TIMESTAMP"),
+
             ([mysql.MSTimeStamp,
-              DefaultClause(sql.text("'1999-09-09 09:09:09' "
-                                      "ON UPDATE CURRENT_TIMESTAMP"))],
-             "TIMESTAMP DEFAULT '1999-09-09 09:09:09' "
+              DefaultClause(sql.text(
+                  "'1999-09-09 09:09:09' "
+                  "ON UPDATE CURRENT_TIMESTAMP"))],
+             {'nullable': False},
+             "TIMESTAMP NOT NULL DEFAULT '1999-09-09 09:09:09' "
+             "ON UPDATE CURRENT_TIMESTAMP"),
+
+            ([mysql.MSTimeStamp(),
+              DefaultClause(sql.text(
+                  "CURRENT_TIMESTAMP "
+                  "ON UPDATE CURRENT_TIMESTAMP"))],
+             {},
+             "TIMESTAMP NULL DEFAULT CURRENT_TIMESTAMP "
              "ON UPDATE CURRENT_TIMESTAMP"),
+
             ([mysql.MSTimeStamp,
-              DefaultClause(sql.text("CURRENT_TIMESTAMP "
-                                      "ON UPDATE CURRENT_TIMESTAMP"))],
-             "TIMESTAMP DEFAULT CURRENT_TIMESTAMP "
+              DefaultClause(sql.text(
+                  "CURRENT_TIMESTAMP "
+                  "ON UPDATE CURRENT_TIMESTAMP"))],
+             {'nullable': False},
+             "TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP "
              "ON UPDATE CURRENT_TIMESTAMP"),
-            ]
-        for spec, expected in columns:
-            c = Column('t', *spec)
+        ]
+        for spec, kw, expected in columns:
+            c = Column('t', *spec, **kw)
             Table('t', MetaData(), c)
             self.assert_compile(
                 schema.CreateColumn(c),
@@ -448,19 +486,20 @@ class TypesTest(fixtures.TestBase, AssertsExecutionResults, AssertsCompiledSQL):
 
     @testing.provide_metadata
     def test_timestamp_nullable(self):
-        ts_table = Table('mysql_timestamp', self.metadata,
-                            Column('t1', TIMESTAMP),
-                            Column('t2', TIMESTAMP, nullable=False),
-                    )
+        ts_table = Table(
+            'mysql_timestamp', self.metadata,
+            Column('t1', TIMESTAMP),
+            Column('t2', TIMESTAMP, nullable=False),
+            mysql_engine='InnoDB'
+        )
         self.metadata.create_all()
 
-        now = testing.db.execute("select now()").scalar()
-
         # TIMESTAMP without NULL inserts current time when passed
         # NULL.  when not passed, generates 0000-00-00 quite
         # annoyingly.
-        ts_table.insert().execute({'t1': now, 't2': None})
-        ts_table.insert().execute({'t1': None, 't2': None})
+        # the flag http://dev.mysql.com/doc/refman/5.6/en/\
+        # server-system-variables.html#sysvar_explicit_defaults_for_timestamp
+        # changes this for 5.6 if set.
 
         # normalize dates that are over the second boundary
         def normalize(dt):
@@ -470,11 +509,27 @@ class TypesTest(fixtures.TestBase, AssertsExecutionResults, AssertsCompiledSQL):
                 return now
             else:
                 return dt
-        eq_(
-            [tuple([normalize(dt) for dt in row])
-            for row in ts_table.select().execute()],
-            [(now, now), (None, now)]
-        )
+
+        with testing.db.begin() as conn:
+            now = conn.scalar("select now()")
+
+            conn.execute(
+                ts_table.insert(), {'t1': now, 't2': None})
+            conn.execute(
+                ts_table.insert(), {'t1': None, 't2': None})
+            conn.execute(
+                ts_table.insert(), {'t2': None})
+
+            eq_(
+                [tuple([normalize(dt) for dt in row])
+                 for row in conn.execute(ts_table.select())],
+                [
+                    (now, now),
+                    (None, now),
+                    (None, now)
+                ]
+            )
+
 
     def test_datetime_generic(self):
         self.assert_compile(