1
  2
  3
  4
  5
  6
  7
  8
  9
 10
 11
 12
 13
 14
 15
 16
 17
 18
 19
 20
 21
 22
 23
 24
 25
 26
 27
 28
 29
 30
 31
 32
 33
 34
 35
 36
 37
 38
 39
 40
 41
 42
 43
 44
 45
 46
 47
 48
 49
 50
 51
 52
 53
 54
 55
 56
 57
 58
 59
 60
 61
 62
 63
 64
 65
 66
 67
 68
 69
 70
 71
 72
 73
 74
 75
 76
 77
 78
 79
 80
 81
 82
 83
 84
 85
 86
 87
 88
 89
 90
 91
 92
 93
 94
 95
 96
 97
 98
 99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
//! A library to run migrations on a PostgreSQL database using SQLx.
//!
//! Make a directory that contains your migrations. The library will run thru
//! all the files in sorted order. The suggested naming convention is
//! `000_first.sql`, `001_second.sql` and so on.
//!
//! The library:
//! 1. Will create the DB if necessary.
//! 1. Will create a table named `sqlx_pg_migrate` to manage the migration state.
//! 1. Will run everything in a single transaction, so all pending migrations
//!    are run, or nothing.
//! 1. Expects you to never delete or rename a migration.
//! 1. Expects you to not put a new migration between two existing ones.
//! 1. Expects file names and contents to be UTF-8.
//! 1. There are no rollbacks - just write a new migration.
//!
//! You'll need to add these two crates as dependencies:
//! ```toml
//! [dependencies]
//! include_dir = "0.6"
//! sqlx-pg-migrate = "1.0"
//! ```
//!
//! The usage looks like this:
//!
//! ```
//! use sqlx_pg_migrate::migrate;
//! use include_dir::{include_dir, Dir};
//!
//! // Use include_dir! to include your migrations into your binary.
//! // The path here is relative to your cargo root.
//! static MIGRATIONS: Dir = include_dir!("migrations");
//!
//! # #[async_attributes::main]
//! # async fn main() -> std::result::Result<(), sqlx_pg_migrate::Error> {
//! #    let db_url = std::env::var("DATABASE_URL")
//! #        .unwrap_or(String::from("postgresql://localhost/sqlxpgmigrate_doctest"));
//! // Somewhere, probably in main, call the migrate function with your DB URL
//! // and the included migrations.
//! migrate(&db_url, &MIGRATIONS).await?;
//! #    Ok(())
//! # }
//! ```

use include_dir::Dir;
use sqlx::postgres::PgRow;
use sqlx::{Connect, Connection, Executor, PgConnection, Row};
use thiserror::Error;

/// The various kinds of errors that can arise when running the migrations.
#[derive(Error, Debug)]
pub enum Error {
    #[error("expected migration `{0}` to already have been run")]
    MissingMigration(String),

    #[error("invalid URL `{0}`: could not determine DB name")]
    InvalidURL(String),

    #[error("error connecting to base URL `{}` to create DB: {}", .url, .source)]
    BaseConnect { url: String, source: sqlx::Error },

    #[error("error finding current migrations: {}", .source)]
    CurrentMigrations { source: sqlx::Error },

    #[error("invalid utf-8 bytes in migration content: {0}")]
    InvalidMigrationContent(std::path::PathBuf),

    #[error("invalid utf-8 bytes in migration path: {0}")]
    InvalidMigrationPath(std::path::PathBuf),

    #[error("more migrations run than are known indicating possibly deleted migrations")]
    DeletedMigrations,

    #[error(transparent)]
    DB(#[from] sqlx::Error),
}

type Result<T> = std::result::Result<T, Error>;

fn base_and_db(url: &str) -> Result<(&str, &str)> {
    let base_split: Vec<&str> = url.rsplitn(2, '/').collect();
    if base_split.len() != 2 {
        return Err(Error::InvalidURL(url.to_string()));
    }
    let qmark_split: Vec<&str> = base_split[0].splitn(2, '?').collect();
    Ok((base_split[1], qmark_split[0]))
}

async fn maybe_make_db(url: &str) -> Result<()> {
    // TODO: first connect to the url, so the base connect of a possibly missing
    // postgres db isn't required.
    let (base_url, db_name) = base_and_db(url)?;
    let mut db = match PgConnection::connect(&format!("{}/postgres", base_url)).await {
        Ok(db) => db,
        Err(err) => {
            return Err(Error::BaseConnect {
                url: base_url.to_string(),
                source: err,
            })
        }
    };
    let exists: bool = sqlx::query("SELECT true AS exists FROM pg_database WHERE datname = $1")
        .bind(db_name)
        .try_map(|row: PgRow| row.try_get("exists"))
        .fetch_optional(&mut db)
        .await?
        .unwrap_or(false);
    if exists {
        return Ok(());
    }
    sqlx::query(&format!(r#"CREATE DATABASE "{}""#, db_name))
        .execute(&mut db)
        .await?;
    Ok(())
}

async fn get_migrated(db: &mut PgConnection) -> Result<Vec<String>> {
    let migrated = sqlx::query("SELECT migration FROM sqlx_pg_migrate ORDER BY id")
        .try_map(|row: PgRow| row.try_get("migration"))
        .fetch_all(db)
        .await;
    match migrated {
        Ok(migrated) => Ok(migrated),
        Err(err) => {
            if let sqlx::Error::Database(dberr) = err {
                // this indicates the table doesn't exist
                if let Some("42P01") = dberr.code() {
                    Ok(vec![])
                } else {
                    Err(Error::CurrentMigrations {
                        source: sqlx::Error::Database(dberr),
                    })
                }
            } else {
                Err(Error::CurrentMigrations { source: err })
            }
        }
    }
}

/// Runs the migrations contained in the directory. See module documentation for
/// more information.
pub async fn migrate(url: &str, dir: &Dir<'_>) -> Result<()> {
    maybe_make_db(url).await?;
    let mut db = PgConnection::connect(url).await?;
    let migrated = get_migrated(&mut db).await?;
    let mut tx = db.begin().await?;
    if migrated.is_empty() {
        sqlx::query(
            r#"
                CREATE TABLE IF NOT EXISTS sqlx_pg_migrate (
                    id SERIAL PRIMARY KEY,
                    migration TEXT UNIQUE,
                    created TIMESTAMP NOT NULL DEFAULT current_timestamp
                );
            "#,
        )
        .execute(&mut tx)
        .await?;
    }
    let mut files: Vec<_> = dir.files().iter().collect();
    if migrated.len() > files.len() {
        return Err(Error::DeletedMigrations);
    }
    files.sort_by(|a, b| a.path().partial_cmp(b.path()).unwrap());
    for (pos, f) in files.iter().enumerate() {
        let path = f
            .path()
            .to_str()
            .ok_or_else(|| Error::InvalidMigrationPath(f.path().to_owned()))?;

        if pos < migrated.len() {
            if migrated[pos] != path {
                return Err(Error::MissingMigration(path.to_owned()));
            }
            continue;
        }

        let content = f
            .contents_utf8()
            .ok_or_else(|| Error::InvalidMigrationContent(f.path().to_owned()))?;
        tx.execute(content).await?;
        sqlx::query("INSERT INTO sqlx_pg_migrate (migration) VALUES ($1)")
            .bind(path)
            .execute(&mut tx)
            .await?;
    }
    tx.commit().await?;
    Ok(())
}

#[cfg(test)]
mod tests {
    use super::migrate;
    use include_dir::{include_dir, Dir};

    static MIGRATIONS: Dir = include_dir!("migrations");

    #[async_attributes::test]
    async fn it_works() -> std::result::Result<(), super::Error> {
        let url = std::env::var("DATABASE_URL").unwrap_or(String::from(
            "postgresql://localhost/sqlxpgmigrate1?sslmode=disable",
        ));
        // run it twice, second time should be a no-op
        for _ in 0..2 {
            match migrate(&url, &MIGRATIONS).await {
                Err(err) => panic!("migrate failed with: {}", err),
                _ => (),
            };
        }
        Ok(())
    }
}