From: Mike Bayer Date: Sun, 11 Nov 2018 02:36:18 +0000 (-0500) Subject: Add new parameters for IDENTITY start/increment in mssql X-Git-Tag: rel_1_3_0b1~10^2 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=6629d9f89273eda53a578cce41af6c79135254c7;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git Add new parameters for IDENTITY start/increment in mssql Deprecated the use of :class:`.Sequence` with SQL Server in order to affect the "start" and "increment" of the IDENTITY value, in favor of new parameters ``mssql_identity_start`` and ``mssql_identity_increment`` which set these parameters directly. :class:`.Sequence` will be used to generate real ``CREATE SEQUENCE`` DDL with SQL Server in a future release. Fixes: #4362 Change-Id: I1e69378c5c960ff0bc28137c923589692f1a918f --- diff --git a/doc/build/changelog/migration_13.rst b/doc/build/changelog/migration_13.rst index 1c3e5b0f72..1f000cc13a 100644 --- a/doc/build/changelog/migration_13.rst +++ b/doc/build/changelog/migration_13.rst @@ -952,3 +952,49 @@ Pass it via :func:`.create_engine`:: :ticket:`4158` + +.. _change_4362: + +New parameters to affect IDENTITY start and increment, use of Sequence deprecated +--------------------------------------------------------------------------------- + +SQL Server as of SQL Server 2012 now supports sequences with real +``CREATE SEQUENCE`` syntax. In :ticket:`4235`, SQLAchemy will add support for +these using :class:`.Sequence` in the same way as for any other dialect. +However, the current situation is that :class:`.Sequence` has been repurposed +on SQL Server specifically in order to affect the "start" and "increment" +parameters for the ``IDENTITY`` specification on a primary key column. In order +to make the transition towards normal sequences being available as well, +using :class:.`.Sequence` will emit a deprecation warning throughout the +1.3 series. In order to affect "start" and "increment", use the +new ``mssql_identity_start`` and ``mssql_identity_increment`` parameters +on :class:`.Column`:: + + test = Table( + 'test', metadata, + Column( + 'id', Integer, primary_key=True, mssql_identity_start=100, + mssql_identity_increment=10 + ), + Column('name', String(20)) + ) + +In order to emit ``IDENTITY`` on a non-primary key column, which is a little-used +but valid SQL Server use case, use the :paramref:`.Column.autoincrement` flag, +setting it to ``True`` on the target column, ``False`` on any integer +primary key column:: + + + test = Table( + 'test', metadata, + Column('id', Integer, primary_key=True, autoincrement=False), + Column('number', Integer, autoincrement=True) + ) + +.. seealso:: + + :ref:`mssql_identity` + +:ticket:`4362` + +:ticket:`4235` \ No newline at end of file diff --git a/doc/build/changelog/unreleased_13/4362.rst b/doc/build/changelog/unreleased_13/4362.rst new file mode 100644 index 0000000000..59b00fc11b --- /dev/null +++ b/doc/build/changelog/unreleased_13/4362.rst @@ -0,0 +1,14 @@ +.. change:: + :tags: bug, mssql + :tickets: 4362 + + Deprecated the use of :class:`.Sequence` with SQL Server in order to affect + the "start" and "increment" of the IDENTITY value, in favor of new + parameters ``mssql_identity_start`` and ``mssql_identity_increment`` which + set these parameters directly. :class:`.Sequence` will be used to generate + real ``CREATE SEQUENCE`` DDL with SQL Server in a future release. + + .. seealso:: + + :ref:`change_4362` + diff --git a/lib/sqlalchemy/dialects/mssql/base.py b/lib/sqlalchemy/dialects/mssql/base.py index ec267880cf..9269225d31 100644 --- a/lib/sqlalchemy/dialects/mssql/base.py +++ b/lib/sqlalchemy/dialects/mssql/base.py @@ -10,15 +10,18 @@ :name: Microsoft SQL Server -Auto Increment Behavior ------------------------ +.. _mssql_identity: + +Auto Increment Behavior / IDENTITY Columns +------------------------------------------ SQL Server provides so-called "auto incrementing" behavior using the -``IDENTITY`` construct, which can be placed on an integer primary key. -SQLAlchemy considers ``IDENTITY`` within its default "autoincrement" behavior, -described at :paramref:`.Column.autoincrement`; this means -that by default, the first integer primary key column in a :class:`.Table` -will be considered to be the identity column and will generate DDL as such:: +``IDENTITY`` construct, which can be placed on any single integer column in a +table. SQLAlchemy considers ``IDENTITY`` within its default "autoincrement" +behavior for an integer primary key column, described at +:paramref:`.Column.autoincrement`. This means that by default, the first +integer primary key column in a :class:`.Table` will be considered to be the +identity column and will generate DDL as such:: from sqlalchemy import Table, MetaData, Column, Integer @@ -39,7 +42,8 @@ The above example will generate DDL as: ) For the case where this default generation of ``IDENTITY`` is not desired, -specify ``autoincrement=False`` on all integer primary key columns:: +specify ``False`` for the :paramref:`.Column.autoincrement` flag, +on the first integer primary key column:: m = MetaData() t = Table('t', m, @@ -47,34 +51,64 @@ specify ``autoincrement=False`` on all integer primary key columns:: Column('x', Integer)) m.create_all(engine) +To add the ``IDENTITY`` keyword to a non-primary key column, specify +``True`` for the :paramref:`.Column.autoincrement` flag on the desired +:class:`.Column` object, and ensure that :paramref:`.Column.autoincrement` +is set to ``False`` on any integer primary key column:: + + m = MetaData() + t = Table('t', m, + Column('id', Integer, primary_key=True, autoincrement=False), + Column('x', Integer, autoincrement=True)) + m.create_all(engine) + +.. versionchanged:: 1.3 Added ``mssql_identity_start`` and + ``mssql_identity_increment`` parameters to :class:`.Column`. These replace + the use of the :class:`.Sequence` object in order to specify these values. + The use of :class:`.Sequence` to specify IDENTITY characteristics is + deprecated and will emit a warning. + +.. note:: + + There can only be one IDENTITY column on the table. When using + ``autoincrement=True`` to enable the IDENTITY keyword, SQLAlchemy does not + guard against multiple columns specifying the option simultaneously. The + SQL Server database will instead reject the ``CREATE TABLE`` statement. + .. note:: - An INSERT statement which refers to an explicit value for such - a column is prohibited by SQL Server, however SQLAlchemy will detect this - and modify the ``IDENTITY_INSERT`` flag accordingly at statement execution - time. As this is not a high performing process, care should be taken to - set the ``autoincrement`` flag appropriately for columns that will not - actually require IDENTITY behavior. + An INSERT statement which attempts to provide a value for a column that is + marked with IDENTITY will be rejected by SQL Server. In order for the + value to be accepted, a session-level option "SET IDENTITY_INSERT" must be + enabled. The SQLAlchemy SQL Server dialect will perform this operation + automatically when using a core :class:`.Insert` construct; if the + execution specifies a value for the IDENTITY column, the "IDENTITY_INSERT" + option will be enabled for the span of that statement's invocation.However, + this scenario is not high performing and should not be relied upon for + normal use. If a table doesn't actually require IDENTITY behavior in its + integer primary key column, the keyword should be disabled when creating + the table by ensuring that ``autoincrement=False`` is set. Controlling "Start" and "Increment" ^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ -Specific control over the parameters of the ``IDENTITY`` value is supported -using the :class:`.schema.Sequence` object. While this object normally -represents an explicit "sequence" for supporting backends, on SQL Server it is -re-purposed to specify behavior regarding the identity column, including -support of the "start" and "increment" values:: +Specific control over the "start" and "increment" values for +the ``IDENTITY`` generator are provided using the +``mssql_identity_start`` and ``mssql_identity_increment`` parameters +passed to the :class:`.Column` object:: - from sqlalchemy import Table, Integer, Sequence, Column + from sqlalchemy import Table, Integer, Column - Table('test', metadata, - Column('id', Integer, - Sequence('blah', start=100, increment=10), - primary_key=True), - Column('name', String(20)) - ).create(some_engine) + test = Table( + 'test', metadata, + Column( + 'id', Integer, primary_key=True, mssql_identity_start=100, + mssql_identity_increment=10 + ), + Column('name', String(20)) + ) -would yield: +The CREATE TABLE for the above :class:`.Table` object would be: .. sourcecode:: sql @@ -83,8 +117,12 @@ would yield: name VARCHAR(20) NULL, ) -Note that the ``start`` and ``increment`` values for sequences are -optional and will default to 1,1. +.. versionchanged:: 1.3 The ``mssql_identity_start`` and + ``mssql_identity_increment`` parameters are now used to affect the + ``IDENTITY`` generator for a :class:`.Column` under SQL Server. + Previously, the :class:`.Sequence` object was used. As SQL Server now + supports real sequences as a separate construct, :class:`.Sequence` will be + functional in the normal way in a future SQLAlchemy version. INSERT behavior ^^^^^^^^^^^^^^^^ @@ -1592,7 +1630,8 @@ class MSDDLCompiler(compiler.DDLCompiler): if column.nullable is not None: if not column.nullable or column.primary_key or \ - isinstance(column.default, sa_schema.Sequence): + isinstance(column.default, sa_schema.Sequence) or \ + column.autoincrement is True: colspec += " NOT NULL" else: colspec += " NULL" @@ -1605,6 +1644,18 @@ class MSDDLCompiler(compiler.DDLCompiler): # install an IDENTITY Sequence if we either a sequence or an implicit # IDENTITY column if isinstance(column.default, sa_schema.Sequence): + + if (column.default.start is not None or + column.default.increment is not None or + column is not column.table._autoincrement_column): + util.warn_deprecated( + "Use of Sequence with SQL Server in order to affect the " + "parameters of the IDENTITY value is deprecated, as " + "Sequence " + "will correspond to an actual SQL Server " + "CREATE SEQUENCE in " + "a future release. Please use the mssql_identity_start " + "and mssql_identity_increment parameters.") if column.default.start == 0: start = 0 else: @@ -1612,8 +1663,11 @@ class MSDDLCompiler(compiler.DDLCompiler): colspec += " IDENTITY(%s,%s)" % (start, column.default.increment or 1) - elif column is column.table._autoincrement_column: - colspec += " IDENTITY(1,1)" + elif column is column.table._autoincrement_column or \ + column.autoincrement is True: + start = column.dialect_options['mssql']['identity_start'] + increment = column.dialect_options['mssql']['identity_increment'] + colspec += " IDENTITY(%s,%s)" % (start, increment) else: default = self.get_column_default_string(column) if default is not None: @@ -1845,6 +1899,10 @@ class MSDialect(default.DefaultDialect): (sa_schema.Index, { "clustered": None, "include": None + }), + (sa_schema.Column, { + "identity_start": 1, + "identity_increment": 1 }) ] @@ -2188,8 +2246,10 @@ class MSDialect(default.DefaultDialect): if type_name.endswith("identity") and col_name in colmap: ic = col_name colmap[col_name]['autoincrement'] = True - colmap[col_name]['sequence'] = dict( - name='%s_identity' % col_name) + colmap[col_name]['dialect_options'] = { + 'mssql_identity_start': 1, + 'mssql_identity_increment': 1 + } break cursor.close() @@ -2202,9 +2262,9 @@ class MSDialect(default.DefaultDialect): row = cursor.first() if row is not None and row[0] is not None: - colmap[ic]['sequence'].update({ - 'start': int(row[0]), - 'increment': int(row[1]) + colmap[ic]['dialect_options'].update({ + 'mssql_identity_start': int(row[0]), + 'mssql_identity_increment': int(row[1]) }) return cols diff --git a/lib/sqlalchemy/engine/reflection.py b/lib/sqlalchemy/engine/reflection.py index a572a34f28..841bb4dfb4 100644 --- a/lib/sqlalchemy/engine/reflection.py +++ b/lib/sqlalchemy/engine/reflection.py @@ -667,10 +667,15 @@ class Inspector(object): col_kw = dict( (k, col_d[k]) - for k in ['nullable', 'autoincrement', 'quote', 'info', 'key', 'comment'] + for k in [ + 'nullable', 'autoincrement', 'quote', 'info', 'key', + 'comment'] if k in col_d ) + if 'dialect_options' in col_d: + col_kw.update(col_d['dialect_options']) + colargs = [] if col_d.get('default') is not None: default = col_d['default'] diff --git a/test/dialect/mssql/test_compiler.py b/test/dialect/mssql/test_compiler.py index e9f9afef5b..0a79b3e598 100644 --- a/test/dialect/mssql/test_compiler.py +++ b/test/dialect/mssql/test_compiler.py @@ -731,34 +731,123 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): checkparams={'x_1': 5} ) - def test_sequence_start_0(self): + def test_primary_key_no_identity(self): metadata = MetaData() tbl = Table('test', metadata, - Column('id', Integer, Sequence('', 0), primary_key=True)) + Column('id', Integer, autoincrement=False, + primary_key=True)) self.assert_compile( schema.CreateTable(tbl), - "CREATE TABLE test (id INTEGER NOT NULL IDENTITY(0,1), " + "CREATE TABLE test (id INTEGER NOT NULL, " "PRIMARY KEY (id))" ) - def test_sequence_non_primary_key(self): + def test_primary_key_defaults_to_identity(self): metadata = MetaData() tbl = Table('test', metadata, - Column('id', Integer, Sequence(''), primary_key=False)) + Column('id', Integer, primary_key=True)) self.assert_compile( schema.CreateTable(tbl), - "CREATE TABLE test (id INTEGER NOT NULL IDENTITY(1,1))" + "CREATE TABLE test (id INTEGER NOT NULL IDENTITY(1,1), " + "PRIMARY KEY (id))" ) - def test_sequence_ignore_nullability(self): + def test_identity_no_primary_key(self): + metadata = MetaData() + tbl = Table('test', metadata, + Column('id', Integer, autoincrement=True)) + self.assert_compile( + schema.CreateTable(tbl), + "CREATE TABLE test (id INTEGER NOT NULL IDENTITY(1,1)" + ")" + ) + + def test_identity_separate_from_primary_key(self): metadata = MetaData() tbl = Table('test', metadata, - Column('id', Integer, Sequence(''), nullable=True)) + Column('id', Integer, autoincrement=False, + primary_key=True), + Column('x', Integer, autoincrement=True) + ) self.assert_compile( schema.CreateTable(tbl), - "CREATE TABLE test (id INTEGER NOT NULL IDENTITY(1,1))" + "CREATE TABLE test (id INTEGER NOT NULL, " + "x INTEGER NOT NULL IDENTITY(1,1), " + "PRIMARY KEY (id))" + ) + + def test_identity_illegal_two_autoincrements(self): + metadata = MetaData() + tbl = Table('test', metadata, + Column('id', Integer, autoincrement=True), + Column('id2', Integer, autoincrement=True), + ) + # this will be rejected by the database, just asserting this is what + # the two autoincrements will do right now + self.assert_compile( + schema.CreateTable(tbl), + "CREATE TABLE test (id INTEGER NOT NULL IDENTITY(1,1), " + "id2 INTEGER NOT NULL IDENTITY(1,1))" + ) + + def test_identity_start_0(self): + metadata = MetaData() + tbl = Table('test', metadata, + Column('id', Integer, mssql_identity_start=0, + primary_key=True)) + self.assert_compile( + schema.CreateTable(tbl), + "CREATE TABLE test (id INTEGER NOT NULL IDENTITY(0,1), " + "PRIMARY KEY (id))" ) + def test_identity_increment_5(self): + metadata = MetaData() + tbl = Table('test', metadata, + Column('id', Integer, mssql_identity_increment=5, + primary_key=True)) + self.assert_compile( + schema.CreateTable(tbl), + "CREATE TABLE test (id INTEGER NOT NULL IDENTITY(1,5), " + "PRIMARY KEY (id))" + ) + + def test_sequence_start_0(self): + metadata = MetaData() + tbl = Table('test', metadata, + Column('id', Integer, Sequence('', 0), primary_key=True)) + with testing.expect_deprecated( + "Use of Sequence with SQL Server in order to affect "): + self.assert_compile( + schema.CreateTable(tbl), + "CREATE TABLE test (id INTEGER NOT NULL IDENTITY(0,1), " + "PRIMARY KEY (id))" + ) + + def test_sequence_non_primary_key(self): + metadata = MetaData() + tbl = Table('test', metadata, + Column('id', Integer, Sequence('', start=5), + primary_key=False)) + with testing.expect_deprecated( + "Use of Sequence with SQL Server in order to affect "): + self.assert_compile( + schema.CreateTable(tbl), + "CREATE TABLE test (id INTEGER NOT NULL IDENTITY(5,1))" + ) + + def test_sequence_ignore_nullability(self): + metadata = MetaData() + tbl = Table('test', metadata, + Column('id', Integer, Sequence('', start=5), + nullable=True)) + with testing.expect_deprecated( + "Use of Sequence with SQL Server in order to affect "): + self.assert_compile( + schema.CreateTable(tbl), + "CREATE TABLE test (id INTEGER NOT NULL IDENTITY(5,1))" + ) + def test_table_pkc_clustering(self): metadata = MetaData() tbl = Table('test', metadata, diff --git a/test/dialect/mssql/test_query.py b/test/dialect/mssql/test_query.py index ef2a1426af..13876d6d18 100644 --- a/test/dialect/mssql/test_query.py +++ b/test/dialect/mssql/test_query.py @@ -8,7 +8,7 @@ from sqlalchemy.util import ue from sqlalchemy import util from sqlalchemy.testing.assertsql import CursorSQL, DialectSQL from sqlalchemy import Integer, String, Table, Column, select, MetaData,\ - func, PrimaryKeyConstraint, desc, Sequence, DDL, ForeignKey, or_, and_ + func, PrimaryKeyConstraint, desc, DDL, ForeignKey, or_, and_ from sqlalchemy import event metadata = None @@ -254,7 +254,7 @@ class QueryTest(testing.AssertsExecutionResults, fixtures.TestBase): # test should be written. meta = MetaData(testing.db) t1 = Table('t1', meta, - Column('id', Integer, Sequence('fred', 100, 1), + Column('id', Integer, mssql_identity_start=100, primary_key=True), Column('descr', String(200)), # the following flag will prevent the @@ -265,7 +265,7 @@ class QueryTest(testing.AssertsExecutionResults, fixtures.TestBase): implicit_returning=False ) t2 = Table('t2', meta, - Column('id', Integer, Sequence('fred', 200, 1), + Column('id', Integer, mssql_identity_start=200, primary_key=True), Column('descr', String(200))) meta.create_all() diff --git a/test/dialect/mssql/test_reflection.py b/test/dialect/mssql/test_reflection.py index 720d6ec18f..e526168f15 100644 --- a/test/dialect/mssql/test_reflection.py +++ b/test/dialect/mssql/test_reflection.py @@ -94,16 +94,19 @@ class ReflectionTest(fixtures.TestBase, ComparesTables, AssertsCompiledSQL): metadata = self.metadata table = Table( 'identity_test', metadata, - Column('col1', Integer, Sequence('fred', 2, 3), primary_key=True) + Column('col1', Integer, mssql_identity_start=2, + mssql_identity_increment=3, primary_key=True) ) table.create() meta2 = MetaData(testing.db) table2 = Table('identity_test', meta2, autoload=True) - sequence = isinstance(table2.c['col1'].default, schema.Sequence) \ - and table2.c['col1'].default - assert sequence.start == 2 - assert sequence.increment == 3 + eq_( + table2.c['col1'].dialect_options['mssql'][ + 'identity_start'], 2) + eq_( + table2.c['col1'].dialect_options['mssql'][ + 'identity_increment'], 3) @testing.emits_warning("Did not recognize") @testing.provide_metadata