From: Denis Kataev Date: Mon, 12 Mar 2018 15:40:34 +0000 (-0400) Subject: Implement SQLite ON CONFLICT for constraints X-Git-Tag: rel_1_3_0b1~21^2 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=de804d7245dd203bc63e4493162bcdf5e8646440;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git Implement SQLite ON CONFLICT for constraints Implemented the SQLite ``ON CONFLICT`` clause as understood at the DDL level, e.g. for primary key, unique, and CHECK constraints as well as specified on a :class:`.Column` to satisfy inline primary key and NOT NULL. Pull request courtesy Denis Kataev. Fixes: #4360 Change-Id: I4cd4bafa8fca41e3101c87dbbfe169741bbda3f4 Pull-request: https://github.com/zzzeek/sqlalchemy/pull/431 --- diff --git a/doc/build/changelog/migration_13.rst b/doc/build/changelog/migration_13.rst index eab13bef95..1c3e5b0f72 100644 --- a/doc/build/changelog/migration_13.rst +++ b/doc/build/changelog/migration_13.rst @@ -855,6 +855,38 @@ JSON is being used for its familiarity. :ticket:`3850` +.. _change_4360: + +Support for SQLite ON CONFLICT in constraints added +---------------------------------------------------- + +SQLite supports a non-standard ON CONFLICT clause that may be specified +for standalone constraints as well as some column-inline constraints such as +NOT NULL. Support has been added for these clauses via the ``sqlite_on_conflict`` +keyword added to objects like :class:`.UniqueConstraint` as well +as several :class:`.Column` -specific variants:: + + some_table = Table( + 'some_table', metadata, + Column('id', Integer, primary_key=True, sqlite_on_conflict_primary_key='FAIL'), + Column('data', Integer), + UniqueConstraint('id', 'data', sqlite_on_conflict='IGNORE') + ) + +The above table would render in a CREATE TABLE statement as:: + + CREATE TABLE some_table ( + id INTEGER NOT NULL, + data INTEGER, + PRIMARY KEY (id) ON CONFLICT FAIL, + UNIQUE (id, data) ON CONFLICT IGNORE + ) + +.. seealso:: + + :ref:`sqlite_on_conflict_ddl` + +:ticket:`4360` Dialect Improvements and Changes - Oracle ============================================= diff --git a/doc/build/changelog/unreleased_13/4360.rst b/doc/build/changelog/unreleased_13/4360.rst new file mode 100644 index 0000000000..433a33d47f --- /dev/null +++ b/doc/build/changelog/unreleased_13/4360.rst @@ -0,0 +1,12 @@ +.. change:: + :tags: feature, sqlite + :tickets: 4360 + + Implemented the SQLite ``ON CONFLICT`` clause as understood at the DDL + level, e.g. for primary key, unique, and CHECK constraints as well as + specified on a :class:`.Column` to satisfy inline primary key and NOT NULL. + Pull request courtesy Denis Kataev. + + .. seealso:: + + :ref:`change_4360` diff --git a/lib/sqlalchemy/dialects/sqlite/base.py b/lib/sqlalchemy/dialects/sqlite/base.py index 345ad901ed..79b3a53192 100644 --- a/lib/sqlalchemy/dialects/sqlite/base.py +++ b/lib/sqlalchemy/dialects/sqlite/base.py @@ -282,6 +282,110 @@ new connections through the usage of events:: :ref:`use_alter` - more information on SQLAlchemy's facilities for handling mutually-dependent foreign key constraints. +.. _sqlite_on_conflict_ddl: + +ON CONFLICT support for constraints +----------------------------------- + +SQLite supports a non-standard clause known as ON CONFLICT which can be applied +to primary key, unique, check, and not null constraints. In DDL, it is +rendered either within the "CONSTRAINT" clause or within the column definition +itself depending on the location of the target constraint. To render this +clause within DDL, the extension parameter ``sqlite_on_conflict`` can be +specified with a string conflict resolution algorithm within the +:class:`.PrimaryKeyConstraint`, :class:`.UniqueConstraint`, +:class:`.CheckConstraint` objects. Within the :class:`.Column` object, there +are individual parameters ``sqlite_on_conflict_not_null``, +``sqlite_on_conflict_primary_key``, ``sqlite_on_conflict_unique`` which each +correspond to the three types of relevant constraint types that can be +indicated from a :class:`.Column` object. + +.. seealso:: + + `ON CONFLICT `_ - in the SQLite + documentation + +.. versionadded:: 1.3 + + +The ``sqlite_on_conflict`` parameters accept a string argument which is just +the resolution name to be chosen, which on SQLite can be one of ROLLBACK, +ABORT, FAIL, IGNORE, and REPLACE. For example, to add a UNIQUE constraint +that specifies the IGNORE algorithm:: + + some_table = Table( + 'some_table', metadata, + Column('id', Integer, primary_key=True), + Column('data', Integer), + UniqueConstraint('id', 'data', sqlite_on_conflict='IGNORE') + ) + +The above renders CREATE TABLE DDL as:: + + CREATE TABLE some_table ( + id INTEGER NOT NULL, + data INTEGER, + PRIMARY KEY (id), + UNIQUE (id, data) ON CONFLICT IGNORE + ) + + +When using the :paramref:`.Column.unique` flag to add a UNIQUE constraint +to a single column, the ``sqlite_on_conflict_unique`` parameter can +be added to the :class:`.Column` as well, which will be added to the +UNIQUE constraint in the DDL:: + + some_table = Table( + 'some_table', metadata, + Column('id', Integer, primary_key=True), + Column('data', Integer, unique=True, + sqlite_on_conflict_unique='IGNORE') + ) + +rendering:: + + CREATE TABLE some_table ( + id INTEGER NOT NULL, + data INTEGER, + PRIMARY KEY (id), + UNIQUE (data) ON CONFLICT IGNORE + ) + +To apply the FAIL algorithm for a NOT NULL constraint, +``sqlite_on_conflict_not_null`` is used:: + + some_table = Table( + 'some_table', metadata, + Column('id', Integer, primary_key=True), + Column('data', Integer, nullable=False, + sqlite_on_conflict_not_null='FAIL') + ) + +this renders the column inline ON CONFLICT phrase:: + + CREATE TABLE some_table ( + id INTEGER NOT NULL, + data INTEGER NOT NULL ON CONFLICT FAIL, + PRIMARY KEY (id) + ) + + +Similarly, for an inline primary key, use ``sqlite_on_conflict_primary_key``:: + + some_table = Table( + 'some_table', metadata, + Column('id', Integer, primary_key=True, + sqlite_on_conflict_primary_key='FAIL') + ) + +SQLAlchemy renders the PRIMARY KEY constraint separately, so the conflict +resolution algorithm is applied to the constraint itself:: + + CREATE TABLE some_table ( + id INTEGER NOT NULL, + PRIMARY KEY (id) ON CONFLICT FAIL + ) + .. _sqlite_type_reflection: Type Reflection @@ -887,6 +991,11 @@ class SQLiteDDLCompiler(compiler.DDLCompiler): if not column.nullable: colspec += " NOT NULL" + on_conflict_clause = column.dialect_options['sqlite'][ + 'on_conflict_not_null'] + if on_conflict_clause is not None: + colspec += " ON CONFLICT " + on_conflict_clause + if column.primary_key: if ( column.autoincrement is True and @@ -898,9 +1007,17 @@ class SQLiteDDLCompiler(compiler.DDLCompiler): if (column.table.dialect_options['sqlite']['autoincrement'] and len(column.table.primary_key.columns) == 1 and - issubclass(column.type._type_affinity, sqltypes.Integer) and + issubclass( + column.type._type_affinity, sqltypes.Integer) and not column.foreign_keys): - colspec += " PRIMARY KEY AUTOINCREMENT" + colspec += " PRIMARY KEY" + + on_conflict_clause = column.dialect_options['sqlite'][ + 'on_conflict_primary_key'] + if on_conflict_clause is not None: + colspec += " ON CONFLICT " + on_conflict_clause + + colspec += " AUTOINCREMENT" return colspec @@ -916,8 +1033,61 @@ class SQLiteDDLCompiler(compiler.DDLCompiler): not c.foreign_keys): return None - return super(SQLiteDDLCompiler, self).visit_primary_key_constraint( - constraint) + text = super( + SQLiteDDLCompiler, + self).visit_primary_key_constraint(constraint) + + on_conflict_clause = constraint.dialect_options['sqlite'][ + 'on_conflict'] + if on_conflict_clause is None and len(constraint.columns) == 1: + on_conflict_clause = list(constraint)[0].\ + dialect_options['sqlite']['on_conflict_primary_key'] + + if on_conflict_clause is not None: + text += " ON CONFLICT " + on_conflict_clause + + return text + + def visit_unique_constraint(self, constraint): + text = super( + SQLiteDDLCompiler, + self).visit_unique_constraint(constraint) + + on_conflict_clause = constraint.dialect_options['sqlite'][ + 'on_conflict'] + if on_conflict_clause is None and len(constraint.columns) == 1: + on_conflict_clause = list(constraint)[0].\ + dialect_options['sqlite']['on_conflict_unique'] + + if on_conflict_clause is not None: + text += " ON CONFLICT " + on_conflict_clause + + return text + + def visit_check_constraint(self, constraint): + text = super( + SQLiteDDLCompiler, + self).visit_check_constraint(constraint) + + on_conflict_clause = constraint.dialect_options['sqlite'][ + 'on_conflict'] + + if on_conflict_clause is not None: + text += " ON CONFLICT " + on_conflict_clause + + return text + + def visit_column_check_constraint(self, constraint): + text = super( + SQLiteDDLCompiler, + self).visit_column_check_constraint(constraint) + + if constraint.dialect_options['sqlite']['on_conflict'] is not None: + raise exc.CompileError( + "SQLite does not support on conflict clause for " + "column check constraint") + + return text def visit_foreign_key_constraint(self, constraint): @@ -1084,6 +1254,14 @@ class SQLiteDialect(default.DefaultDialect): (sa_schema.Index, { "where": None, }), + (sa_schema.Column, { + "on_conflict_primary_key": None, + "on_conflict_not_null": None, + "on_conflict_unique": None, + }), + (sa_schema.Constraint, { + "on_conflict": None, + }), ] _broken_fk_pragma_quotes = False diff --git a/lib/sqlalchemy/sql/schema.py b/lib/sqlalchemy/sql/schema.py index 88050b87e3..14d7067200 100644 --- a/lib/sqlalchemy/sql/schema.py +++ b/lib/sqlalchemy/sql/schema.py @@ -913,7 +913,7 @@ class Table(DialectKWArgs, SchemaItem, TableClause): return self._schema_item_copy(table) -class Column(SchemaItem, ColumnClause): +class Column(DialectKWArgs, SchemaItem, ColumnClause): """Represents a column in a database table.""" __visit_name__ = 'column' @@ -1284,9 +1284,10 @@ class Column(SchemaItem, ColumnClause): if 'info' in kwargs: self.info = kwargs.pop('info') - if kwargs: - raise exc.ArgumentError( - "Unknown arguments passed to Column: " + repr(list(kwargs))) + self._extra_kwargs(**kwargs) + + def _extra_kwargs(self, **kwargs): + self._validate_dialect_kwargs(kwargs) # @property # def quote(self): @@ -2748,7 +2749,7 @@ class CheckConstraint(ColumnCollectionConstraint): def __init__(self, sqltext, name=None, deferrable=None, initially=None, table=None, info=None, _create_rule=None, - _autoattach=True, _type_bound=False): + _autoattach=True, _type_bound=False, **kw): r"""Construct a CHECK constraint. :param sqltext: @@ -2787,7 +2788,7 @@ class CheckConstraint(ColumnCollectionConstraint): name=name, deferrable=deferrable, initially=initially, _create_rule=_create_rule, info=info, _type_bound=_type_bound, _autoattach=_autoattach, - *columns) + *columns, **kw) if table is not None: self._set_parent_with_dispatch(table) diff --git a/test/dialect/test_sqlite.py b/test/dialect/test_sqlite.py index 9b1d5d7ea5..417ace5c8f 100644 --- a/test/dialect/test_sqlite.py +++ b/test/dialect/test_sqlite.py @@ -8,7 +8,8 @@ from sqlalchemy.testing import eq_, assert_raises, \ assert_raises_message, is_, expect_warnings from sqlalchemy import Table, select, bindparam, Column,\ MetaData, func, extract, ForeignKey, text, DefaultClause, and_, \ - create_engine, UniqueConstraint, Index, PrimaryKeyConstraint + create_engine, \ + UniqueConstraint, Index, PrimaryKeyConstraint, CheckConstraint from sqlalchemy.types import Integer, String, Boolean, DateTime, Date, Time from sqlalchemy import types as sqltypes from sqlalchemy import event, inspect @@ -835,6 +836,139 @@ class SQLTest(fixtures.TestBase, AssertsCompiledSQL): CreateTable(t).compile, dialect=sqlite.dialect() ) +class OnConflictDDLTest(fixtures.TestBase, AssertsCompiledSQL): + + __dialect__ = sqlite.dialect() + + def test_on_conflict_clause_column_not_null(self): + c = Column('test', Integer, nullable=False, + sqlite_on_conflict_not_null='FAIL') + + self.assert_compile(schema.CreateColumn(c), + 'test INTEGER NOT NULL ' + 'ON CONFLICT FAIL', dialect=sqlite.dialect()) + + def test_on_conflict_clause_column_many_clause(self): + meta = MetaData() + t = Table( + 'n', meta, + Column('test', Integer, nullable=False, primary_key=True, + sqlite_on_conflict_not_null='FAIL', + sqlite_on_conflict_primary_key='IGNORE') + ) + + self.assert_compile(CreateTable(t), + "CREATE TABLE n (" + "test INTEGER NOT NULL ON CONFLICT FAIL, " + "PRIMARY KEY (test) ON CONFLICT IGNORE)", + dialect=sqlite.dialect()) + + def test_on_conflict_clause_unique_constraint_from_column(self): + meta = MetaData() + t = Table( + 'n', meta, + Column('x', String(30), unique=True, + sqlite_on_conflict_unique='FAIL'), + ) + + self.assert_compile(CreateTable(t), + "CREATE TABLE n (x VARCHAR(30), " + "UNIQUE (x) ON CONFLICT FAIL)", + dialect=sqlite.dialect()) + + def test_on_conflict_clause_unique_constraint(self): + + meta = MetaData() + t = Table( + 'n', meta, + Column('id', Integer), + Column('x', String(30)), + UniqueConstraint('id', 'x', sqlite_on_conflict='FAIL'), + ) + + self.assert_compile(CreateTable(t), + "CREATE TABLE n (id INTEGER, x VARCHAR(30), " + "UNIQUE (id, x) ON CONFLICT FAIL)", + dialect=sqlite.dialect()) + + def test_on_conflict_clause_primary_key(self): + + meta = MetaData() + t = Table( + 'n', meta, + Column('id', Integer, primary_key=True, + sqlite_on_conflict_primary_key='FAIL'), + sqlite_autoincrement=True + ) + + self.assert_compile(CreateTable(t), + "CREATE TABLE n (id INTEGER NOT NULL " + "PRIMARY KEY ON CONFLICT FAIL AUTOINCREMENT)", + dialect=sqlite.dialect()) + + def test_on_conflict_clause_primary_key_constraint_from_column(self): + + meta = MetaData() + t = Table( + 'n', meta, + Column('x', String(30), sqlite_on_conflict_primary_key='FAIL', + primary_key=True), + ) + + self.assert_compile(CreateTable(t), + "CREATE TABLE n (x VARCHAR(30) NOT NULL, " + "PRIMARY KEY (x) ON CONFLICT FAIL)", + dialect=sqlite.dialect()) + + def test_on_conflict_clause_check_constraint(self): + + meta = MetaData() + t = Table( + 'n', meta, + Column('id', Integer), + Column('x', Integer), + CheckConstraint('id > x', sqlite_on_conflict='FAIL'), + ) + + self.assert_compile(CreateTable(t), + "CREATE TABLE n (id INTEGER, x INTEGER, " + "CHECK (id > x) ON CONFLICT FAIL)", + dialect=sqlite.dialect()) + + def test_on_conflict_clause_check_constraint_from_column(self): + + meta = MetaData() + t = Table( + 'n', meta, + Column('x', Integer, + CheckConstraint('x > 1', + sqlite_on_conflict='FAIL')), + ) + + assert_raises_message( + exc.CompileError, + "SQLite does not support on conflict " + "clause for column check constraint", + CreateTable(t).compile, dialect=sqlite.dialect() + ) + + def test_on_conflict_clause_primary_key_constraint(self): + + meta = MetaData() + t = Table( + 'n', meta, + Column('id', Integer), + Column('x', String(30)), + PrimaryKeyConstraint('id', 'x', sqlite_on_conflict='FAIL'), + ) + + self.assert_compile(CreateTable(t), + "CREATE TABLE n (" + "id INTEGER NOT NULL, " + "x VARCHAR(30) NOT NULL, " + "PRIMARY KEY (id, x) ON CONFLICT FAIL)", + dialect=sqlite.dialect()) + class InsertTest(fixtures.TestBase, AssertsExecutionResults):