|
| 1 | +"""migrate favorites and ratings to user_ratings |
| 2 | +
|
| 3 | +Revision ID: d7c6efd2de42 |
| 4 | +Revises: 09aba125b57a |
| 5 | +Create Date: 2024-03-18 02:28:15.896959 |
| 6 | +
|
| 7 | +""" |
| 8 | + |
| 9 | +from datetime import datetime |
| 10 | +from textwrap import dedent |
| 11 | +from typing import Any |
| 12 | +from uuid import uuid4 |
| 13 | + |
| 14 | +import sqlalchemy as sa |
| 15 | +from sqlalchemy import orm |
| 16 | + |
| 17 | +import mealie.db.migration_types |
| 18 | +from alembic import op |
| 19 | + |
| 20 | +# revision identifiers, used by Alembic. |
| 21 | +revision = "d7c6efd2de42" |
| 22 | +down_revision = "09aba125b57a" |
| 23 | +branch_labels = None |
| 24 | +depends_on = None |
| 25 | + |
| 26 | + |
| 27 | +def is_postgres(): |
| 28 | + return op.get_context().dialect.name == "postgresql" |
| 29 | + |
| 30 | + |
| 31 | +def new_user_rating(user_id: Any, recipe_id: Any, rating: float | None = None, is_favorite: bool = False): |
| 32 | + if is_postgres(): |
| 33 | + id = str(uuid4()) |
| 34 | + else: |
| 35 | + id = "%.32x" % uuid4().int |
| 36 | + |
| 37 | + now = datetime.now().isoformat() |
| 38 | + return { |
| 39 | + "id": id, |
| 40 | + "user_id": user_id, |
| 41 | + "recipe_id": recipe_id, |
| 42 | + "rating": rating, |
| 43 | + "is_favorite": is_favorite, |
| 44 | + "created_at": now, |
| 45 | + "update_at": now, |
| 46 | + } |
| 47 | + |
| 48 | + |
| 49 | +def migrate_user_favorites_to_user_ratings(): |
| 50 | + bind = op.get_bind() |
| 51 | + session = orm.Session(bind=bind) |
| 52 | + |
| 53 | + with session: |
| 54 | + user_ids_and_recipe_ids = session.execute(sa.text("SELECT user_id, recipe_id FROM users_to_favorites")).all() |
| 55 | + rows = [ |
| 56 | + new_user_rating(user_id, recipe_id, is_favorite=True) |
| 57 | + for user_id, recipe_id in user_ids_and_recipe_ids |
| 58 | + if user_id and recipe_id |
| 59 | + ] |
| 60 | + |
| 61 | + if is_postgres(): |
| 62 | + query = dedent( |
| 63 | + """ |
| 64 | + INSERT INTO users_to_recipes (id, user_id, recipe_id, rating, is_favorite, created_at, update_at) |
| 65 | + VALUES (:id, :user_id, :recipe_id, :rating, :is_favorite, :created_at, :update_at) |
| 66 | + ON CONFLICT DO NOTHING |
| 67 | + """ |
| 68 | + ) |
| 69 | + else: |
| 70 | + query = dedent( |
| 71 | + """ |
| 72 | + INSERT OR IGNORE INTO users_to_recipes |
| 73 | + (id, user_id, recipe_id, rating, is_favorite, created_at, update_at) |
| 74 | + VALUES (:id, :user_id, :recipe_id, :rating, :is_favorite, :created_at, :update_at) |
| 75 | + """ |
| 76 | + ) |
| 77 | + |
| 78 | + for row in rows: |
| 79 | + session.execute(sa.text(query), row) |
| 80 | + |
| 81 | + |
| 82 | +def migrate_group_to_user_ratings(group_id: Any): |
| 83 | + bind = op.get_bind() |
| 84 | + session = orm.Session(bind=bind) |
| 85 | + |
| 86 | + with session: |
| 87 | + user_ids = ( |
| 88 | + session.execute(sa.text("SELECT id FROM users WHERE group_id=:group_id").bindparams(group_id=group_id)) |
| 89 | + .scalars() |
| 90 | + .all() |
| 91 | + ) |
| 92 | + |
| 93 | + recipe_ids_ratings = session.execute( |
| 94 | + sa.text( |
| 95 | + "SELECT id, rating FROM recipes WHERE group_id=:group_id AND rating > 0 AND rating IS NOT NULL" |
| 96 | + ).bindparams(group_id=group_id) |
| 97 | + ).all() |
| 98 | + |
| 99 | + # Convert recipe ratings to user ratings. Since we don't know who |
| 100 | + # rated the recipe initially, we copy the rating to all users. |
| 101 | + rows: list[dict] = [] |
| 102 | + for recipe_id, rating in recipe_ids_ratings: |
| 103 | + for user_id in user_ids: |
| 104 | + rows.append(new_user_rating(user_id, recipe_id, rating, is_favorite=False)) |
| 105 | + |
| 106 | + if is_postgres(): |
| 107 | + insert_query = dedent( |
| 108 | + """ |
| 109 | + INSERT INTO users_to_recipes (id, user_id, recipe_id, rating, is_favorite, created_at, update_at) |
| 110 | + VALUES (:id, :user_id, :recipe_id, :rating, :is_favorite, :created_at, :update_at) |
| 111 | + ON CONFLICT (user_id, recipe_id) DO NOTHING; |
| 112 | + """ |
| 113 | + ) |
| 114 | + else: |
| 115 | + insert_query = dedent( |
| 116 | + """ |
| 117 | + INSERT OR IGNORE INTO users_to_recipes |
| 118 | + (id, user_id, recipe_id, rating, is_favorite, created_at, update_at) |
| 119 | + VALUES (:id, :user_id, :recipe_id, :rating, :is_favorite, :created_at, :update_at); |
| 120 | + """ |
| 121 | + ) |
| 122 | + |
| 123 | + update_query = dedent( |
| 124 | + """ |
| 125 | + UPDATE users_to_recipes |
| 126 | + SET rating = :rating, update_at = :update_at |
| 127 | + WHERE user_id = :user_id AND recipe_id = :recipe_id; |
| 128 | + """ |
| 129 | + ) |
| 130 | + |
| 131 | + # Create new user ratings with is_favorite set to False |
| 132 | + for row in rows: |
| 133 | + session.execute(sa.text(insert_query), row) |
| 134 | + |
| 135 | + # Update existing user ratings with the correct rating |
| 136 | + for row in rows: |
| 137 | + session.execute(sa.text(update_query), row) |
| 138 | + |
| 139 | + |
| 140 | +def migrate_to_user_ratings(): |
| 141 | + migrate_user_favorites_to_user_ratings() |
| 142 | + |
| 143 | + bind = op.get_bind() |
| 144 | + session = orm.Session(bind=bind) |
| 145 | + |
| 146 | + with session: |
| 147 | + group_ids = session.execute(sa.text("SELECT id FROM groups")).scalars().all() |
| 148 | + |
| 149 | + for group_id in group_ids: |
| 150 | + migrate_group_to_user_ratings(group_id) |
| 151 | + |
| 152 | + |
| 153 | +def upgrade(): |
| 154 | + # ### commands auto generated by Alembic - please adjust! ### |
| 155 | + op.create_table( |
| 156 | + "users_to_recipes", |
| 157 | + sa.Column("user_id", mealie.db.migration_types.GUID(), nullable=False), |
| 158 | + sa.Column("recipe_id", mealie.db.migration_types.GUID(), nullable=False), |
| 159 | + sa.Column("rating", sa.Float(), nullable=True), |
| 160 | + sa.Column("is_favorite", sa.Boolean(), nullable=False), |
| 161 | + sa.Column("id", mealie.db.migration_types.GUID(), nullable=False), |
| 162 | + sa.Column("created_at", sa.DateTime(), nullable=True), |
| 163 | + sa.Column("update_at", sa.DateTime(), nullable=True), |
| 164 | + sa.ForeignKeyConstraint( |
| 165 | + ["recipe_id"], |
| 166 | + ["recipes.id"], |
| 167 | + ), |
| 168 | + sa.ForeignKeyConstraint( |
| 169 | + ["user_id"], |
| 170 | + ["users.id"], |
| 171 | + ), |
| 172 | + sa.PrimaryKeyConstraint("user_id", "recipe_id", "id"), |
| 173 | + sa.UniqueConstraint("user_id", "recipe_id", name="user_id_recipe_id_rating_key"), |
| 174 | + ) |
| 175 | + op.create_index(op.f("ix_users_to_recipes_created_at"), "users_to_recipes", ["created_at"], unique=False) |
| 176 | + op.create_index(op.f("ix_users_to_recipes_is_favorite"), "users_to_recipes", ["is_favorite"], unique=False) |
| 177 | + op.create_index(op.f("ix_users_to_recipes_rating"), "users_to_recipes", ["rating"], unique=False) |
| 178 | + op.create_index(op.f("ix_users_to_recipes_recipe_id"), "users_to_recipes", ["recipe_id"], unique=False) |
| 179 | + op.create_index(op.f("ix_users_to_recipes_user_id"), "users_to_recipes", ["user_id"], unique=False) |
| 180 | + |
| 181 | + migrate_to_user_ratings() |
| 182 | + |
| 183 | + if is_postgres(): |
| 184 | + op.drop_index("ix_users_to_favorites_recipe_id", table_name="users_to_favorites") |
| 185 | + op.drop_index("ix_users_to_favorites_user_id", table_name="users_to_favorites") |
| 186 | + op.alter_column("recipes", "rating", existing_type=sa.INTEGER(), type_=sa.Float(), existing_nullable=True) |
| 187 | + else: |
| 188 | + op.execute("DROP INDEX IF EXISTS ix_users_to_favorites_recipe_id") |
| 189 | + op.execute("DROP INDEX IF EXISTS ix_users_to_favorites_user_id") |
| 190 | + with op.batch_alter_table("recipes") as batch_op: |
| 191 | + batch_op.alter_column("rating", existing_type=sa.INTEGER(), type_=sa.Float(), existing_nullable=True) |
| 192 | + |
| 193 | + op.drop_table("users_to_favorites") |
| 194 | + op.create_index(op.f("ix_recipes_rating"), "recipes", ["rating"], unique=False) |
| 195 | + # ### end Alembic commands ### |
| 196 | + |
| 197 | + |
| 198 | +def downgrade(): |
| 199 | + # ### commands auto generated by Alembic - please adjust! ### |
| 200 | + op.alter_column( |
| 201 | + "recipes_ingredients", "quantity", existing_type=sa.Float(), type_=sa.INTEGER(), existing_nullable=True |
| 202 | + ) |
| 203 | + op.drop_index(op.f("ix_recipes_rating"), table_name="recipes") |
| 204 | + op.alter_column("recipes", "rating", existing_type=sa.Float(), type_=sa.INTEGER(), existing_nullable=True) |
| 205 | + op.create_unique_constraint("ingredient_units_name_group_id_key", "ingredient_units", ["name", "group_id"]) |
| 206 | + op.create_unique_constraint("ingredient_foods_name_group_id_key", "ingredient_foods", ["name", "group_id"]) |
| 207 | + op.create_table( |
| 208 | + "users_to_favorites", |
| 209 | + sa.Column("user_id", sa.CHAR(length=32), nullable=True), |
| 210 | + sa.Column("recipe_id", sa.CHAR(length=32), nullable=True), |
| 211 | + sa.ForeignKeyConstraint( |
| 212 | + ["recipe_id"], |
| 213 | + ["recipes.id"], |
| 214 | + ), |
| 215 | + sa.ForeignKeyConstraint( |
| 216 | + ["user_id"], |
| 217 | + ["users.id"], |
| 218 | + ), |
| 219 | + sa.UniqueConstraint("user_id", "recipe_id", name="user_id_recipe_id_key"), |
| 220 | + ) |
| 221 | + op.create_index("ix_users_to_favorites_user_id", "users_to_favorites", ["user_id"], unique=False) |
| 222 | + op.create_index("ix_users_to_favorites_recipe_id", "users_to_favorites", ["recipe_id"], unique=False) |
| 223 | + op.drop_index(op.f("ix_users_to_recipes_user_id"), table_name="users_to_recipes") |
| 224 | + op.drop_index(op.f("ix_users_to_recipes_recipe_id"), table_name="users_to_recipes") |
| 225 | + op.drop_index(op.f("ix_users_to_recipes_rating"), table_name="users_to_recipes") |
| 226 | + op.drop_index(op.f("ix_users_to_recipes_is_favorite"), table_name="users_to_recipes") |
| 227 | + op.drop_index(op.f("ix_users_to_recipes_created_at"), table_name="users_to_recipes") |
| 228 | + op.drop_table("users_to_recipes") |
| 229 | + # ### end Alembic commands ### |
0 commit comments