From: Mike Bayer Date: Mon, 2 Oct 2017 19:52:46 +0000 (-0400) Subject: Add SQL Server TIMESTAMP / ROWVERSION datatypes X-Git-Tag: rel_1_2_0~64^2 X-Git-Url: http://git.ipfire.org/gitweb.cgi?a=commitdiff_plain;h=fadebedff0049fee9575632f57561143aa8a801e;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git Add SQL Server TIMESTAMP / ROWVERSION datatypes SQL Server has an entirely different use for the TIMESTAMP datatype that is unrelated to the SQL standard's version of this type. It is a read-only type that returns an incrementing binary value. The ROWVERSION name will supersede the TIMESTAMP name. Implement datatype objects for both, separate from the base DateTime/TIMESTAMP class hierarchy, and also implement an optional integer coercion feature. Change-Id: Ie2bd43b7aac57760b8ec6ff6e26460e2086a95eb Fixes: #4086 --- diff --git a/doc/build/changelog/unreleased_12/4086.rst b/doc/build/changelog/unreleased_12/4086.rst new file mode 100644 index 0000000000..ee1e66f63c --- /dev/null +++ b/doc/build/changelog/unreleased_12/4086.rst @@ -0,0 +1,10 @@ +.. change:: + :tags: feature, mssql + :tickets: 4086 + + Added a new :class:`.mssql.TIMESTAMP` datatype, that + correctly acts like a binary datatype for SQL Server + rather than a datetime type, as SQL Server breaks the + SQL standard here. Also added :class:`.mssql.ROWVERSION`, + as the "TIMESTAMP" type in SQL Server is deprecated in + favor of ROWVERSION. diff --git a/doc/build/dialects/mssql.rst b/doc/build/dialects/mssql.rst index acc9710e52..6244412292 100644 --- a/doc/build/dialects/mssql.rst +++ b/doc/build/dialects/mssql.rst @@ -63,6 +63,8 @@ construction arguments, are as follows: .. autoclass:: REAL :members: __init__ +.. autoclass:: ROWVERSION + :members: __init__ .. autoclass:: SMALLDATETIME :members: __init__ @@ -84,6 +86,9 @@ construction arguments, are as follows: :members: __init__ +.. autoclass:: TIMESTAMP + :members: __init__ + .. autoclass:: TINYINT :members: __init__ diff --git a/lib/sqlalchemy/dialects/mssql/__init__.py b/lib/sqlalchemy/dialects/mssql/__init__.py index 6b70df3a85..7cd5c32bc9 100644 --- a/lib/sqlalchemy/dialects/mssql/__init__.py +++ b/lib/sqlalchemy/dialects/mssql/__init__.py @@ -14,7 +14,7 @@ from sqlalchemy.dialects.mssql.base import \ INTEGER, BIGINT, SMALLINT, TINYINT, VARCHAR, NVARCHAR, CHAR, \ NCHAR, TEXT, NTEXT, DECIMAL, NUMERIC, FLOAT, DATETIME,\ DATETIME2, DATETIMEOFFSET, DATE, TIME, SMALLDATETIME, \ - BINARY, VARBINARY, BIT, REAL, IMAGE, TIMESTAMP,\ + BINARY, VARBINARY, BIT, REAL, IMAGE, TIMESTAMP, ROWVERSION, \ MONEY, SMALLMONEY, UNIQUEIDENTIFIER, SQL_VARIANT, dialect @@ -22,6 +22,6 @@ __all__ = ( 'INTEGER', 'BIGINT', 'SMALLINT', 'TINYINT', 'VARCHAR', 'NVARCHAR', 'CHAR', 'NCHAR', 'TEXT', 'NTEXT', 'DECIMAL', 'NUMERIC', 'FLOAT', 'DATETIME', 'DATETIME2', 'DATETIMEOFFSET', 'DATE', 'TIME', 'SMALLDATETIME', - 'BINARY', 'VARBINARY', 'BIT', 'REAL', 'IMAGE', 'TIMESTAMP', + 'BINARY', 'VARBINARY', 'BIT', 'REAL', 'IMAGE', 'TIMESTAMP', 'ROWVERSION', 'MONEY', 'SMALLMONEY', 'UNIQUEIDENTIFIER', 'SQL_VARIANT', 'dialect' ) diff --git a/lib/sqlalchemy/dialects/mssql/base.py b/lib/sqlalchemy/dialects/mssql/base.py index 5f936fd765..a7c5286e08 100644 --- a/lib/sqlalchemy/dialects/mssql/base.py +++ b/lib/sqlalchemy/dialects/mssql/base.py @@ -607,6 +607,7 @@ http://msdn.microsoft.com/en-us/library/ms175095.aspx. """ +import codecs import datetime import operator import re @@ -617,7 +618,7 @@ from ... import engine from ...engine import reflection, default from ... import types as sqltypes from ...types import INTEGER, BIGINT, SMALLINT, DECIMAL, NUMERIC, \ - FLOAT, TIMESTAMP, DATETIME, DATE, BINARY,\ + FLOAT, DATETIME, DATE, BINARY,\ TEXT, VARCHAR, NVARCHAR, CHAR, NCHAR @@ -793,6 +794,75 @@ class _StringType(object): super(_StringType, self).__init__(collation=collation) +class TIMESTAMP(sqltypes._Binary): + """Implement the SQL Server TIMESTAMP type. + + Note this is **completely different** than the SQL Standard + TIMESTAMP type, which is not supported by SQL Server. It + is a read-only datatype that does not support INSERT of values. + + .. versionadded:: 1.2 + + .. seealso:: + + :class:`.mssql.ROWVERSION` + + """ + + __visit_name__ = 'TIMESTAMP' + + # expected by _Binary to be present + length = None + + def __init__(self, convert_int=False): + """Construct a TIMESTAMP or ROWVERSION type. + + :param convert_int: if True, binary integer values will + be converted to integers on read. + + .. versionadded:: 1.2 + + """ + self.convert_int = convert_int + + def result_processor(self, dialect, coltype): + super_ = super(TIMESTAMP, self).result_processor(dialect, coltype) + if self.convert_int: + def process(value): + value = super_(value) + if value is not None: + # https://stackoverflow.com/a/30403242/34549 + value = int(codecs.encode(value, 'hex'), 16) + return value + return process + else: + return super_ + + +class ROWVERSION(TIMESTAMP): + """Implement the SQL Server ROWVERSION type. + + The ROWVERSION datatype is a SQL Server synonym for the TIMESTAMP + datatype, however current SQL Server documentation suggests using + ROWVERSION for new datatypes going forward. + + The ROWVERSION datatype does **not** reflect (e.g. introspect) from the + database as itself; the returned datatype will be + :class:`.mssql.TIMESTAMP`. + + This is a read-only datatype that does not support INSERT of values. + + .. versionadded:: 1.2 + + .. seealso:: + + :class:`.mssql.TIMESTAMP` + + """ + + __visit_name__ = 'ROWVERSION' + + class NTEXT(sqltypes.UnicodeText): """MSSQL NTEXT type, for variable-length unicode text up to 2^30 @@ -960,6 +1030,12 @@ class MSTypeCompiler(compiler.GenericTypeCompiler): else: return "TIME" + def visit_TIMESTAMP(self, type_, **kw): + return "TIMESTAMP" + + def visit_ROWVERSION(self, type_, **kw): + return "ROWVERSION" + def visit_DATETIME2(self, type_, **kw): precision = getattr(type_, 'precision', None) if precision is not None: diff --git a/test/dialect/mssql/test_types.py b/test/dialect/mssql/test_types.py index f0402e8fbc..63a2f3bd3c 100644 --- a/test/dialect/mssql/test_types.py +++ b/test/dialect/mssql/test_types.py @@ -4,9 +4,10 @@ from sqlalchemy.testing import is_, is_not_ import datetime import os from sqlalchemy import Table, Column, MetaData, Float, \ - Integer, String, Boolean, TIMESTAMP, Sequence, Numeric, select, \ + Integer, String, Boolean, Sequence, Numeric, select, \ Date, Time, DateTime, DefaultClause, PickleType, text, Text, \ UnicodeText, LargeBinary +from sqlalchemy.dialects.mssql import TIMESTAMP, ROWVERSION from sqlalchemy import types, schema from sqlalchemy import util from sqlalchemy.databases import mssql @@ -18,6 +19,10 @@ from sqlalchemy import testing from sqlalchemy.testing import emits_warning_on import decimal from sqlalchemy.util import b +from sqlalchemy import inspect +from sqlalchemy.sql import sqltypes +import sqlalchemy as sa +import codecs class TimeTypeTest(fixtures.TestBase): @@ -81,6 +86,95 @@ class MSDateTypeTest(fixtures.TestBase): eq_(r, exp) +class RowVersionTest(fixtures.TablesTest): + __only_on__ = 'mssql' + __backend__ = True + + @classmethod + def define_tables(cls, metadata): + Table( + 'rv_t', metadata, + Column('data', String(50)), + Column('rv', ROWVERSION) + ) + + Table( + 'ts_t', metadata, + Column('data', String(50)), + Column('rv', TIMESTAMP) + ) + + def test_rowversion_reflection(self): + # ROWVERSION is only a synonym for TIMESTAMP + insp = inspect(testing.db) + assert isinstance( + insp.get_columns('rv_t')[1]['type'], TIMESTAMP + ) + + def test_timestamp_reflection(self): + insp = inspect(testing.db) + assert isinstance( + insp.get_columns('ts_t')[1]['type'], TIMESTAMP + ) + + def test_class_hierarchy(self): + """TIMESTAMP and ROWVERSION aren't datetime types, theyre binary.""" + + assert issubclass(TIMESTAMP, sqltypes._Binary) + assert issubclass(ROWVERSION, sqltypes._Binary) + + def test_round_trip_ts(self): + self._test_round_trip('ts_t', TIMESTAMP, False) + + def test_round_trip_rv(self): + self._test_round_trip('rv_t', ROWVERSION, False) + + def test_round_trip_ts_int(self): + self._test_round_trip('ts_t', TIMESTAMP, True) + + def test_round_trip_rv_int(self): + self._test_round_trip('rv_t', ROWVERSION, True) + + def _test_round_trip(self, tab, cls, convert_int): + t = Table( + tab, MetaData(), + Column('data', String(50)), + Column('rv', cls(convert_int=convert_int)) + ) + + with testing.db.connect() as conn: + conn.execute(t.insert().values(data='foo')) + last_ts_1 = conn.scalar("SELECT @@DBTS") + + if convert_int: + last_ts_1 = int(codecs.encode(last_ts_1, 'hex'), 16) + + eq_(conn.scalar(select([t.c.rv])), last_ts_1) + + conn.execute( + t.update().values(data='bar').where(t.c.data == 'foo')) + last_ts_2 = conn.scalar("SELECT @@DBTS") + if convert_int: + last_ts_2 = int(codecs.encode(last_ts_2, 'hex'), 16) + + eq_(conn.scalar(select([t.c.rv])), last_ts_2) + + def test_cant_insert_rowvalue(self): + self._test_cant_insert(self.tables.rv_t) + + def test_cant_insert_timestamp(self): + self._test_cant_insert(self.tables.ts_t) + + def _test_cant_insert(self, tab): + with testing.db.connect() as conn: + assert_raises_message( + sa.exc.DBAPIError, + r".*Cannot insert an explicit value into a timestamp column.", + conn.execute, + tab.insert().values(data='ins', rv=b'000') + ) + + class TypeDDLTest(fixtures.TestBase): def test_boolean(self): @@ -343,21 +437,6 @@ class TypeDDLTest(fixtures.TestBase): "IMAGE" ) - def test_timestamp(self): - """Exercise TIMESTAMP column.""" - - dialect = mssql.dialect() - - metadata = MetaData() - spec, expected = (TIMESTAMP, 'TIMESTAMP') - t = Table( - 'mssql_ts', metadata, - Column('id', Integer, primary_key=True), - Column('t', spec, nullable=None)) - gen = dialect.ddl_compiler(dialect, schema.CreateTable(t)) - testing.eq_(gen.get_column_specification(t.c.t), "t %s" % expected) - self.assert_(repr(t.c.t)) - def test_money(self): """Exercise type specification for money types.""" diff --git a/test/engine/test_reflection.py b/test/engine/test_reflection.py index 1bd369610e..724f361473 100644 --- a/test/engine/test_reflection.py +++ b/test/engine/test_reflection.py @@ -1576,7 +1576,6 @@ def createTables(meta, schema=None): Column('test3', sa.Text), Column('test4', sa.Numeric(10, 2), nullable=False), Column('test5', sa.Date), - Column('test5_1', sa.TIMESTAMP), Column('parent_user_id', sa.Integer, sa.ForeignKey('%susers.user_id' % schema_prefix)), Column('test6', sa.Date, nullable=False),