fix: database unique constraints (#2594)

* fixed missing migration name

* added unique constraints to all m2m tables

* fixed bug trying to create duplicate tags

* added more unique constraints

* fixed duplicate seeder data

* updated tests

* fixed seed rollback error
This commit is contained in:
Michael Genson 2023-10-07 14:23:13 -05:00 committed by GitHub
parent 247a4de283
commit a98e863bca
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
13 changed files with 222 additions and 15 deletions

View File

@ -1,4 +1,4 @@
"""empty message
"""added normalized unit and food names
Revision ID: 0341b154f79a
Revises: bcfdad6b7355

View File

@ -0,0 +1,172 @@
"""added unique constraints
Revision ID: dded3119c1fe
Revises: 0341b154f79a
Create Date: 2023-10-04 14:29:26.688065
"""
from dataclasses import dataclass
from typing import Any
import sqlalchemy as sa
from sqlalchemy.orm import Session
import mealie.db.migration_types
from alembic import op
from mealie.db.models._model_base import SqlAlchemyBase
# revision identifiers, used by Alembic.
revision = "dded3119c1fe"
down_revision = "0341b154f79a"
branch_labels = None
depends_on = None
@dataclass
class TableMeta:
tablename: str
pk_1: str
pk_2: str
@classmethod
def composite_pk(self, pk_1_val: Any, pk_2_val: Any) -> str:
return "$$".join([pk_1_val, pk_2_val])
def _is_postgres():
return op.get_context().dialect.name == "postgresql"
def _remove_duplicates_from_m2m_table(session: Session, table_meta: TableMeta):
if _is_postgres():
default_pk = "CTID"
else:
default_pk = "ROWID"
# some of these tables are missing defined unique pks, so we have to rely on the database default pk
query = sa.text(
f"""
DELETE FROM {table_meta.tablename}
WHERE EXISTS (
SELECT 1 FROM {table_meta.tablename} t2
WHERE {table_meta.tablename}.{table_meta.pk_1} = t2.{table_meta.pk_1}
AND {table_meta.tablename}.{table_meta.pk_2} = t2.{table_meta.pk_2}
AND {table_meta.tablename}.{default_pk} > t2.{default_pk}
)
"""
)
session.execute(query)
session.commit()
def _remove_duplicates_from_m2m_tables(table_metas: list[TableMeta]):
bind = op.get_bind()
session = Session(bind=bind)
for table_meta in table_metas:
_remove_duplicates_from_m2m_table(session, table_meta)
def upgrade():
_remove_duplicates_from_m2m_tables(
[
# M2M
TableMeta("cookbooks_to_categories", "cookbook_id", "category_id"),
TableMeta("cookbooks_to_tags", "cookbook_id", "tag_id"),
TableMeta("cookbooks_to_tools", "cookbook_id", "tool_id"),
TableMeta("group_to_categories", "group_id", "category_id"),
TableMeta("plan_rules_to_categories", "group_plan_rule_id", "category_id"),
TableMeta("plan_rules_to_tags", "plan_rule_id", "tag_id"),
TableMeta("recipes_to_categories", "recipe_id", "category_id"),
TableMeta("recipes_to_tags", "recipe_id", "tag_id"),
TableMeta("recipes_to_tools", "recipe_id", "tool_id"),
TableMeta("users_to_favorites", "user_id", "recipe_id"),
TableMeta("shopping_lists_multi_purpose_labels", "shopping_list_id", "label_id"),
# Foods/Units/Labels
TableMeta("ingredient_foods", "name", "group_id"),
TableMeta("ingredient_units", "name", "group_id"),
TableMeta("multi_purpose_labels", "name", "group_id"),
]
)
# ### commands auto generated by Alembic - please adjust! ###
# we use batch_alter_table here because otherwise this fails on sqlite
# M2M
with op.batch_alter_table("cookbooks_to_categories") as batch_op:
batch_op.create_unique_constraint("cookbook_id_category_id_key", ["cookbook_id", "category_id"])
with op.batch_alter_table("cookbooks_to_tags") as batch_op:
batch_op.create_unique_constraint("cookbook_id_tag_id_key", ["cookbook_id", "tag_id"])
with op.batch_alter_table("cookbooks_to_tools") as batch_op:
batch_op.create_unique_constraint("cookbook_id_tool_id_key", ["cookbook_id", "tool_id"])
with op.batch_alter_table("group_to_categories") as batch_op:
batch_op.create_unique_constraint("group_id_category_id_key", ["group_id", "category_id"])
with op.batch_alter_table("plan_rules_to_categories") as batch_op:
batch_op.create_unique_constraint("group_plan_rule_id_category_id_key", ["group_plan_rule_id", "category_id"])
with op.batch_alter_table("plan_rules_to_tags") as batch_op:
batch_op.create_unique_constraint("plan_rule_id_tag_id_key", ["plan_rule_id", "tag_id"])
with op.batch_alter_table("recipes_to_categories") as batch_op:
batch_op.create_unique_constraint("recipe_id_category_id_key", ["recipe_id", "category_id"])
with op.batch_alter_table("recipes_to_tags") as batch_op:
batch_op.create_unique_constraint("recipe_id_tag_id_key", ["recipe_id", "tag_id"])
with op.batch_alter_table("recipes_to_tools") as batch_op:
batch_op.create_unique_constraint("recipe_id_tool_id_key", ["recipe_id", "tool_id"])
with op.batch_alter_table("users_to_favorites") as batch_op:
batch_op.create_unique_constraint("user_id_recipe_id_key", ["user_id", "recipe_id"])
with op.batch_alter_table("shopping_lists_multi_purpose_labels") as batch_op:
batch_op.create_unique_constraint("shopping_list_id_label_id_key", ["shopping_list_id", "label_id"])
# Foods/Units/Labels
with op.batch_alter_table("ingredient_foods") as batch_op:
batch_op.create_unique_constraint("ingredient_foods_name_group_id_key", ["name", "group_id"])
with op.batch_alter_table("ingredient_units") as batch_op:
batch_op.create_unique_constraint("ingredient_units_name_group_id_key", ["name", "group_id"])
with op.batch_alter_table("multi_purpose_labels") as batch_op:
batch_op.create_unique_constraint("multi_purpose_labels_name_group_id_key", ["name", "group_id"])
op.create_index(
op.f("ix_shopping_lists_multi_purpose_labels_created_at"),
"shopping_lists_multi_purpose_labels",
["created_at"],
unique=False,
)
# ### end Alembic commands ###
def downgrade():
# ### commands auto generated by Alembic - please adjust! ###
# M2M
op.drop_constraint("user_id_recipe_id_key", "users_to_favorites", type_="unique")
op.drop_index(
op.f("ix_shopping_lists_multi_purpose_labels_created_at"), table_name="shopping_lists_multi_purpose_labels"
)
op.drop_constraint("recipe_id_tool_id_key", "recipes_to_tools", type_="unique")
op.drop_constraint("recipe_id_tag_id_key", "recipes_to_tags", type_="unique")
op.drop_constraint("recipe_id_category_id_key", "recipes_to_categories", type_="unique")
op.drop_constraint("plan_rule_id_tag_id_key", "plan_rules_to_tags", type_="unique")
op.drop_constraint("group_plan_rule_id_category_id_key", "plan_rules_to_categories", type_="unique")
op.drop_constraint("group_id_category_id_key", "group_to_categories", type_="unique")
op.drop_constraint("cookbook_id_tool_id_key", "cookbooks_to_tools", type_="unique")
op.drop_constraint("cookbook_id_tag_id_key", "cookbooks_to_tags", type_="unique")
op.drop_constraint("cookbook_id_category_id_key", "cookbooks_to_categories", type_="unique")
op.drop_constraint("shopping_list_id_label_id_key", "shopping_lists_multi_purpose_labels", type_="unique")
# Foods/Units/Labels
op.drop_constraint("multi_purpose_labels_name_group_id_key", "multi_purpose_labels", type_="unique")
op.drop_constraint("ingredient_units_name_group_id_key", "ingredient_units", type_="unique")
op.drop_constraint("ingredient_foods_name_group_id_key", "ingredient_foods", type_="unique")
# ### end Alembic commands ###

View File

@ -1,6 +1,6 @@
from typing import TYPE_CHECKING, Optional
from sqlalchemy import Boolean, Float, ForeignKey, Integer, String, orm
from sqlalchemy import Boolean, Float, ForeignKey, Integer, String, UniqueConstraint, orm
from sqlalchemy.ext.orderinglist import ordering_list
from sqlalchemy.orm import Mapped, mapped_column
@ -25,7 +25,7 @@ class ShoppingListItemRecipeReference(BaseMixins, SqlAlchemyBase):
recipe_id: Mapped[GUID | None] = mapped_column(GUID, ForeignKey("recipes.id"), index=True)
recipe: Mapped[Optional["RecipeModel"]] = orm.relationship("RecipeModel", back_populates="shopping_list_item_refs")
recipe_quantity: Mapped[float] = mapped_column(Float, nullable=False)
recipe_scale: Mapped[float | None] = mapped_column(Float, default=1)
recipe_scale: Mapped[float] = mapped_column(Float, default=1)
recipe_note: Mapped[str | None] = mapped_column(String)
@auto_init()
@ -102,6 +102,7 @@ class ShoppingListRecipeReference(BaseMixins, SqlAlchemyBase):
class ShoppingListMultiPurposeLabel(SqlAlchemyBase, BaseMixins):
__tablename__ = "shopping_lists_multi_purpose_labels"
__table_args__ = (UniqueConstraint("shopping_list_id", "label_id", name="shopping_list_id_label_id_key"),)
id: Mapped[GUID] = mapped_column(GUID, primary_key=True, default=GUID.generate)
shopping_list_id: Mapped[GUID] = mapped_column(GUID, ForeignKey("shopping_lists.id"), primary_key=True)

View File

@ -1,6 +1,6 @@
from typing import TYPE_CHECKING
from sqlalchemy import ForeignKey, String, orm
from sqlalchemy import ForeignKey, String, UniqueConstraint, orm
from sqlalchemy.orm import Mapped, mapped_column
from mealie.db.models._model_base import BaseMixins, SqlAlchemyBase
@ -16,6 +16,8 @@ if TYPE_CHECKING:
class MultiPurposeLabel(SqlAlchemyBase, BaseMixins):
__tablename__ = "multi_purpose_labels"
__table_args__ = (UniqueConstraint("name", "group_id", name="multi_purpose_labels_name_group_id_key"),)
id: Mapped[GUID] = mapped_column(GUID, default=GUID.generate, primary_key=True)
name: Mapped[str] = mapped_column(String(255), nullable=False)
color: Mapped[str] = mapped_column(String(10), nullable=False, default="")

View File

@ -21,6 +21,7 @@ group_to_categories = sa.Table(
SqlAlchemyBase.metadata,
sa.Column("group_id", GUID, sa.ForeignKey("groups.id"), index=True),
sa.Column("category_id", GUID, sa.ForeignKey("categories.id"), index=True),
sa.UniqueConstraint("group_id", "category_id", name="group_id_category_id_key"),
)
plan_rules_to_categories = sa.Table(
@ -28,6 +29,7 @@ plan_rules_to_categories = sa.Table(
SqlAlchemyBase.metadata,
sa.Column("group_plan_rule_id", GUID, sa.ForeignKey("group_meal_plan_rules.id"), index=True),
sa.Column("category_id", GUID, sa.ForeignKey("categories.id"), index=True),
sa.UniqueConstraint("group_plan_rule_id", "category_id", name="group_plan_rule_id_category_id_key"),
)
recipes_to_categories = sa.Table(
@ -35,6 +37,7 @@ recipes_to_categories = sa.Table(
SqlAlchemyBase.metadata,
sa.Column("recipe_id", GUID, sa.ForeignKey("recipes.id"), index=True),
sa.Column("category_id", GUID, sa.ForeignKey("categories.id"), index=True),
sa.UniqueConstraint("recipe_id", "category_id", name="recipe_id_category_id_key"),
)
cookbooks_to_categories = sa.Table(
@ -42,6 +45,7 @@ cookbooks_to_categories = sa.Table(
SqlAlchemyBase.metadata,
sa.Column("cookbook_id", GUID, sa.ForeignKey("cookbooks.id"), index=True),
sa.Column("category_id", GUID, sa.ForeignKey("categories.id"), index=True),
sa.UniqueConstraint("cookbook_id", "category_id", name="cookbook_id_category_id_key"),
)

View File

@ -46,6 +46,7 @@ class IngredientUnitModel(SqlAlchemyBase, BaseMixins):
self.abbreviation = self.normalize(abbreviation)
tableargs = [
sa.UniqueConstraint("name", "group_id", name="ingredient_units_name_group_id_key"),
sa.Index(
"ix_ingredient_units_name_normalized",
"name_normalized",
@ -113,6 +114,7 @@ class IngredientFoodModel(SqlAlchemyBase, BaseMixins):
self.name_normalized = self.normalize(name)
tableargs = [
sa.UniqueConstraint("name", "group_id", name="ingredient_foods_name_group_id_key"),
sa.Index(
"ix_ingredient_foods_name_normalized",
"name_normalized",

View File

@ -21,6 +21,7 @@ recipes_to_tags = sa.Table(
SqlAlchemyBase.metadata,
sa.Column("recipe_id", guid.GUID, sa.ForeignKey("recipes.id"), index=True),
sa.Column("tag_id", guid.GUID, sa.ForeignKey("tags.id"), index=True),
sa.UniqueConstraint("recipe_id", "tag_id", name="recipe_id_tag_id_key"),
)
plan_rules_to_tags = sa.Table(
@ -28,6 +29,7 @@ plan_rules_to_tags = sa.Table(
SqlAlchemyBase.metadata,
sa.Column("plan_rule_id", guid.GUID, sa.ForeignKey("group_meal_plan_rules.id"), index=True),
sa.Column("tag_id", guid.GUID, sa.ForeignKey("tags.id"), index=True),
sa.UniqueConstraint("plan_rule_id", "tag_id", name="plan_rule_id_tag_id_key"),
)
cookbooks_to_tags = sa.Table(
@ -35,6 +37,7 @@ cookbooks_to_tags = sa.Table(
SqlAlchemyBase.metadata,
sa.Column("cookbook_id", guid.GUID, sa.ForeignKey("cookbooks.id"), index=True),
sa.Column("tag_id", guid.GUID, sa.ForeignKey("tags.id"), index=True),
sa.UniqueConstraint("cookbook_id", "tag_id", name="cookbook_id_tag_id_key"),
)

View File

@ -17,6 +17,7 @@ recipes_to_tools = Table(
SqlAlchemyBase.metadata,
Column("recipe_id", GUID, ForeignKey("recipes.id"), index=True),
Column("tool_id", GUID, ForeignKey("tools.id"), index=True),
UniqueConstraint("recipe_id", "tool_id", name="recipe_id_tool_id_key"),
)
cookbooks_to_tools = Table(
@ -24,6 +25,7 @@ cookbooks_to_tools = Table(
SqlAlchemyBase.metadata,
Column("cookbook_id", GUID, ForeignKey("cookbooks.id"), index=True),
Column("tool_id", GUID, ForeignKey("tools.id"), index=True),
UniqueConstraint("cookbook_id", "tool_id", name="cookbook_id_tool_id_key"),
)

View File

@ -1,4 +1,4 @@
from sqlalchemy import Column, ForeignKey, Table
from sqlalchemy import Column, ForeignKey, Table, UniqueConstraint
from .._model_base import SqlAlchemyBase
from .._model_utils import GUID
@ -8,4 +8,5 @@ users_to_favorites = Table(
SqlAlchemyBase.metadata,
Column("user_id", GUID, ForeignKey("users.id"), index=True),
Column("recipe_id", GUID, ForeignKey("recipes.id"), index=True),
UniqueConstraint("user_id", "recipe_id", name="user_id_recipe_id_key"),
)

View File

@ -164,10 +164,15 @@ class RepositoryGeneric(Generic[Schema, Model]):
return eff_schema.from_orm(result)
def create(self, data: Schema | BaseModel | dict) -> Schema:
data = data if isinstance(data, dict) else data.dict()
new_document = self.model(session=self.session, **data)
self.session.add(new_document)
self.session.commit()
try:
data = data if isinstance(data, dict) else data.dict()
new_document = self.model(session=self.session, **data)
self.session.add(new_document)
self.session.commit()
except Exception:
self.session.rollback()
raise
self.session.refresh(new_document)
return self.schema.from_orm(new_document)

View File

@ -4,10 +4,7 @@ from collections.abc import Generator
from functools import cached_property
from mealie.schema.labels import MultiPurposeLabelSave
from mealie.schema.recipe.recipe_ingredient import (
SaveIngredientFood,
SaveIngredientUnit,
)
from mealie.schema.recipe.recipe_ingredient import SaveIngredientFood, SaveIngredientUnit
from mealie.services.group_services.labels_service import MultiPurposeLabelService
from ._abstract_seeder import AbstractSeeder
@ -26,7 +23,12 @@ class MultiPurposeLabelSeeder(AbstractSeeder):
def load_data(self, locale: str | None = None) -> Generator[MultiPurposeLabelSave, None, None]:
file = self.get_file(locale)
seen_label_names = set()
for label in json.loads(file.read_text(encoding="utf-8")):
if label["name"] in seen_label_names:
continue
seen_label_names.add(label["name"])
yield MultiPurposeLabelSave(
name=label["name"],
group_id=self.group_id,
@ -49,7 +51,12 @@ class IngredientUnitsSeeder(AbstractSeeder):
def load_data(self, locale: str | None = None) -> Generator[SaveIngredientUnit, None, None]:
file = self.get_file(locale)
seen_unit_names = set()
for unit in json.loads(file.read_text(encoding="utf-8")).values():
if unit["name"] in seen_unit_names:
continue
seen_unit_names.add(unit["name"])
yield SaveIngredientUnit(
group_id=self.group_id,
name=unit["name"],
@ -75,7 +82,7 @@ class IngredientFoodsSeeder(AbstractSeeder):
file = self.get_file(locale)
seed_foods: dict[str, str] = json.loads(file.read_text(encoding="utf-8"))
for food in seed_foods.values():
for food in set(seed_foods.values()):
yield SaveIngredientFood(
group_id=self.group_id,
name=food,

View File

@ -33,8 +33,13 @@ class ScrapedExtras:
repo = ctx.repos.tags.by_group(ctx.group_id)
tags = []
seen_tag_slugs: set[str] = set()
for tag in self._tags:
slugify_tag = slugify(tag)
if slugify_tag in seen_tag_slugs:
continue
seen_tag_slugs.add(slugify_tag)
# Check if tag exists
if db_tag := repo.get_one(slugify_tag, "slug"):

View File

@ -656,7 +656,10 @@ def test_pagination_order_by_nested_model(
alphabet = ["a", "b", "c", "d", "e"]
labels = database.group_multi_purpose_labels.create_many(
[MultiPurposeLabelSave(group_id=unique_user.group_id, name=letter) for letter in alphabet]
[
MultiPurposeLabelSave(group_id=unique_user.group_id, name=letter + f"_{random_string()}")
for letter in alphabet
]
)
random.shuffle(labels)