|
| 1 | +# SPDX-License-Identifier: Apache-2.0 |
| 2 | +""" |
| 3 | +Data migration for UserUniqueLogin.ip_address_id |
| 4 | +
|
| 5 | +Revision ID: be443e514e3e |
| 6 | +Revises: df52c3746740 |
| 7 | +Create Date: 2025-12-02 17:32:29.770684 |
| 8 | +""" |
| 9 | + |
| 10 | + |
| 11 | +import os |
| 12 | + |
| 13 | +import sqlalchemy as sa |
| 14 | + |
| 15 | +from alembic import op |
| 16 | + |
| 17 | +revision = "be443e514e3e" |
| 18 | +down_revision = "df52c3746740" |
| 19 | + |
| 20 | + |
| 21 | +def _get_remaining_logins_to_update(conn): |
| 22 | + return conn.execute( |
| 23 | + sa.text("SELECT COUNT(*) FROM user_unique_logins WHERE ip_address_id IS NULL") |
| 24 | + ).scalar_one() |
| 25 | + |
| 26 | + |
| 27 | +def _get_remaining_ips_to_insert(conn): |
| 28 | + return conn.execute( |
| 29 | + sa.text( |
| 30 | + """ |
| 31 | +SELECT COUNT(DISTINCT user_unique_logins.ip_address) |
| 32 | +FROM user_unique_logins |
| 33 | +LEFT JOIN ip_addresses ON user_unique_logins.ip_address::inet = ip_addresses.ip_address |
| 34 | +WHERE ip_addresses.id IS NULL AND user_unique_logins.ip_address IS NOT NULL |
| 35 | +""" |
| 36 | + ) |
| 37 | + ).scalar_one() |
| 38 | + |
| 39 | + |
| 40 | +def upgrade(): |
| 41 | + op.execute("SET statement_timeout = 120000") |
| 42 | + op.execute("SET lock_timeout = 120000") |
| 43 | + |
| 44 | + op.create_index( |
| 45 | + "ix_user_unique_logins_ip_address_migration", |
| 46 | + "user_unique_logins", |
| 47 | + ["ip_address"], |
| 48 | + unique=False, |
| 49 | + if_not_exists=True, |
| 50 | + ) |
| 51 | + |
| 52 | + bind = op.get_bind() |
| 53 | + batch_size = 1000 |
| 54 | + salt = os.environ.get("WAREHOUSE_IP_SALT") |
| 55 | + |
| 56 | + while _get_remaining_ips_to_insert(bind) > 0: |
| 57 | + bind.execute( |
| 58 | + sa.text( |
| 59 | + f""" |
| 60 | +INSERT INTO ip_addresses (ip_address, hashed_ip_address) |
| 61 | +SELECT |
| 62 | + DISTINCT user_unique_logins.ip_address::inet, |
| 63 | + encode( |
| 64 | + digest( |
| 65 | + CONCAT(user_unique_logins.ip_address, '{salt}'), |
| 66 | + 'sha256' |
| 67 | + ), |
| 68 | + 'hex' |
| 69 | + ) |
| 70 | +FROM user_unique_logins |
| 71 | +LEFT JOIN ip_addresses ON user_unique_logins.ip_address::inet = ip_addresses.ip_address |
| 72 | +WHERE ip_addresses.id IS NULL AND user_unique_logins.ip_address IS NOT NULL |
| 73 | +LIMIT :batch_size |
| 74 | +""" |
| 75 | + ), |
| 76 | + {"batch_size": batch_size}, |
| 77 | + ) |
| 78 | + bind.commit() |
| 79 | + |
| 80 | + while _get_remaining_logins_to_update(bind) > 0: |
| 81 | + bind.execute( |
| 82 | + sa.text( |
| 83 | + """ |
| 84 | +UPDATE user_unique_logins |
| 85 | +SET ip_address_id = ip_addresses.id |
| 86 | +FROM ip_addresses |
| 87 | +WHERE |
| 88 | + user_unique_logins.ip_address::inet = ip_addresses.ip_address AND |
| 89 | + user_unique_logins.ip_address_id IS NULL AND |
| 90 | + user_unique_logins.id IN ( |
| 91 | + SELECT id |
| 92 | + FROM user_unique_logins |
| 93 | + WHERE ip_address_id IS NULL |
| 94 | + ORDER BY id |
| 95 | + LIMIT :batch_size |
| 96 | + ) |
| 97 | +""" |
| 98 | + ), |
| 99 | + {"batch_size": batch_size}, |
| 100 | + ) |
| 101 | + bind.commit() |
| 102 | + |
| 103 | + # Finally make the ip_address_id column non-nullable |
| 104 | + op.alter_column("user_unique_logins", "ip_address_id", nullable=False) |
| 105 | + |
| 106 | + op.drop_index( |
| 107 | + "ix_user_unique_logins_ip_address_migration", |
| 108 | + "user_unique_logins", |
| 109 | + if_exists=True, |
| 110 | + ) |
| 111 | + |
| 112 | + |
| 113 | +def downgrade(): |
| 114 | + op.alter_column("user_unique_logins", "ip_address_id", nullable=True) |
0 commit comments