From 5e56da87e074f6178f8146683978f24f68586120 Mon Sep 17 00:00:00 2001 From: Marco Neumann Date: Tue, 13 Sep 2022 00:52:04 +0000 Subject: [PATCH] fix: ensure migration progress is not lost for PG, mysql and sqlite (#1991) * fix: ensure migration progress is not lost for PG Fixes #1966. * fix: ensure migration progress is not lost for sqlite This is similar to #1966. * fix: ensure reverse migration progress is not lost for PG See #1966. * fix: ensure reverse migration progress is not lost for sqlite See #1966. * fix: ensure migration progress is not lost for mysql This is similar to #1966. * fix: ensure reverse migration progress is not lost for mysql See #1966. * test: check migration type as well * test: extend migrations testing * fix: work around MySQL implicit commits * refactor: simplify migration testing --- Cargo.toml | 15 ++++ sqlx-core/src/migrate/migration_type.rs | 2 +- sqlx-core/src/mysql/migrate.rs | 85 ++++++++++++++++--- sqlx-core/src/postgres/migrate.rs | 43 +++++++--- sqlx-core/src/sqlite/migrate.rs | 43 +++++++--- tests/migrate/macro.rs | 21 +++-- .../migrations/20200723212833_tweet.sql | 6 -- .../migrations/20200723212841_accounts.sql | 5 -- .../20220721124650_add_table.down.sql | 1 + .../20220721124650_add_table.up.sql | 7 ++ .../20220721125033_modify_column.down.sql | 2 + .../20220721125033_modify_column.up.sql | 2 + .../20220721115250_add_test_table.sql | 7 ++ .../20220721115524_convert_type.sql | 34 ++++++++ tests/mysql/migrate.rs | 78 +++++++++++++++++ .../20220721124650_add_table.down.sql | 1 + .../20220721124650_add_table.up.sql | 7 ++ .../20220721125033_modify_column.down.sql | 2 + .../20220721125033_modify_column.up.sql | 2 + .../20220721115250_add_test_table.sql | 7 ++ .../20220721115524_convert_type.sql | 34 ++++++++ tests/postgres/migrate.rs | 78 +++++++++++++++++ .../20220721124650_add_table.down.sql | 1 + .../20220721124650_add_table.up.sql | 7 ++ .../20220721125033_modify_column.down.sql | 2 + .../20220721125033_modify_column.up.sql | 2 + .../20220721115250_add_test_table.sql | 7 ++ .../20220721115524_convert_type.sql | 34 ++++++++ tests/sqlite/migrate.rs | 78 +++++++++++++++++ .../20220721124650_add_table.down.sql | 1 + .../20220721124650_add_table.up.sql | 7 ++ .../20220721125033_modify_column.down.sql | 2 + .../20220721125033_modify_column.up.sql | 2 + .../20220721115250_add_test_table.sql | 7 ++ .../20220721115524_convert_type.sql | 30 +++++++ 35 files changed, 612 insertions(+), 50 deletions(-) delete mode 100644 tests/migrate/migrations/20200723212833_tweet.sql delete mode 100644 tests/migrate/migrations/20200723212841_accounts.sql create mode 100644 tests/migrate/migrations_reversible/20220721124650_add_table.down.sql create mode 100644 tests/migrate/migrations_reversible/20220721124650_add_table.up.sql create mode 100644 tests/migrate/migrations_reversible/20220721125033_modify_column.down.sql create mode 100644 tests/migrate/migrations_reversible/20220721125033_modify_column.up.sql create mode 100644 tests/migrate/migrations_simple/20220721115250_add_test_table.sql create mode 100644 tests/migrate/migrations_simple/20220721115524_convert_type.sql create mode 100644 tests/mysql/migrate.rs create mode 100644 tests/mysql/migrations_reversible/20220721124650_add_table.down.sql create mode 100644 tests/mysql/migrations_reversible/20220721124650_add_table.up.sql create mode 100644 tests/mysql/migrations_reversible/20220721125033_modify_column.down.sql create mode 100644 tests/mysql/migrations_reversible/20220721125033_modify_column.up.sql create mode 100644 tests/mysql/migrations_simple/20220721115250_add_test_table.sql create mode 100644 tests/mysql/migrations_simple/20220721115524_convert_type.sql create mode 100644 tests/postgres/migrate.rs create mode 100644 tests/postgres/migrations_reversible/20220721124650_add_table.down.sql create mode 100644 tests/postgres/migrations_reversible/20220721124650_add_table.up.sql create mode 100644 tests/postgres/migrations_reversible/20220721125033_modify_column.down.sql create mode 100644 tests/postgres/migrations_reversible/20220721125033_modify_column.up.sql create mode 100644 tests/postgres/migrations_simple/20220721115250_add_test_table.sql create mode 100644 tests/postgres/migrations_simple/20220721115524_convert_type.sql create mode 100644 tests/sqlite/migrate.rs create mode 100644 tests/sqlite/migrations_reversible/20220721124650_add_table.down.sql create mode 100644 tests/sqlite/migrations_reversible/20220721124650_add_table.up.sql create mode 100644 tests/sqlite/migrations_reversible/20220721125033_modify_column.down.sql create mode 100644 tests/sqlite/migrations_reversible/20220721125033_modify_column.up.sql create mode 100644 tests/sqlite/migrations_simple/20220721115250_add_test_table.sql create mode 100644 tests/sqlite/migrations_simple/20220721115524_convert_type.sql diff --git a/Cargo.toml b/Cargo.toml index 41d05245c6..8ea9cafe60 100644 --- a/Cargo.toml +++ b/Cargo.toml @@ -212,6 +212,11 @@ name = "sqlite-test-attr" path = "tests/sqlite/test-attr.rs" required-features = ["sqlite", "macros", "migrate"] +[[test]] +name = "sqlite-migrate" +path = "tests/sqlite/migrate.rs" +required-features = ["sqlite", "macros", "migrate"] + # # MySQL # @@ -241,6 +246,11 @@ name = "mysql-test-attr" path = "tests/mysql/test-attr.rs" required-features = ["mysql", "macros", "migrate"] +[[test]] +name = "mysql-migrate" +path = "tests/mysql/migrate.rs" +required-features = ["mysql", "macros", "migrate"] + # # PostgreSQL # @@ -275,6 +285,11 @@ name = "postgres-test-attr" path = "tests/postgres/test-attr.rs" required-features = ["postgres", "macros", "migrate"] +[[test]] +name = "postgres-migrate" +path = "tests/postgres/migrate.rs" +required-features = ["postgres", "macros", "migrate"] + # # Microsoft SQL Server (MSSQL) # diff --git a/sqlx-core/src/migrate/migration_type.rs b/sqlx-core/src/migrate/migration_type.rs index edabdbed5d..87feedfa2b 100644 --- a/sqlx-core/src/migrate/migration_type.rs +++ b/sqlx-core/src/migrate/migration_type.rs @@ -1,5 +1,5 @@ /// Migration Type represents the type of migration -#[derive(Debug, Copy, Clone)] +#[derive(Debug, Copy, Clone, PartialEq)] pub enum MigrationType { /// Simple migration are single file migrations with no up / down queries Simple, diff --git a/sqlx-core/src/mysql/migrate.rs b/sqlx-core/src/mysql/migrate.rs index 800d7408dc..d17fbfb59c 100644 --- a/sqlx-core/src/mysql/migrate.rs +++ b/sqlx-core/src/mysql/migrate.rs @@ -1,4 +1,4 @@ -use crate::connection::ConnectOptions; +use crate::connection::{ConnectOptions, Connection}; use crate::error::Error; use crate::executor::Executor; use crate::migrate::MigrateError; @@ -209,29 +209,67 @@ CREATE TABLE IF NOT EXISTS _sqlx_migrations ( migration: &'m Migration, ) -> BoxFuture<'m, Result> { Box::pin(async move { + // Use a single transaction for the actual migration script and the essential bookeeping so we never + // execute migrations twice. See https://github.com/launchbadge/sqlx/issues/1966. + // The `execution_time` however can only be measured for the whole transaction. This value _only_ exists for + // data lineage and debugging reasons, so it is not super important if it is lost. So we initialize it to -1 + // and update it once the actual transaction completed. + let mut tx = self.begin().await?; let start = Instant::now(); - let res = self.execute(&*migration.sql).await; - - let elapsed = start.elapsed(); - + // For MySQL we cannot really isolate migrations due to implicit commits caused by table modification, see + // https://dev.mysql.com/doc/refman/8.0/en/implicit-commit.html + // + // To somewhat try to detect this, we first insert the migration into the migration table with + // `success=FALSE` and later modify the flag. + // // language=MySQL let _ = query( r#" INSERT INTO _sqlx_migrations ( version, description, success, checksum, execution_time ) - VALUES ( ?, ?, ?, ?, ? ) + VALUES ( ?, ?, FALSE, ?, -1 ) "#, ) .bind(migration.version) .bind(&*migration.description) - .bind(res.is_ok()) .bind(&*migration.checksum) + .execute(&mut tx) + .await?; + + let _ = tx.execute(&*migration.sql).await?; + + // language=MySQL + let _ = query( + r#" + UPDATE _sqlx_migrations + SET success = TRUE + WHERE version = ? + "#, + ) + .bind(migration.version) + .execute(&mut tx) + .await?; + + tx.commit().await?; + + // Update `elapsed_time`. + // NOTE: The process may disconnect/die at this point, so the elapsed time value might be lost. We accept + // this small risk since this value is not super important. + + let elapsed = start.elapsed(); + + let _ = query( + r#" + UPDATE _sqlx_migrations + SET execution_time = ? + WHERE version = ? + "#, + ) .bind(elapsed.as_nanos() as i64) + .bind(migration.version) .execute(self) .await?; - res?; - Ok(elapsed) }) } @@ -241,18 +279,41 @@ CREATE TABLE IF NOT EXISTS _sqlx_migrations ( migration: &'m Migration, ) -> BoxFuture<'m, Result> { Box::pin(async move { + // Use a single transaction for the actual migration script and the essential bookeeping so we never + // execute migrations twice. See https://github.com/launchbadge/sqlx/issues/1966. + let mut tx = self.begin().await?; let start = Instant::now(); - self.execute(&*migration.sql).await?; + // For MySQL we cannot really isolate migrations due to implicit commits caused by table modification, see + // https://dev.mysql.com/doc/refman/8.0/en/implicit-commit.html + // + // To somewhat try to detect this, we first insert the migration into the migration table with + // `success=FALSE` and later remove the migration altogether. + // + // language=MySQL + let _ = query( + r#" + UPDATE _sqlx_migrations + SET success = FALSE + WHERE version = ? + "#, + ) + .bind(migration.version) + .execute(&mut tx) + .await?; - let elapsed = start.elapsed(); + tx.execute(&*migration.sql).await?; // language=SQL let _ = query(r#"DELETE FROM _sqlx_migrations WHERE version = ?"#) .bind(migration.version) - .execute(self) + .execute(&mut tx) .await?; + tx.commit().await?; + + let elapsed = start.elapsed(); + Ok(elapsed) }) } diff --git a/sqlx-core/src/postgres/migrate.rs b/sqlx-core/src/postgres/migrate.rs index 71084e72f7..183b193b51 100644 --- a/sqlx-core/src/postgres/migrate.rs +++ b/sqlx-core/src/postgres/migrate.rs @@ -222,23 +222,44 @@ CREATE TABLE IF NOT EXISTS _sqlx_migrations ( let mut tx = self.begin().await?; let start = Instant::now(); + // Use a single transaction for the actual migration script and the essential bookeeping so we never + // execute migrations twice. See https://github.com/launchbadge/sqlx/issues/1966. + // The `execution_time` however can only be measured for the whole transaction. This value _only_ exists for + // data lineage and debugging reasons, so it is not super important if it is lost. So we initialize it to -1 + // and update it once the actual transaction completed. let _ = tx.execute(&*migration.sql).await?; - tx.commit().await?; - - let elapsed = start.elapsed(); - // language=SQL let _ = query( r#" INSERT INTO _sqlx_migrations ( version, description, success, checksum, execution_time ) - VALUES ( $1, $2, TRUE, $3, $4 ) + VALUES ( $1, $2, TRUE, $3, -1 ) "#, ) .bind(migration.version) .bind(&*migration.description) .bind(&*migration.checksum) + .execute(&mut tx) + .await?; + + tx.commit().await?; + + // Update `elapsed_time`. + // NOTE: The process may disconnect/die at this point, so the elapsed time value might be lost. We accept + // this small risk since this value is not super important. + + let elapsed = start.elapsed(); + + // language=SQL + let _ = query( + r#" + UPDATE _sqlx_migrations + SET execution_time = $1 + WHERE version = $2 + "#, + ) .bind(elapsed.as_nanos() as i64) + .bind(migration.version) .execute(self) .await?; @@ -251,21 +272,23 @@ CREATE TABLE IF NOT EXISTS _sqlx_migrations ( migration: &'m Migration, ) -> BoxFuture<'m, Result> { Box::pin(async move { + // Use a single transaction for the actual migration script and the essential bookeeping so we never + // execute migrations twice. See https://github.com/launchbadge/sqlx/issues/1966. let mut tx = self.begin().await?; let start = Instant::now(); let _ = tx.execute(&*migration.sql).await?; - tx.commit().await?; - - let elapsed = start.elapsed(); - // language=SQL let _ = query(r#"DELETE FROM _sqlx_migrations WHERE version = $1"#) .bind(migration.version) - .execute(self) + .execute(&mut tx) .await?; + tx.commit().await?; + + let elapsed = start.elapsed(); + Ok(elapsed) }) } diff --git a/sqlx-core/src/sqlite/migrate.rs b/sqlx-core/src/sqlite/migrate.rs index d8f18e57e1..c07f6c8164 100644 --- a/sqlx-core/src/sqlite/migrate.rs +++ b/sqlx-core/src/sqlite/migrate.rs @@ -173,23 +173,44 @@ CREATE TABLE IF NOT EXISTS _sqlx_migrations ( let mut tx = self.begin().await?; let start = Instant::now(); + // Use a single transaction for the actual migration script and the essential bookeeping so we never + // execute migrations twice. See https://github.com/launchbadge/sqlx/issues/1966. + // The `execution_time` however can only be measured for the whole transaction. This value _only_ exists for + // data lineage and debugging reasons, so it is not super important if it is lost. So we initialize it to -1 + // and update it once the actual transaction completed. let _ = tx.execute(&*migration.sql).await?; - tx.commit().await?; - - let elapsed = start.elapsed(); - // language=SQL let _ = query( r#" INSERT INTO _sqlx_migrations ( version, description, success, checksum, execution_time ) - VALUES ( ?1, ?2, TRUE, ?3, ?4 ) + VALUES ( ?1, ?2, TRUE, ?3, -1 ) "#, ) .bind(migration.version) .bind(&*migration.description) .bind(&*migration.checksum) + .execute(&mut tx) + .await?; + + tx.commit().await?; + + // Update `elapsed_time`. + // NOTE: The process may disconnect/die at this point, so the elapsed time value might be lost. We accept + // this small risk since this value is not super important. + + let elapsed = start.elapsed(); + + // language=SQL + let _ = query( + r#" + UPDATE _sqlx_migrations + SET execution_time = ?1 + WHERE version = ?2 + "#, + ) .bind(elapsed.as_nanos() as i64) + .bind(migration.version) .execute(self) .await?; @@ -202,21 +223,23 @@ CREATE TABLE IF NOT EXISTS _sqlx_migrations ( migration: &'m Migration, ) -> BoxFuture<'m, Result> { Box::pin(async move { + // Use a single transaction for the actual migration script and the essential bookeeping so we never + // execute migrations twice. See https://github.com/launchbadge/sqlx/issues/1966. let mut tx = self.begin().await?; let start = Instant::now(); let _ = tx.execute(&*migration.sql).await?; - tx.commit().await?; - - let elapsed = start.elapsed(); - // language=SQL let _ = query(r#"DELETE FROM _sqlx_migrations WHERE version = ?1"#) .bind(migration.version) - .execute(self) + .execute(&mut tx) .await?; + tx.commit().await?; + + let elapsed = start.elapsed(); + Ok(elapsed) }) } diff --git a/tests/migrate/macro.rs b/tests/migrate/macro.rs index 7215046bef..da7f901996 100644 --- a/tests/migrate/macro.rs +++ b/tests/migrate/macro.rs @@ -1,20 +1,29 @@ use sqlx::migrate::Migrator; use std::path::Path; -static EMBEDDED: Migrator = sqlx::migrate!("tests/migrate/migrations"); +static EMBEDDED_SIMPLE: Migrator = sqlx::migrate!("tests/migrate/migrations_simple"); +static EMBEDDED_REVERSIBLE: Migrator = sqlx::migrate!("tests/migrate/migrations_reversible"); #[sqlx_macros::test] async fn same_output() -> anyhow::Result<()> { - let runtime = Migrator::new(Path::new("tests/migrate/migrations")).await?; + let runtime_simple = Migrator::new(Path::new("tests/migrate/migrations_simple")).await?; + let runtime_reversible = + Migrator::new(Path::new("tests/migrate/migrations_reversible")).await?; - assert_eq!(runtime.migrations.len(), EMBEDDED.migrations.len()); + assert_same(&EMBEDDED_SIMPLE, &runtime_simple); + assert_same(&EMBEDDED_REVERSIBLE, &runtime_reversible); - for (e, r) in EMBEDDED.iter().zip(runtime.iter()) { + Ok(()) +} + +fn assert_same(embedded: &Migrator, runtime: &Migrator) { + assert_eq!(runtime.migrations.len(), embedded.migrations.len()); + + for (e, r) in embedded.iter().zip(runtime.iter()) { assert_eq!(e.version, r.version); assert_eq!(e.description, r.description); + assert_eq!(e.migration_type, r.migration_type); assert_eq!(e.sql, r.sql); assert_eq!(e.checksum, r.checksum); } - - Ok(()) } diff --git a/tests/migrate/migrations/20200723212833_tweet.sql b/tests/migrate/migrations/20200723212833_tweet.sql deleted file mode 100644 index 45c09606c4..0000000000 --- a/tests/migrate/migrations/20200723212833_tweet.sql +++ /dev/null @@ -1,6 +0,0 @@ -CREATE TABLE tweet ( - id BIGINT NOT NULL PRIMARY KEY, - text TEXT NOT NULL, - is_sent BOOLEAN NOT NULL DEFAULT TRUE, - owner_id BIGINT -); diff --git a/tests/migrate/migrations/20200723212841_accounts.sql b/tests/migrate/migrations/20200723212841_accounts.sql deleted file mode 100644 index f2c0a73929..0000000000 --- a/tests/migrate/migrations/20200723212841_accounts.sql +++ /dev/null @@ -1,5 +0,0 @@ -CREATE TABLE accounts ( - id INTEGER NOT NULL PRIMARY KEY, - name TEXT NOT NULL, - is_active BOOLEAN -); diff --git a/tests/migrate/migrations_reversible/20220721124650_add_table.down.sql b/tests/migrate/migrations_reversible/20220721124650_add_table.down.sql new file mode 100644 index 0000000000..5505859725 --- /dev/null +++ b/tests/migrate/migrations_reversible/20220721124650_add_table.down.sql @@ -0,0 +1 @@ +DROP TABLE migrations_reversible_test; diff --git a/tests/migrate/migrations_reversible/20220721124650_add_table.up.sql b/tests/migrate/migrations_reversible/20220721124650_add_table.up.sql new file mode 100644 index 0000000000..9dfc757954 --- /dev/null +++ b/tests/migrate/migrations_reversible/20220721124650_add_table.up.sql @@ -0,0 +1,7 @@ +CREATE TABLE migrations_reversible_test ( + some_id BIGINT NOT NULL PRIMARY KEY, + some_payload BIGINT NOT NUll +); + +INSERT INTO migrations_reversible_test (some_id, some_payload) +VALUES (1, 100); diff --git a/tests/migrate/migrations_reversible/20220721125033_modify_column.down.sql b/tests/migrate/migrations_reversible/20220721125033_modify_column.down.sql new file mode 100644 index 0000000000..3f71737b8c --- /dev/null +++ b/tests/migrate/migrations_reversible/20220721125033_modify_column.down.sql @@ -0,0 +1,2 @@ +UPDATE migrations_reversible_test +SET some_payload = some_payload - 1; diff --git a/tests/migrate/migrations_reversible/20220721125033_modify_column.up.sql b/tests/migrate/migrations_reversible/20220721125033_modify_column.up.sql new file mode 100644 index 0000000000..bbb176cf41 --- /dev/null +++ b/tests/migrate/migrations_reversible/20220721125033_modify_column.up.sql @@ -0,0 +1,2 @@ +UPDATE migrations_reversible_test +SET some_payload = some_payload + 1; diff --git a/tests/migrate/migrations_simple/20220721115250_add_test_table.sql b/tests/migrate/migrations_simple/20220721115250_add_test_table.sql new file mode 100644 index 0000000000..d5ba291914 --- /dev/null +++ b/tests/migrate/migrations_simple/20220721115250_add_test_table.sql @@ -0,0 +1,7 @@ +CREATE TABLE migrations_simple_test ( + some_id BIGINT NOT NULL PRIMARY KEY, + some_payload BIGINT NOT NUll +); + +INSERT INTO migrations_simple_test (some_id, some_payload) +VALUES (1, 100); diff --git a/tests/migrate/migrations_simple/20220721115524_convert_type.sql b/tests/migrate/migrations_simple/20220721115524_convert_type.sql new file mode 100644 index 0000000000..8f6b04d6b0 --- /dev/null +++ b/tests/migrate/migrations_simple/20220721115524_convert_type.sql @@ -0,0 +1,34 @@ +-- Perform a tricky conversion of the payload. +-- +-- This script will only succeed once and will fail if executed twice. + +-- set up temporary target column +ALTER TABLE migrations_simple_test +ADD some_payload_tmp TEXT; + +-- perform conversion +-- This will fail if `some_payload` is already a string column due to the addition. +-- We add a suffix after the addition to ensure that the SQL database does not silently cast the string back to an +-- integer. +UPDATE migrations_simple_test +SET some_payload_tmp = CONCAT(CAST((some_payload + 10) AS TEXT), '_suffix'); + +-- remove original column including the content +ALTER TABLE migrations_simple_test +DROP COLUMN some_payload; + +-- prepare new payload column (nullable, so we can copy over the data) +ALTER TABLE migrations_simple_test +ADD some_payload TEXT; + +-- copy new values +UPDATE migrations_simple_test +SET some_payload = some_payload_tmp; + +-- "freeze" column +ALTER TABLE migrations_simple_test +ALTER COLUMN some_payload SET NOT NULL; + +-- clean up +ALTER TABLE migrations_simple_test +DROP COLUMN some_payload_tmp; diff --git a/tests/mysql/migrate.rs b/tests/mysql/migrate.rs new file mode 100644 index 0000000000..97caa38005 --- /dev/null +++ b/tests/mysql/migrate.rs @@ -0,0 +1,78 @@ +use sqlx::migrate::Migrator; +use sqlx::mysql::{MySql, MySqlConnection}; +use sqlx::pool::PoolConnection; +use sqlx::Executor; +use sqlx::Row; +use std::path::Path; + +#[sqlx::test(migrations = false)] +async fn simple(mut conn: PoolConnection) -> anyhow::Result<()> { + clean_up(&mut conn).await?; + + let migrator = Migrator::new(Path::new("tests/mysql/migrations_simple")).await?; + + // run migration + migrator.run(&mut conn).await?; + + // check outcome + let res: String = conn + .fetch_one("SELECT some_payload FROM migrations_simple_test") + .await? + .get(0); + assert_eq!(res, "110_suffix"); + + // running it a 2nd time should still work + migrator.run(&mut conn).await?; + + Ok(()) +} + +#[sqlx::test(migrations = false)] +async fn reversible(mut conn: PoolConnection) -> anyhow::Result<()> { + clean_up(&mut conn).await?; + + let migrator = Migrator::new(Path::new("tests/mysql/migrations_reversible")).await?; + + // run migration + migrator.run(&mut conn).await?; + + // check outcome + let res: i64 = conn + .fetch_one("SELECT some_payload FROM migrations_reversible_test") + .await? + .get(0); + assert_eq!(res, 101); + + // roll back nothing (last version) + migrator.undo(&mut conn, 20220721125033).await?; + + // check outcome + let res: i64 = conn + .fetch_one("SELECT some_payload FROM migrations_reversible_test") + .await? + .get(0); + assert_eq!(res, 101); + + // roll back one version + migrator.undo(&mut conn, 20220721124650).await?; + + // check outcome + let res: i64 = conn + .fetch_one("SELECT some_payload FROM migrations_reversible_test") + .await? + .get(0); + assert_eq!(res, 100); + + Ok(()) +} + +/// Ensure that we have a clean initial state. +async fn clean_up(conn: &mut MySqlConnection) -> anyhow::Result<()> { + conn.execute("DROP TABLE migrations_simple_test").await.ok(); + conn.execute("DROP TABLE migrations_reversible_test") + .await + .ok(); + conn.execute("DROP TABLE _sqlx_migrations").await.ok(); + + Ok(()) +} diff --git a/tests/mysql/migrations_reversible/20220721124650_add_table.down.sql b/tests/mysql/migrations_reversible/20220721124650_add_table.down.sql new file mode 100644 index 0000000000..5505859725 --- /dev/null +++ b/tests/mysql/migrations_reversible/20220721124650_add_table.down.sql @@ -0,0 +1 @@ +DROP TABLE migrations_reversible_test; diff --git a/tests/mysql/migrations_reversible/20220721124650_add_table.up.sql b/tests/mysql/migrations_reversible/20220721124650_add_table.up.sql new file mode 100644 index 0000000000..9dfc757954 --- /dev/null +++ b/tests/mysql/migrations_reversible/20220721124650_add_table.up.sql @@ -0,0 +1,7 @@ +CREATE TABLE migrations_reversible_test ( + some_id BIGINT NOT NULL PRIMARY KEY, + some_payload BIGINT NOT NUll +); + +INSERT INTO migrations_reversible_test (some_id, some_payload) +VALUES (1, 100); diff --git a/tests/mysql/migrations_reversible/20220721125033_modify_column.down.sql b/tests/mysql/migrations_reversible/20220721125033_modify_column.down.sql new file mode 100644 index 0000000000..3f71737b8c --- /dev/null +++ b/tests/mysql/migrations_reversible/20220721125033_modify_column.down.sql @@ -0,0 +1,2 @@ +UPDATE migrations_reversible_test +SET some_payload = some_payload - 1; diff --git a/tests/mysql/migrations_reversible/20220721125033_modify_column.up.sql b/tests/mysql/migrations_reversible/20220721125033_modify_column.up.sql new file mode 100644 index 0000000000..bbb176cf41 --- /dev/null +++ b/tests/mysql/migrations_reversible/20220721125033_modify_column.up.sql @@ -0,0 +1,2 @@ +UPDATE migrations_reversible_test +SET some_payload = some_payload + 1; diff --git a/tests/mysql/migrations_simple/20220721115250_add_test_table.sql b/tests/mysql/migrations_simple/20220721115250_add_test_table.sql new file mode 100644 index 0000000000..d5ba291914 --- /dev/null +++ b/tests/mysql/migrations_simple/20220721115250_add_test_table.sql @@ -0,0 +1,7 @@ +CREATE TABLE migrations_simple_test ( + some_id BIGINT NOT NULL PRIMARY KEY, + some_payload BIGINT NOT NUll +); + +INSERT INTO migrations_simple_test (some_id, some_payload) +VALUES (1, 100); diff --git a/tests/mysql/migrations_simple/20220721115524_convert_type.sql b/tests/mysql/migrations_simple/20220721115524_convert_type.sql new file mode 100644 index 0000000000..03c9732d0b --- /dev/null +++ b/tests/mysql/migrations_simple/20220721115524_convert_type.sql @@ -0,0 +1,34 @@ +-- Perform a tricky conversion of the payload. +-- +-- This script will only succeed once and will fail if executed twice. + +-- set up temporary target column +ALTER TABLE migrations_simple_test +ADD some_payload_tmp TEXT; + +-- perform conversion +-- This will fail if `some_payload` is already a string column due to the addition. +-- We add a suffix after the addition to ensure that the SQL database does not silently cast the string back to an +-- integer. +UPDATE migrations_simple_test +SET some_payload_tmp = CONCAT(CAST((some_payload + 10) AS CHAR(3)), '_suffix'); + +-- remove original column including the content +ALTER TABLE migrations_simple_test +DROP COLUMN some_payload; + +-- prepare new payload column (nullable, so we can copy over the data) +ALTER TABLE migrations_simple_test +ADD some_payload TEXT; + +-- copy new values +UPDATE migrations_simple_test +SET some_payload = some_payload_tmp; + +-- "freeze" column +ALTER TABLE migrations_simple_test +MODIFY some_payload TEXT NOT NULL; + +-- clean up +ALTER TABLE migrations_simple_test +DROP COLUMN some_payload_tmp; diff --git a/tests/postgres/migrate.rs b/tests/postgres/migrate.rs new file mode 100644 index 0000000000..ff25096831 --- /dev/null +++ b/tests/postgres/migrate.rs @@ -0,0 +1,78 @@ +use sqlx::migrate::Migrator; +use sqlx::pool::PoolConnection; +use sqlx::postgres::{PgConnection, Postgres}; +use sqlx::Executor; +use sqlx::Row; +use std::path::Path; + +#[sqlx::test(migrations = false)] +async fn simple(mut conn: PoolConnection) -> anyhow::Result<()> { + clean_up(&mut conn).await?; + + let migrator = Migrator::new(Path::new("tests/postgres/migrations_simple")).await?; + + // run migration + migrator.run(&mut conn).await?; + + // check outcome + let res: String = conn + .fetch_one("SELECT some_payload FROM migrations_simple_test") + .await? + .get(0); + assert_eq!(res, "110_suffix"); + + // running it a 2nd time should still work + migrator.run(&mut conn).await?; + + Ok(()) +} + +#[sqlx::test(migrations = false)] +async fn reversible(mut conn: PoolConnection) -> anyhow::Result<()> { + clean_up(&mut conn).await?; + + let migrator = Migrator::new(Path::new("tests/postgres/migrations_reversible")).await?; + + // run migration + migrator.run(&mut conn).await?; + + // check outcome + let res: i64 = conn + .fetch_one("SELECT some_payload FROM migrations_reversible_test") + .await? + .get(0); + assert_eq!(res, 101); + + // roll back nothing (last version) + migrator.undo(&mut conn, 20220721125033).await?; + + // check outcome + let res: i64 = conn + .fetch_one("SELECT some_payload FROM migrations_reversible_test") + .await? + .get(0); + assert_eq!(res, 101); + + // roll back one version + migrator.undo(&mut conn, 20220721124650).await?; + + // check outcome + let res: i64 = conn + .fetch_one("SELECT some_payload FROM migrations_reversible_test") + .await? + .get(0); + assert_eq!(res, 100); + + Ok(()) +} + +/// Ensure that we have a clean initial state. +async fn clean_up(conn: &mut PgConnection) -> anyhow::Result<()> { + conn.execute("DROP TABLE migrations_simple_test").await.ok(); + conn.execute("DROP TABLE migrations_reversible_test") + .await + .ok(); + conn.execute("DROP TABLE _sqlx_migrations").await.ok(); + + Ok(()) +} diff --git a/tests/postgres/migrations_reversible/20220721124650_add_table.down.sql b/tests/postgres/migrations_reversible/20220721124650_add_table.down.sql new file mode 100644 index 0000000000..5505859725 --- /dev/null +++ b/tests/postgres/migrations_reversible/20220721124650_add_table.down.sql @@ -0,0 +1 @@ +DROP TABLE migrations_reversible_test; diff --git a/tests/postgres/migrations_reversible/20220721124650_add_table.up.sql b/tests/postgres/migrations_reversible/20220721124650_add_table.up.sql new file mode 100644 index 0000000000..9dfc757954 --- /dev/null +++ b/tests/postgres/migrations_reversible/20220721124650_add_table.up.sql @@ -0,0 +1,7 @@ +CREATE TABLE migrations_reversible_test ( + some_id BIGINT NOT NULL PRIMARY KEY, + some_payload BIGINT NOT NUll +); + +INSERT INTO migrations_reversible_test (some_id, some_payload) +VALUES (1, 100); diff --git a/tests/postgres/migrations_reversible/20220721125033_modify_column.down.sql b/tests/postgres/migrations_reversible/20220721125033_modify_column.down.sql new file mode 100644 index 0000000000..3f71737b8c --- /dev/null +++ b/tests/postgres/migrations_reversible/20220721125033_modify_column.down.sql @@ -0,0 +1,2 @@ +UPDATE migrations_reversible_test +SET some_payload = some_payload - 1; diff --git a/tests/postgres/migrations_reversible/20220721125033_modify_column.up.sql b/tests/postgres/migrations_reversible/20220721125033_modify_column.up.sql new file mode 100644 index 0000000000..bbb176cf41 --- /dev/null +++ b/tests/postgres/migrations_reversible/20220721125033_modify_column.up.sql @@ -0,0 +1,2 @@ +UPDATE migrations_reversible_test +SET some_payload = some_payload + 1; diff --git a/tests/postgres/migrations_simple/20220721115250_add_test_table.sql b/tests/postgres/migrations_simple/20220721115250_add_test_table.sql new file mode 100644 index 0000000000..d5ba291914 --- /dev/null +++ b/tests/postgres/migrations_simple/20220721115250_add_test_table.sql @@ -0,0 +1,7 @@ +CREATE TABLE migrations_simple_test ( + some_id BIGINT NOT NULL PRIMARY KEY, + some_payload BIGINT NOT NUll +); + +INSERT INTO migrations_simple_test (some_id, some_payload) +VALUES (1, 100); diff --git a/tests/postgres/migrations_simple/20220721115524_convert_type.sql b/tests/postgres/migrations_simple/20220721115524_convert_type.sql new file mode 100644 index 0000000000..8f6b04d6b0 --- /dev/null +++ b/tests/postgres/migrations_simple/20220721115524_convert_type.sql @@ -0,0 +1,34 @@ +-- Perform a tricky conversion of the payload. +-- +-- This script will only succeed once and will fail if executed twice. + +-- set up temporary target column +ALTER TABLE migrations_simple_test +ADD some_payload_tmp TEXT; + +-- perform conversion +-- This will fail if `some_payload` is already a string column due to the addition. +-- We add a suffix after the addition to ensure that the SQL database does not silently cast the string back to an +-- integer. +UPDATE migrations_simple_test +SET some_payload_tmp = CONCAT(CAST((some_payload + 10) AS TEXT), '_suffix'); + +-- remove original column including the content +ALTER TABLE migrations_simple_test +DROP COLUMN some_payload; + +-- prepare new payload column (nullable, so we can copy over the data) +ALTER TABLE migrations_simple_test +ADD some_payload TEXT; + +-- copy new values +UPDATE migrations_simple_test +SET some_payload = some_payload_tmp; + +-- "freeze" column +ALTER TABLE migrations_simple_test +ALTER COLUMN some_payload SET NOT NULL; + +-- clean up +ALTER TABLE migrations_simple_test +DROP COLUMN some_payload_tmp; diff --git a/tests/sqlite/migrate.rs b/tests/sqlite/migrate.rs new file mode 100644 index 0000000000..19e8690f9a --- /dev/null +++ b/tests/sqlite/migrate.rs @@ -0,0 +1,78 @@ +use sqlx::migrate::Migrator; +use sqlx::pool::PoolConnection; +use sqlx::sqlite::{Sqlite, SqliteConnection}; +use sqlx::Executor; +use sqlx::Row; +use std::path::Path; + +#[sqlx::test(migrations = false)] +async fn simple(mut conn: PoolConnection) -> anyhow::Result<()> { + clean_up(&mut conn).await?; + + let migrator = Migrator::new(Path::new("tests/sqlite/migrations_simple")).await?; + + // run migration + migrator.run(&mut conn).await?; + + // check outcome + let res: String = conn + .fetch_one("SELECT some_payload FROM migrations_simple_test") + .await? + .get(0); + assert_eq!(res, "110_suffix"); + + // running it a 2nd time should still work + migrator.run(&mut conn).await?; + + Ok(()) +} + +#[sqlx::test(migrations = false)] +async fn reversible(mut conn: PoolConnection) -> anyhow::Result<()> { + clean_up(&mut conn).await?; + + let migrator = Migrator::new(Path::new("tests/sqlite/migrations_reversible")).await?; + + // run migration + migrator.run(&mut conn).await?; + + // check outcome + let res: i64 = conn + .fetch_one("SELECT some_payload FROM migrations_reversible_test") + .await? + .get(0); + assert_eq!(res, 101); + + // roll back nothing (last version) + migrator.undo(&mut conn, 20220721125033).await?; + + // check outcome + let res: i64 = conn + .fetch_one("SELECT some_payload FROM migrations_reversible_test") + .await? + .get(0); + assert_eq!(res, 101); + + // roll back one version + migrator.undo(&mut conn, 20220721124650).await?; + + // check outcome + let res: i64 = conn + .fetch_one("SELECT some_payload FROM migrations_reversible_test") + .await? + .get(0); + assert_eq!(res, 100); + + Ok(()) +} + +/// Ensure that we have a clean initial state. +async fn clean_up(conn: &mut SqliteConnection) -> anyhow::Result<()> { + conn.execute("DROP TABLE migrations_simple_test").await.ok(); + conn.execute("DROP TABLE migrations_reversible_test") + .await + .ok(); + conn.execute("DROP TABLE _sqlx_migrations").await.ok(); + + Ok(()) +} diff --git a/tests/sqlite/migrations_reversible/20220721124650_add_table.down.sql b/tests/sqlite/migrations_reversible/20220721124650_add_table.down.sql new file mode 100644 index 0000000000..5505859725 --- /dev/null +++ b/tests/sqlite/migrations_reversible/20220721124650_add_table.down.sql @@ -0,0 +1 @@ +DROP TABLE migrations_reversible_test; diff --git a/tests/sqlite/migrations_reversible/20220721124650_add_table.up.sql b/tests/sqlite/migrations_reversible/20220721124650_add_table.up.sql new file mode 100644 index 0000000000..9dfc757954 --- /dev/null +++ b/tests/sqlite/migrations_reversible/20220721124650_add_table.up.sql @@ -0,0 +1,7 @@ +CREATE TABLE migrations_reversible_test ( + some_id BIGINT NOT NULL PRIMARY KEY, + some_payload BIGINT NOT NUll +); + +INSERT INTO migrations_reversible_test (some_id, some_payload) +VALUES (1, 100); diff --git a/tests/sqlite/migrations_reversible/20220721125033_modify_column.down.sql b/tests/sqlite/migrations_reversible/20220721125033_modify_column.down.sql new file mode 100644 index 0000000000..3f71737b8c --- /dev/null +++ b/tests/sqlite/migrations_reversible/20220721125033_modify_column.down.sql @@ -0,0 +1,2 @@ +UPDATE migrations_reversible_test +SET some_payload = some_payload - 1; diff --git a/tests/sqlite/migrations_reversible/20220721125033_modify_column.up.sql b/tests/sqlite/migrations_reversible/20220721125033_modify_column.up.sql new file mode 100644 index 0000000000..bbb176cf41 --- /dev/null +++ b/tests/sqlite/migrations_reversible/20220721125033_modify_column.up.sql @@ -0,0 +1,2 @@ +UPDATE migrations_reversible_test +SET some_payload = some_payload + 1; diff --git a/tests/sqlite/migrations_simple/20220721115250_add_test_table.sql b/tests/sqlite/migrations_simple/20220721115250_add_test_table.sql new file mode 100644 index 0000000000..d5ba291914 --- /dev/null +++ b/tests/sqlite/migrations_simple/20220721115250_add_test_table.sql @@ -0,0 +1,7 @@ +CREATE TABLE migrations_simple_test ( + some_id BIGINT NOT NULL PRIMARY KEY, + some_payload BIGINT NOT NUll +); + +INSERT INTO migrations_simple_test (some_id, some_payload) +VALUES (1, 100); diff --git a/tests/sqlite/migrations_simple/20220721115524_convert_type.sql b/tests/sqlite/migrations_simple/20220721115524_convert_type.sql new file mode 100644 index 0000000000..25de20b6a5 --- /dev/null +++ b/tests/sqlite/migrations_simple/20220721115524_convert_type.sql @@ -0,0 +1,30 @@ +-- Perform a tricky conversion of the payload. +-- +-- This script will only succeed once and will fail if executed twice. + +-- set up temporary target column +ALTER TABLE migrations_simple_test +ADD some_payload_tmp TEXT; + +-- perform conversion +-- This will fail if `some_payload` is already a string column due to the addition. +-- We add a suffix after the addition to ensure that the SQL database does not silently cast the string back to an +-- integer. +UPDATE migrations_simple_test +SET some_payload_tmp = CAST((some_payload + 10) AS TEXT) || '_suffix'; + +-- remove original column including the content +ALTER TABLE migrations_simple_test +DROP COLUMN some_payload; + +-- prepare new payload column (nullable, so we can copy over the data) +ALTER TABLE migrations_simple_test +ADD some_payload TEXT; + +-- copy new values +UPDATE migrations_simple_test +SET some_payload = some_payload_tmp; + +-- clean up +ALTER TABLE migrations_simple_test +DROP COLUMN some_payload_tmp;