From: Mike Bayer Date: Sun, 26 Jul 2020 17:17:56 +0000 (-0400) Subject: Improve delete cascade and passive deletes sections X-Git-Tag: rel_1_4_0b1~213 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=9e1ee412b8650761af6df993e119906682604728;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git Improve delete cascade and passive deletes sections Add cross linking from Core to ORM and also add new sections and examples regarding many-to-many. Move the section out of "collections" and into the "cascades" chapter where it's more likely to be found. Change-Id: If29360e463e5745279bc5335bd12352d50ad8953 --- diff --git a/doc/build/core/constraints.rst b/doc/build/core/constraints.rst index 3e1eaabad4..9e6ba0b732 100644 --- a/doc/build/core/constraints.rst +++ b/doc/build/core/constraints.rst @@ -303,6 +303,14 @@ arguments. The value is any string which will be output after the appropriate Note that these clauses require ``InnoDB`` tables when used with MySQL. They may also not be supported on other databases. +.. seealso:: + + For background on integration of ``ON DELETE CASCADE`` with + ORM :func:`_orm.relationship` constructs, see the following sections: + + :ref:`passive_deletes` + + :ref:`passive_deletes_many_to_many` UNIQUE Constraint ----------------- diff --git a/doc/build/orm/basic_relationships.rst b/doc/build/orm/basic_relationships.rst index a837dd6317..b05701802b 100644 --- a/doc/build/orm/basic_relationships.rst +++ b/doc/build/orm/basic_relationships.rst @@ -57,6 +57,24 @@ on a single :func:`_orm.relationship` instead of using id = Column(Integer, primary_key=True) children = relationship("Child", backref="parent") +Configuring Delete Behavior for One to Many +^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ + +It is often the case that all ``Child`` objects should be deleted +when their owning ``Parent`` is deleted. To configure this behavior, +the ``delete`` cascade option described at :ref:`cascade_delete` is used. +An additional option is that a ``Child`` object can itself be deleted when +it is deassociated from its parent. This behavior is described at +:ref:`cascade_delete_orphan`. + +.. seealso:: + + :ref:`cascade_delete` + + :ref:`passive_deletes` + + :ref:`cascade_delete_orphan` + Many To One ~~~~~~~~~~~ @@ -153,9 +171,10 @@ Many To Many Many to Many adds an association table between two classes. The association table is indicated by the :paramref:`_orm.relationship.secondary` argument to -:func:`_orm.relationship`. Usually, the :class:`_schema.Table` uses the :class:`_schema.MetaData` -object associated with the declarative base class, so that the :class:`_schema.ForeignKey` -directives can locate the remote tables with which to link:: +:func:`_orm.relationship`. Usually, the :class:`_schema.Table` uses the +:class:`_schema.MetaData` object associated with the declarative base +class, so that the :class:`_schema.ForeignKey` directives can locate the +remote tables with which to link:: association_table = Table('association', Base.metadata, Column('left_id', Integer, ForeignKey('left.id')), @@ -198,8 +217,9 @@ for each :func:`_orm.relationship` specify the common association table:: back_populates="children") When using the :paramref:`_orm.relationship.backref` parameter instead of -:paramref:`_orm.relationship.back_populates`, the backref will automatically use -the same :paramref:`_orm.relationship.secondary` argument for the reverse relationship:: +:paramref:`_orm.relationship.back_populates`, the backref will automatically +use the same :paramref:`_orm.relationship.secondary` argument for the +reverse relationship:: association_table = Table('association', Base.metadata, Column('left_id', Integer, ForeignKey('left.id')), @@ -217,11 +237,11 @@ the same :paramref:`_orm.relationship.secondary` argument for the reverse relati __tablename__ = 'right' id = Column(Integer, primary_key=True) -The :paramref:`_orm.relationship.secondary` argument of :func:`_orm.relationship` also accepts a callable -that returns the ultimate argument, which is evaluated only when mappers are -first used. Using this, we can define the ``association_table`` at a later -point, as long as it's available to the callable after all module initialization -is complete:: +The :paramref:`_orm.relationship.secondary` argument of +:func:`_orm.relationship` also accepts a callable that returns the ultimate +argument, which is evaluated only when mappers are first used. Using this, we +can define the ``association_table`` at a later point, as long as it's +available to the callable after all module initialization is complete:: class Parent(Base): __tablename__ = 'left' @@ -252,11 +272,12 @@ is accepted as well, matching the name of the table as stored in ``Base.metadata Deleting Rows from the Many to Many Table ^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ -A behavior which is unique to the :paramref:`_orm.relationship.secondary` argument to :func:`_orm.relationship` -is that the :class:`_schema.Table` which is specified here is automatically subject -to INSERT and DELETE statements, as objects are added or removed from the collection. -There is **no need to delete from this table manually**. The act of removing a -record from the collection will have the effect of the row being deleted on flush:: +A behavior which is unique to the :paramref:`_orm.relationship.secondary` +argument to :func:`_orm.relationship` is that the :class:`_schema.Table` which +is specified here is automatically subject to INSERT and DELETE statements, as +objects are added or removed from the collection. There is **no need to delete +from this table manually**. The act of removing a record from the collection +will have the effect of the row being deleted on flush:: # row will be deleted from the "secondary" table # automatically @@ -290,13 +311,20 @@ There are several possibilities here: directive on :func:`_orm.relationship`; see :ref:`passive_deletes` for more details on this. -Note again, these behaviors are *only* relevant to the :paramref:`_orm.relationship.secondary` option -used with :func:`_orm.relationship`. If dealing with association tables that -are mapped explicitly and are *not* present in the :paramref:`_orm.relationship.secondary` option -of a relevant :func:`_orm.relationship`, cascade rules can be used instead -to automatically delete entities in reaction to a related entity being +Note again, these behaviors are *only* relevant to the +:paramref:`_orm.relationship.secondary` option used with +:func:`_orm.relationship`. If dealing with association tables that are mapped +explicitly and are *not* present in the :paramref:`_orm.relationship.secondary` +option of a relevant :func:`_orm.relationship`, cascade rules can be used +instead to automatically delete entities in reaction to a related entity being deleted - see :ref:`unitofwork_cascades` for information on this feature. +.. seealso:: + + :ref:`cascade_delete_many_to_many` + + :ref:`passive_deletes_many_to_many` + .. _association_pattern: diff --git a/doc/build/orm/cascades.rst b/doc/build/orm/cascades.rst index d7cddc09c2..00fa32174d 100644 --- a/doc/build/orm/cascades.rst +++ b/doc/build/orm/cascades.rst @@ -137,7 +137,7 @@ with ``delete`` cascade configured:: class User(Base): # ... - addresses = relationship("Address", cascade="save-update, merge, delete") + addresses = relationship("Address", cascade="all, delete") If using the above mapping, we have a ``User`` object and two related ``Address`` objects:: @@ -183,23 +183,168 @@ deleted, but are instead de-associated: (1,) COMMIT -``delete`` cascade is more often than not used in conjunction with -:ref:`cascade_delete_orphan` cascade, which will emit a DELETE for the related -row if the "child" object is deassociated from the parent. The combination -of ``delete`` and ``delete-orphan`` cascade covers both situations where -SQLAlchemy has to decide between setting a foreign key column to NULL versus -deleting the row entirely. +:ref:`cascade_delete` cascade on one-to-many relationships is often combined +with :ref:`cascade_delete_orphan` cascade, which will emit a DELETE for the +related row if the "child" object is deassociated from the parent. The +combination of ``delete`` and ``delete-orphan`` cascade covers both +situations where SQLAlchemy has to decide between setting a foreign key +column to NULL versus deleting the row entirely. -.. topic:: ORM-level "delete" cascade vs. FOREIGN KEY level "ON DELETE" cascade +The feature by default works completely independently of database-configured +``FOREIGN KEY`` constraints that may themselves configure ``CASCADE`` behavior. +In order to integrate more efficiently with this configuration, additional +directives described at :ref:`passive_deletes` should be used. - The behavior of SQLAlchemy's "delete" cascade has a lot of overlap with the - ``ON DELETE CASCADE`` feature of a database foreign key, as well - as with that of the ``ON DELETE SET NULL`` foreign key setting when "delete" - cascade is not specified. Database level "ON DELETE" cascades are specific to the - "FOREIGN KEY" construct of the relational database; SQLAlchemy allows - configuration of these schema-level constructs at the :term:`DDL` level - using options on :class:`_schema.ForeignKeyConstraint` which are described - at :ref:`on_update_on_delete`. +.. seealso:: + + :ref:`passive_deletes` + + :ref:`cascade_delete_many_to_many` + + :ref:`cascade_delete_orphan` + +.. _cascade_delete_many_to_many: + +Using delete cascade with many-to-many relationships +^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ + +The ``cascade="all, delete"`` option works equally well with a many-to-many +relationship, one that uses :paramref:`_orm.relationship.secondary` to +indicate an association table. When a parent object is deleted, and therefore +de-associated with its related objects, the unit of work process will normally +delete rows from the association table, but leave the related objects intact. +When combined with ``cascade="all, delete"``, additional ``DELETE`` statements +will take place for the child rows themselves. + +The following example adapts that of :ref:`relationships_many_to_many` to +illustrate the ``cascade="all, delete"`` setting on **one** side of the +association:: + + association_table = Table('association', Base.metadata, + Column('left_id', Integer, ForeignKey('left.id')), + Column('right_id', Integer, ForeignKey('right.id')) + ) + + class Parent(Base): + __tablename__ = 'left' + id = Column(Integer, primary_key=True) + children = relationship( + "Child", + secondary=association_table, + back_populates="parents", + cascade="all, delete" + ) + + class Child(Base): + __tablename__ = 'right' + id = Column(Integer, primary_key=True) + parents = relationship( + "Parent", + secondary=association_table, + back_populates="children", + ) + +Above, when a ``Parent`` object is marked for deletion +using :meth:`_orm.Session.delete`, the flush process will as usual delete +the assocation rows from the ``association`` table, however per cascade +rules it will also delete all related ``Child`` rows. + + +.. warning:: + + If the above ``cascade="all, delete"`` setting were configured on **both** + relationships, then the cascade action would continue cascading through all + ``Parent`` and ``Child`` objects, loading each ``children`` and ``parents`` + collection encountered and deleting everything that's connected. It is + typically not desireable for "delete" cascade to be configured + bidirectionally. + +.. seealso:: + + :ref:`relationships_many_to_many_deletion` + + :ref:`passive_deletes_many_to_many` + +.. _passive_deletes: + +Using foreign key ON DELETE cascade with ORM relationships +^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ + +The behavior of SQLAlchemy's "delete" cascade overlaps with the +``ON DELETE`` feature of a database foreign key constraint. +Database level ``ON DELETE`` cascades are specific to the +"FOREIGN KEY" construct of the relational database; SQLAlchemy allows +configuration of these schema-level constructs at the :term:`DDL` level +using options on :class:`_schema.ForeignKeyConstraint` which are described +at :ref:`on_update_on_delete`. + +In order to use ``ON DELETE`` foreign key cascades that are configured in +the database itself, in conjunction with +:func:`_orm.relationship`, the :paramref:`_orm.relationship.cascade` setting +is still used, so that the ORM can distinguish between whether or not +related items should also be deleted when the parent row is deleted, or if +their foreign key columns should be set to NULL. There is then an additional +option controlled by the :paramref:`_orm.relationship.passive_deletes` +parameter which indicates the degree to which the ORM should try to run +DELETE/UPDATE operations on related rows itself, vs. how much it should rely +upon expecting the database-side FOREIGN KEY constraint cascade to handle +the task. + +The most typical example is that where child rows are to be deleted when +parent rows are deleted, and that ``ON DELETE CASCADE`` is configured +on the relevant ``FOREIGN KEY`` constraint as well:: + + + class Parent(Base): + __tablename__ = 'parent' + id = Column(Integer, primary_key=True) + children = relationship( + "Child", back_populates="parent", + cascade="all, delete", + passive_deletes=True + ) + + class Child(Base): + __tablename__ = 'child' + id = Column(Integer, primary_key=True) + parent_id = Column(Integer, ForeignKey('parent.id', ondelete="CASCADE")) + parent = relationship("Parent", back_populates="children") + +The behavior of the above configuration when a parent row is deleted +is as follows: + +1. The application calls ``session.delete(my_parent)``, where ``my_parent`` + is an instance of ``Parent``. + +2. When the :class:`_orm.Session` next flushes changes to the database, + all of the **currently loaded** items within the ``my_parent.children`` + collection are deleted by the ORM, meaning a ``DELETE`` statement is + emitted for each record. + +3. If the ``my_parent.children`` collection is **unloaded**, then no ``DELETE`` + statements are emitted. If the :paramref:`_orm.relationship.passive_deletes` + flag were **not** set on this :func:`_orm.relationship`, then a ``SELECT`` + statement for unloaded ``Child`` objects would have been emitted. + +4. A ``DELETE`` statement is then emitted for the ``my_parent`` row itself. + +5. The ``Parent`` instance referred to by ``my_parent``, as well as all + instances of ``Child`` that were related to this object and were + **loaded** (i.e. step 2 above took place), are de-associated from the + :class:`._orm.Session`. + +.. note:: + + To use "ON DELETE CASCADE", the underlying database engine must + support ``FOREIGN KEY`` constraints and they must be enforcing: + + * When using MySQL, an appropriate storage engine must be + selected. See :ref:`mysql_storage_engines` for details. + + * When using SQLite, foreign key support must be enabled explicitly. + See :ref:`sqlite_foreign_keys` for details. + +.. topic:: Notes on Passive Deletes It is important to note the differences between the ORM and the relational database's notion of "cascade" as well as how they integrate: @@ -225,16 +370,17 @@ deleting the row entirely. level. An attempt by SQLAlchemy to set the column to NULL will fail with a simple NOT NULL constraint exception. - * The other, more special case way is to set the :paramref:`_orm.relationship.passive_deletes` - flag to the string ``"all"``. This has the effect of entirely - disabling SQLAlchemy's behavior of setting the foreign key column - to NULL, and a DELETE will be emitted for the parent row without - any affect on the child row, even if the child row is present - in memory. This may be desirable in the case when - database-level foreign key triggers, either special ``ON DELETE`` settings - or otherwise, need to be activated in all cases when a parent row is deleted. - - * Database level ``ON DELETE`` cascade is **vastly more efficient** + * The other, more special case way is to set the + :paramref:`_orm.relationship.passive_deletes` flag to the string + ``"all"``. This has the effect of entirely disabling SQLAlchemy's + behavior of setting the foreign key column to NULL, and a DELETE will + be emitted for the parent row without any affect on the child row, + even if the child row is present in memory. This may be desirable in + the case when database-level foreign key triggers, either special + ``ON DELETE`` settings or otherwise, need to be activated in all + cases when a parent row is deleted. + + * Database level ``ON DELETE`` cascade is generally much more efficient than that of SQLAlchemy. The database can chain a series of cascade operations across many relationships at once; e.g. if row A is deleted, all the related rows in table B can be deleted, and all the C rows related @@ -265,16 +411,82 @@ deleting the row entirely. :paramref:`_orm.relationship.single_parent` flag should be used to establish an in-Python assertion for this case. +.. _passive_deletes_many_to_many: + +Using foreign key ON DELETE with many-to-many relationships +^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ + +As described at :ref:`cascade_delete_many_to_many`, "delete" cascade works +for many-to-many relationships as well. To make use of ``ON DELETE CASCADE`` +foreign keys in conjunction with many to many, ``FOREIGN KEY`` directives +are configured on the association table. These directives can handle +the task of automatically deleting from the association table, but cannot +accommodate the automatic deletion of the related objects themselves. + +In this case, the :paramref:`_orm.relationship.passive_deletes` directive can +save us some additional ``SELECT`` statements during a delete operation but +there are still some collections that the ORM will continue to load, in order +to locate affected child objects and handle them correctly. + +.. note:: + + Hypothetical optimizations to this could include a single ``DELETE`` + statement against all parent-associated rows of the association table at + once, then use ``RETURNING`` to locate affected related child rows, however + this is not currently part of the ORM unit of work implementation. + +In this configuration, we configure ``ON DELETE CASCADE`` on both foreign key +constraints of the association table. We configure ``cascade="all, delete"`` +on the parent->child side of the relationship, and we can then configure +``passive_deletes=True`` on the **other** side of the bidirectional +relationship as illustrated below:: + + association_table = Table('association', Base.metadata, + Column('left_id', Integer, ForeignKey('left.id', ondelete="CASCADE")), + Column('right_id', Integer, ForeignKey('right.id', ondelete="CASCADE")) + ) + + class Parent(Base): + __tablename__ = 'left' + id = Column(Integer, primary_key=True) + children = relationship( + "Child", + secondary=association_table, + back_populates="parents", + cascade="all, delete", + ) + + class Child(Base): + __tablename__ = 'right' + id = Column(Integer, primary_key=True) + parents = relationship( + "Parent", + secondary=association_table, + back_populates="children", + passive_deletes=True + ) + +Using the above configuration, the deletion of a ``Parent`` object proceeds +as follows: + +1. A ``Parent`` object is marked for deletion using + :meth:`_orm.Session.delete`. + +2. When the flush occurs, if the ``Parent.children`` collection is not loaded, + the ORM will first emit a SELECT statement in order to load the ``Child`` + objects that correspond to ``Parent.children``. + +3. It will then then emit ``DELETE`` statements for the rows in ``association`` + which correspond to that parent row. + +4. for each ``Child`` object affected by this immediate deletion, because + ``passive_deletes=True`` is configured, the unit of work will not need to + try to emit SELECT statements for each ``Child.parents`` collection as it + is assumed the corresponding rows in ``association`` will be deleted. + +5. ``DELETE`` statements are then emitted for each ``Child`` object that was + loaded from ``Parent.children``. -When using a :func:`_orm.relationship` that also includes a many-to-many -table using the :paramref:`_orm.relationship.secondary` option, SQLAlchemy's -delete cascade handles the rows in this many-to-many table automatically. -Just like, as described in :ref:`relationships_many_to_many_deletion`, -the addition or removal of an object from a many-to-many collection -results in the INSERT or DELETE of a row in the many-to-many table, -the ``delete`` cascade, when activated as the result of a parent object -delete operation, will DELETE not just the row in the "child" table but also -in the many-to-many table. .. _cascade_delete_orphan: diff --git a/doc/build/orm/collections.rst b/doc/build/orm/collections.rst index 78d29b82e7..22387efce3 100644 --- a/doc/build/orm/collections.rst +++ b/doc/build/orm/collections.rst @@ -145,47 +145,8 @@ loader option. Using Passive Deletes --------------------- -Use :paramref:`_orm.relationship.passive_deletes` to disable child object loading on a DELETE -operation, in conjunction with "ON DELETE (CASCADE|SET NULL)" on your database -to automatically cascade deletes to child objects:: +See :ref:`passive_deletes` for this section. - class MyClass(Base): - __tablename__ = 'mytable' - id = Column(Integer, primary_key=True) - children = relationship("MyOtherClass", - cascade="all, delete-orphan", - passive_deletes=True) - - class MyOtherClass(Base): - __tablename__ = 'myothertable' - id = Column(Integer, primary_key=True) - parent_id = Column(Integer, - ForeignKey('mytable.id', ondelete='CASCADE') - ) - - -.. note:: - - To use "ON DELETE CASCADE", the underlying database engine must - support foreign keys. - - * When using MySQL, an appropriate storage engine must be - selected. See :ref:`mysql_storage_engines` for details. - - * When using SQLite, foreign key support must be enabled explicitly. - See :ref:`sqlite_foreign_keys` for details. - -When :paramref:`_orm.relationship.passive_deletes` is applied, the ``children`` relationship will not be -loaded into memory when an instance of ``MyClass`` is marked for deletion. The -``cascade="all, delete-orphan"`` *will* take effect for instances of -``MyOtherClass`` which are currently present in the session; however for -instances of ``MyOtherClass`` which are not loaded, SQLAlchemy assumes that -"ON DELETE CASCADE" rules will ensure that those rows are deleted by the -database. - -.. seealso:: - - :paramref:`.orm.mapper.passive_deletes` - similar feature on :func:`.mapper` .. currentmodule:: sqlalchemy.orm.collections