|
| 1 | +use sea_orm_migration::prelude::*; |
| 2 | + |
| 3 | +#[derive(DeriveMigrationName)] |
| 4 | +pub struct Migration; |
| 5 | + |
| 6 | +#[async_trait::async_trait] |
| 7 | +#[allow(deprecated)] |
| 8 | +impl MigrationTrait for Migration { |
| 9 | + async fn up(&self, manager: &SchemaManager) -> Result<(), DbErr> { |
| 10 | + // Add generated columns for package_namespace and package_name |
| 11 | + // These columns split the package field to enable indexed lookups: |
| 12 | + // - package_namespace: NULL for packages without '/', otherwise the part before '/' |
| 13 | + // - package_name: the part after '/' if present, otherwise the entire package value |
| 14 | + // |
| 15 | + // Examples: |
| 16 | + // package = "lodash" -> namespace=NULL, name="lodash" |
| 17 | + // package = "npmjs/lodash" -> namespace="npmjs", name="lodash" |
| 18 | + // package = "@types/node" -> namespace="@types", name="node" |
| 19 | + // |
| 20 | + // This maintains compatibility with existing query patterns: |
| 21 | + // - Match on name only: WHERE package_namespace IS NULL AND package_name = ? |
| 22 | + // - Match on namespace/name: WHERE package_namespace = ? AND package_name = ? |
| 23 | + manager |
| 24 | + .get_connection() |
| 25 | + .execute_unprepared( |
| 26 | + "ALTER TABLE product_status \ |
| 27 | + ADD COLUMN IF NOT EXISTS package_namespace text GENERATED ALWAYS AS (\ |
| 28 | + CASE WHEN package LIKE '%/%' THEN split_part(package, '/', 1) ELSE NULL END\ |
| 29 | + ) STORED", |
| 30 | + ) |
| 31 | + .await?; |
| 32 | + |
| 33 | + manager |
| 34 | + .get_connection() |
| 35 | + .execute_unprepared( |
| 36 | + "ALTER TABLE product_status \ |
| 37 | + ADD COLUMN IF NOT EXISTS package_name text GENERATED ALWAYS AS (\ |
| 38 | + CASE WHEN package LIKE '%/%' THEN split_part(package, '/', 2) ELSE package END\ |
| 39 | + ) STORED", |
| 40 | + ) |
| 41 | + .await?; |
| 42 | + |
| 43 | + // Backfill existing rows with UPDATE to trigger recalculation of generated columns |
| 44 | + manager |
| 45 | + .get_connection() |
| 46 | + .execute_unprepared( |
| 47 | + "UPDATE product_status SET package = package WHERE package_namespace IS NULL OR package_name IS NULL", |
| 48 | + ) |
| 49 | + .await?; |
| 50 | + |
| 51 | + // CONCURRENTLY (not supported by SeaORM) to avoid blocking writes |
| 52 | + manager |
| 53 | + .get_connection() |
| 54 | + .execute_unprepared( |
| 55 | + "CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_product_status_package_lookup \ |
| 56 | + ON product_status (package_namespace, package_name)", |
| 57 | + ) |
| 58 | + .await?; |
| 59 | + |
| 60 | + Ok(()) |
| 61 | + } |
| 62 | + |
| 63 | + async fn down(&self, manager: &SchemaManager) -> Result<(), DbErr> { |
| 64 | + manager |
| 65 | + .get_connection() |
| 66 | + .execute_unprepared("DROP INDEX IF EXISTS idx_product_status_package_lookup") |
| 67 | + .await?; |
| 68 | + |
| 69 | + manager |
| 70 | + .get_connection() |
| 71 | + .execute_unprepared("ALTER TABLE product_status DROP COLUMN IF EXISTS package_name") |
| 72 | + .await?; |
| 73 | + |
| 74 | + manager |
| 75 | + .get_connection() |
| 76 | + .execute_unprepared( |
| 77 | + "ALTER TABLE product_status DROP COLUMN IF EXISTS package_namespace", |
| 78 | + ) |
| 79 | + .await?; |
| 80 | + |
| 81 | + Ok(()) |
| 82 | + } |
| 83 | +} |
0 commit comments