From 99a0ecd5661678892644ac0d3cffd727016f0eb0 Mon Sep 17 00:00:00 2001 From: David Bernheisel Date: Fri, 16 Jan 2026 22:01:56 -0500 Subject: [PATCH] Add Safe Ecto Migration guides --- guides/backfilling_data.md | 365 ++++++++++++++ guides/migration_anatomy.md | 525 ++++++++++++++++++++ guides/safe_migrations.md | 937 ++++++++++++++++++++++++++++++++++++ lib/ecto/migration.ex | 6 +- mix.exs | 17 +- mix.lock | 5 +- 6 files changed, 1848 insertions(+), 7 deletions(-) create mode 100644 guides/backfilling_data.md create mode 100644 guides/migration_anatomy.md create mode 100644 guides/safe_migrations.md diff --git a/guides/backfilling_data.md b/guides/backfilling_data.md new file mode 100644 index 000000000..82c5da7f7 --- /dev/null +++ b/guides/backfilling_data.md @@ -0,0 +1,365 @@ +# Backfilling Data + +When I say "backfilling data", I mean that as any attempt to change data in bulk. This can happen in code through migrations, application code, UIs that allow multiple selections and updates, or in a console connected to a running application. Since bulk changes affect a lot of data, it's always a good idea to have the code reviewed before it runs. You also want to check that it runs efficiently and does not overwhelm the database. Ideally, it's nice when the code is written to be safe to re-run. For these reasons, please don't change data in bulk through a console! + +We're going to focus on bulk changes executed though Ecto migrations, but the same principles are applicable to any case where bulk changes are being made. Typical scenarios where you might need to run data migrations is when you need to fill in data for records that already exist (hence, backfilling data). This usually comes up when table structures are changed in the database. + +Some examples of backfilling: + +- Populating data into a new column +- Changing a column to make it required. May require changing existing rows to set a value. +- Splitting one database table into several +- Fixing bad data + +For simplicity, we are using `Ecto.Migrator` to run our data migrations, but it's important to not let these migrations break developers' environments over time (more on this below). If using migrations to change data is a normal process that happens regularly, then you may consider exploring a migration system outside of `Ecto.Migrator` that is observable, hooks into error reporting, metrics, and allows for dry runs. This guide is intended as a starting point, and since Ecto ships with a migration runner, we'll leverage it to also run the data migrations. + +There are both bad and good ways to write these data migrations. Let explore some: + +## Bad + +In the following example, a migration references the schema `MyApp.MySchema`. + +```elixir +defmodule MyApp.Repo.DataMigrations.BackfillPosts do + use Ecto.Migration + import Ecto.Query + + def change do + alter table("posts") do + add :new_data, :text + end + + flush() + + MyApp.MySchema + |> where(new_data: nil) + |> MyApp.Repo.update_all(set: [new_data: "some data"]) + end +end +``` + +The problem is the code and schema may change over time. However, migrations are using a snapshot of your schemas at the time it's written. In the future, many assumptions may no longer be true. For example, the new_data column may not be present anymore in the schema causing the query to fail if this migration is run months later. + +Additionally, in your development environment, you might have 10 records to migrate; in staging, you might have 100; in production, you might have 1 billion to migrate. Scaling your approach matters. + +Ultimately, there are several bad practices here: + +1. The Ecto schema in the query may change after this migration was written. +1. If you try to backfill the data all at once, it may exhaust the database memory and/or CPU if it's changing a large data set. +1. Backfilling data inside a transaction for the migration locks row updates for the duration of the migration, even if you are updating in batches. +1. Disabling the transaction for the migration and only batching updates may still spike the database CPU to 100%, causing other concurrent reads or writes to time out. + +## Good + +There are four keys to backfilling safely: + +1. running outside a transaction +1. batching +1. throttling +1. resiliency + +As we've learned in this guide, it's straight-forward to disable the migration transactions. Add these options to the migration: + +```elixir +@disable_ddl_transaction true +@disable_migration_lock true +``` + +Batching our data migrations still has several challenges. + +We'll start with how do we paginate efficiently: `LIMIT`/`OFFSET` by itself is an expensive query for large tables (they start fast, but slow to a crawl when in the later pages of the table), so we must find another way to paginate. Since we cannot use a database transaction, this also implies we cannot leverage cursors since they require a transaction. This leaves us with [keyset pagination](https://www.citusdata.com/blog/2016/03/30/five-ways-to-paginate/). + +For querying and updating the data, there are two ways to "snapshot" your schema at the time of the migration. We'll use both options below in the examples: + +1. Execute raw SQL that represents the table at that moment. Do not use Ecto schemas. Prefer this approach when you can. Your application's Ecto schemas will change over time, but your migration should not, therefore it's not a true snapshot of the data at the time. +1. Write a small Ecto schema module inside the migration that only uses what you need. Then use that in your data migration. This is helpful if you prefer the Ecto API and decouples from your application's Ecto schemas as it evolves separately. + +For throttling, we can simply add a `Process.sleep(@throttle)` for each page. + +For resiliency, we need to ensure that we handle errors without losing our progress. You don't want to migrate the same data twice! Most data migrations I have run find some records in a state that I wasn't expecting. This causes the data migration to fail. When the data migration stops, that means I have to write a little bit more code to handle that scenario, and re-run the migration. Every time the data migration is re-run, it should pick up where it left off without revisiting already-migrated records. + +Finally, to manage these data migrations separately, we need to: + +1. Store data migrations separately from your schema migrations. +1. Run the data migrations manually. + +To achieve this, be inspired by [Ecto's documentation on creating a Release module](`Ecto.Migrator`), and extend your release module to allow options to pass into `Ecto.Migrator` that specifies the version to migrate and the data migrations' file path, for example: + +```elixir +defmodule MyApp.Release do + # ... + @doc """ + Migrate data in the database. Defaults to migrating to the latest, `[all: true]` + Also accepts `[step: 1]`, or `[to: 20200118045751]` + """ + def migrate_data(opts \\ [all: true]) do + for repo <- repos() do + path = Ecto.Migrator.migrations_path(repo, "data_migrations") + {:ok, _, _} = Ecto.Migrator.with_repo(repo, &Ecto.Migrator.run(&1, path, :up, opts)) + end + end +end +``` + +## Batching Deterministic Data + +If the data can be queried with a condition that is removed after update then you can repeatedly query the data and update the data until the query result is empty. For example, if a column is currently null and will be updated to not be null, then you can query for the null records and pick up where you left off. + +Here's how we can manage the backfill: + +1. Disable migration transactions. +1. Use keyset pagination: Order the data, find rows greater than the last mutated row and limit by batch size. +1. For each page, mutate the records. +1. Check for failed updates and handle it appropriately. +1. Use the last mutated record's ID as the starting point for the next page. This helps with resiliency and prevents looping on the same record over and over again. +1. Arbitrarily sleep to throttle and prevent exhausting the database. +1. Rinse and repeat until there are no more records + +For example: + +```bash +mix ecto.gen.migration --migrations-path=priv/repo/data_migrations backfill_posts +``` + +And modify the migration: + +```elixir +defmodule MyApp.Repo.DataMigrations.BackfillPosts do + use Ecto.Migration + import Ecto.Query + + @disable_ddl_transaction true + @disable_migration_lock true + @batch_size 1000 + @throttle_ms 100 + + def up do + throttle_change_in_batches(&page_query/1, &do_change/1) + end + + def down, do: :ok + + def do_change(batch_of_ids) do + {_updated, results} = repo().update_all( + from(r in "weather", select: r.id, where: r.id in ^batch_of_ids), + [set: [approved: true]], + log: :info + ) + not_updated = MapSet.difference(MapSet.new(batch_of_ids), MapSet.new(results)) |> MapSet.to_list() + Enum.each(not_updated, &handle_non_update/1) + Enum.sort(results) + end + + def page_query(last_id) do + # Notice how we do not use Ecto schemas here. + from( + r in "weather", + select: r.id, + where: is_nil(r.approved) and r.id > ^last_id, + order_by: [asc: r.id], + limit: @batch_size + ) + end + + # If you have integer IDs, default last_pos = 0 + # If you have binary IDs, default last_pos = "00000000-0000-0000-0000-000000000000" + defp throttle_change_in_batches(query_fun, change_fun, last_pos \\ 0) + defp throttle_change_in_batches(_query_fun, _change_fun, nil), do: :ok + defp throttle_change_in_batches(query_fun, change_fun, last_pos) do + case repo().all(query_fun.(last_pos), [log: :info, timeout: :infinity]) do + [] -> + :ok + + ids -> + results = change_fun.(List.flatten(ids)) + next_page = List.first(results) + Process.sleep(@throttle_ms) + throttle_change_in_batches(query_fun, change_fun, next_page) + end + end + + defp handle_non_update(id) do + raise "#{inspect(id)} was not updated" + end +end +``` + +## Batching Arbitrary Data + +If the data being updated does not indicate it's already been updated, then we need to take a snapshot of the current data and store it temporarily. For example, if all rows should increment a column's value by 10, how would you know if a record was already updated? You could load a list of IDs into the application during the migration, but what if the process crashes? Instead we're going to keep the data we need in the database. + +To do this, it works well if we can pick a specific point in time where all records _after_ that point in time do not need adjustment. This happens when you realize a bug was creating bad data and after the bug was fixed and deployed, all new entries are good and should not be touched as we clean up the bad data. For this example, we'll use `inserted_at` as our marker. Let's say that the bug was fixed on a midnight deploy on 2021-08-22. + +Here's how we'll manage the backfill: + +1. Create a "temporary" table. In this example, we're creating a real table that we'll drop at the end of the data migration. In Postgres, there are [actual temporary tables](https://www.postgresql.org/docs/12/sql-createtable.html) that are discarded after the session is over; we're not using those because we need resiliency in case the data migration encounters an error. The error would cause the session to be over, and therefore the temporary table tracking progress would be lost. Real tables don't have this problem. Likewise, we don't want to store IDs in application memory during the migration for the same reason. +1. Populate that temporary table with IDs of records that need to update. This query only requires a read of the current records, so there are no consequential locks occurring when populating, but be aware this could be a lengthy query. Populating this table can occur at creation or afterwards; in this example we'll populate it at table creation. +1. Ensure there's an index on the temporary table so it's fast to delete IDs from it. I use an index instead of a primary key because it's easier to re-run the migration in case there's an error. There isn't a straight-forward way to `CREATE IF NOT EXIST` on a primary key; but you can do that easily with an index. +1. Use keyset pagination to pull batches of IDs from the temporary table. Do this inside a database transaction and lock records for updates. Each batch should read and update within milliseconds, so this should have little impact on concurrent reads and writes. +1. For each batch of records, determine the data changes that need to happen. This can happen for each record. +1. [Upsert](https://wiki.postgresql.org/wiki/UPSERT) those changes to the real table. This insert will include the ID of the record that already exists and a list of attributes to change for that record. Since these insertions will conflict with existing records, we'll instruct Postgres to replace certain fields on conflicts. +1. Delete those IDs from the temporary table since they're updated on the real table. Close the database transaction for that batch. +1. Throttle so we don't overwhelm the database, and also give opportunity to other concurrent processes to work. +1. Rinse and repeat until the temporary table is empty. +1. Finally, drop the temporary table when empty. + +Let's see how this can work: + +```bash +mix ecto.gen.migration --migrations-path=priv/repo/data_migrations backfill_weather +``` + +Modify the migration: + +```elixir +# Both of these modules are in the same migration file +# In this example, we'll define a new Ecto Schema that is a snapshot +# of the current underlying table and no more. +defmodule MyApp.Repo.DataMigrations.BackfillWeather.MigratingSchema do + use Ecto.Schema + + # Copy of the schema at the time of migration + schema "weather" do + field :temp_lo, :integer + field :temp_hi, :integer + field :prcp, :float + field :city, :string + + timestamps(type: :naive_datetime_usec) + end +end + +defmodule MyApp.Repo.DataMigrations.BackfillWeather do + use Ecto.Migration + import Ecto.Query + alias MyApp.Repo.DataMigrations.BackfillWeather.MigratingSchema + + @disable_ddl_transaction true + @disable_migration_lock true + @temp_table_name "records_to_update" + @batch_size 1000 + @throttle_ms 100 + + def up do + repo().query!(""" + CREATE TABLE IF NOT EXISTS "#{@temp_table_name}" AS + SELECT id FROM weather WHERE inserted_at < '2021-08-21T00:00:00' + """, [], log: :info, timeout: :infinity) + flush() + + create_if_not_exists index(@temp_table_name, [:id]) + flush() + + throttle_change_in_batches(&page_query/1, &do_change/1) + + # You may want to check if it's empty before dropping it. + # Since we're raising an exception on non-updates + # we don't have to do that in this example. + drop table(@temp_table_name) + end + + def down, do: :ok + + def do_change(batch_of_ids) do + # Wrap in a transaction to momentarily lock records during read/update + repo().transaction(fn -> + mutations = + from( + r in MigratingSchema, + where: r.id in ^batch_of_ids, + lock: "FOR UPDATE" + ) + |> repo().all() + |> Enum.reduce([], &mutation/2) + + # Don't be fooled by the name `insert_all`, this is actually an upsert + # that will update existing records when conflicting; they should all + # conflict since the ID is included in the update. + + {_updated, results} = repo().insert_all( + MigratingSchema, + mutations, + returning: [:id], + # Alternatively, {:replace_all_except, [:id, :inserted_at]} + on_conflict: {:replace, [:temp_lo, :updated_at]}, + conflict_target: [:id], + placeholders: %{now: NaiveDateTime.utc_now()}, + log: :info + ) + results = results |> Enum.map(& &1.id) |> Enum.sort() + + not_updated = + mutations + |> Enum.map(& &1[:id]) + |> MapSet.new() + |> MapSet.difference(MapSet.new(results)) + |> MapSet.to_list() + + Enum.each(not_updated, &handle_non_update/1) + repo().delete_all(from(r in @temp_table_name, where: r.id in ^results)) + + results + end) + end + + def mutation(record, mutations_acc) do + # This logic can be whatever you need; we'll just do something simple + # here to illustrate + + if record.temp_hi > 1 do + # No updated needed + mutations_acc + else + # Upserts don't update autogenerated fields like timestamps, so be sure + # to update them yourself. The inserted_at value should never be used + # since all these records are already inserted, and we won't replace + # this field on conflicts; we just need it to satisfy table constraints. + [%{ + id: record.id, + temp_lo: record.temp_hi - 10, + inserted_at: {:placeholder, :now}, + updated_at: {:placeholder, :now} + } | mutations_acc] + end + end + + def page_query(last_id) do + from( + r in @temp_table_name, + select: r.id, + where: r.id > ^last_id, + order_by: [asc: r.id], + limit: @batch_size + ) + end + + defp handle_non_update(id) do + raise "#{inspect(id)} was not updated" + end + + # If you have integer IDs, fallback last_pod = 0 + # If you have binary IDs, fallback last_pos = "00000000-0000-0000-0000-000000000000" + defp throttle_change_in_batches(query_fun, change_fun, last_pos \\ 0) + defp throttle_change_in_batches(_query_fun, _change_fun, nil), do: :ok + defp throttle_change_in_batches(query_fun, change_fun, last_pos) do + case repo().all(query_fun.(last_pos), [log: :info, timeout: :infinity]) do + [] -> + :ok + + ids -> + case change_fun.(List.flatten(ids)) do + {:ok, results} -> + next_page = List.first(results) + Process.sleep(@throttle_ms) + throttle_change_in_batches(query_fun, change_fun, next_page) + error -> + raise error + end + end + end +end +``` + +--- + +This guide was originally published on [Fly.io Phoenix Files](https://fly.io/phoenix-files/backfilling-data/). diff --git a/guides/migration_anatomy.md b/guides/migration_anatomy.md new file mode 100644 index 000000000..2cf0e3011 --- /dev/null +++ b/guides/migration_anatomy.md @@ -0,0 +1,525 @@ +# Anatomy of a Migration + +[Ecto migrations](`Ecto.Migration`) are used to do the following: + +* Change the structure of the database, such as adding fields, tables, or indexes to improve lookups (DDL). +* Populating fields with modified data or new data (DML). + +In order for us to create and run safe Ecto migrations on our database, it is helpful to understand what is actually happening with the database. To do that, we'll dig deeper into how Ecto migrations work by looking both at the code being executed and the Postgres logs. + +To generate a migration, we'll use run a mix task: + +```bash +mix ecto.gen.migration create_weather_table +``` + +> #### Tip {: .tip} +> +> If you're using Phoenix, you might consider `mix phx.gen.schema` which will generate a migration and also allows you to pass in fields and types. See `mix help phx.gen.schema` for more information. + +This command will generate a file in `priv/repo/migrations` given the repo name of `Repo`. If you named it `OtherRepo` the file would be `in priv/other_repo/migrations`. + +Let's look at that file: + +```elixir +defmodule MyApp.Repo.Migrations.CreateWeatherTable do + use Ecto.Migration + + def change do + + end +end +``` + +Let's make some changes; how about we create a table that tracks a city's climate? + +```elixir +defmodule MyApp.Repo.Migrations.CreateWeatherTable do + use Ecto.Migration + + def change do + create table("weather") do + add :city, :string, size: 40 + add :temp_lo, :integer + add :temp_hi, :integer + add :prcp, :float + + timestamps() + end + end +end +``` + +Now that we have a migration, let's run it! Run `mix ecto.migrate`: + +```shell +$ mix ecto.migrate +21:26:18.992 [info] == Running 20210702012346 MyApp.Repo.Migrations.CreateWeatherTable.change/0 forward +21:26:18.994 [info] create table weather +21:26:19.004 [info] == Migrated 20210702012346 in 0.0s +``` + +## Inspect SQL + +Understanding exactly what SQL commands are running is helpful to ensure safe migrations, so how do we see the SQL that is executed? By default, Ecto does not log the raw SQL. First, I'll rollback, and then re-migrate but with an additional flag `--log-migrations-sql` so we can see what actually runs. + +```shell +$ mix ecto.rollback +== Running 20210702012346 MyApp.Repo.Migrations.CreateWeatherTable.change/0 backward +drop table weather +== Migrated 20210702012346 in 0.0s +``` + +```shell +$ mix ecto.migrate --log-migrations-sql +== Running 20210702012346 MyApp.Repo.Migrations.CreateWeatherTable.change/0 forward +create table weather +QUERY OK db=3.2ms +CREATE TABLE "weather" ("id" bigserial, "city" varchar(40), "temp_lo" integer, "temp_hi" integer, "prcp" float, "inserted_at" timestamp(0) NOT NULL, "updated_at" timestamp(0) NOT NULL, PRIMARY KEY ("id")) [] +21:29:36.467 [info] == Migrated 20210702012346 in 0.0s +``` + +Ecto logged the SQL for our changes, but we're not seeing all the SQL that Ecto is running for the migration-- we're missing the Ecto.Migrator SQL that manages the migration. To get these missing logs, we'll also use another flag, `--log-migrator-sql`. Here I am tailing the PostgreSQL server logs: + +```shell +$ mix ecto.rollback +$ mix ecto.migrate --log-migrator-sql --log-migrations-sql +``` + +``` +begin [] +LOCK TABLE "schema_migrations" IN SHARE UPDATE EXCLUSIVE MODE [] +begin [] +== Running 20210702012346 MyApp.Repo.Migrations.CreateWeatherTable.change/0 forward +create table weather +QUERY OK db=14.8ms +CREATE TABLE "weather" ("id" bigserial, "city" varchar(40), "temp_lo" integer, "temp_hi" integer, "prcp" float, "inserted_ +at" timestamp(0) NOT NULL, "updated_at" timestamp(0) NOT NULL, PRIMARY KEY ("id")) [] +== Migrated 20210702012346 in 0.0s +QUERY OK source="schema_migrations" db=5.1ms +INSERT INTO "schema_migrations" ("version","inserted_at") VALUES ($1,$2) [20210718204657, ~N[2021-07-18 18:20:46]] +QUERY OK db=1.0ms +commit [] +QUERY OK db=0.3ms +commit [] +``` + +Inside the transaction, the Ecto Postgres adapter obtains a `SHARE UPDATE EXCLUSIVE` lock of the "schema_migrations" table. + +**Why this lock is important**: Systems at scale may have multiple instances of the application connected to the same database, and during a deployment all of the instances rolling out may try to migrate that database at the same time, Ecto leverages this `SHARE UPDATE EXCLUSIVE` lock as a way to ensure that only one instance is running a migration at a time and only once. + +This is what the migration actually looks like: + +```sql +BEGIN; +LOCK TABLE "schema_migrations" IN SHARE UPDATE EXCLUSIVE MODE; +BEGIN; +CREATE TABLE "weather" ("id" bigserial, "city" varchar(40), "temp_lo" integer, "temp_hi" integer, "prcp" float, "inserted_at" timestamp(0) NOT NULL, "updated_at" timestamp(0) NOT NULL, PRIMARY KEY ("id")); +INSERT INTO "schema_migrations" ("version","inserted_at") VALUES ('20210718204657','2021-07-18 20:53:49'); +COMMIT; +COMMIT; +``` + +When a migration fails, the transaction is rolled back and no changes are kept in the database. In most situations, these are great defaults. + +Veteran database administrators may notice the database transactions (`BEGIN`/`COMMIT`) and wonder how to turn those off in situations where transactions could cause problems; such as when adding indexes concurrently; Ecto provides some options that can help with transactions and locks. Let's explore some of those options next. + +## Migration Options + +A typical migration has this structure (reminder: this guide is using Postgres; other adapters will vary): + +```sql +BEGIN; + LOCK TABLE "schema_migrations" IN SHARE UPDATE EXCLUSIVE MODE; + BEGIN; + -- after_begin callback + -- my_changes + -- before_commit callback + INSERT INTO "schema_migrations" ("version","inserted_at") VALUES ($1,$2); + COMMIT; +COMMIT; +``` + +_`my_changes` refers to the changes you specify in each of your migrations._ + +### `@disable_migration_lock` + +By default, Ecto acquires a lock on the "schema_migrations" table during the migration transaction: + +```sql +BEGIN; + -- THIS LOCK + LOCK TABLE "schema_migrations" IN SHARE UPDATE EXCLUSIVE MODE + BEGIN; + -- after_begin callback + -- my_changes + -- before_commit callback + INSERT INTO "schema_migrations" ("version","inserted_at") VALUES ($1,$2); + COMMIT; +COMMIT; +``` + +You want this lock for most migrations because running multiple migrations simultaneously without this lock could have unpredictable results. In database transactions, any locks obtained inside the transaction are released when the transaction is committed, which then unblocks other transactions that touch the same records to proceed. + +However, there are some scenarios where you don't want a lock. We'll explore these scenarios later on (for example, backfilling data and creating indexes). + +You can skip this lock in Ecto by setting the module attribute `@disable_migration_lock true` in your migration. When the migration lock is disabled, the migration looks like this: + +```sql +BEGIN; + -- after_begin callback + -- my changes + -- before_commit callback + INSERT INTO "schema_migrations" ("version","inserted_at") VALUES ($1,$2); +COMMIT; +``` + +### `@disable_ddl_transaction` + +By default, Ecto wraps your changes in a transaction: + +```sql +BEGIN; + LOCK TABLE "schema_migrations" IN SHARE UPDATE EXCLUSIVE MODE + -- THIS TRANSACTION + BEGIN; + -- after_begin callback + -- my changes + -- before_commit callback + INSERT INTO "schema_migrations" ("version","inserted_at") VALUES ($1,$2); + COMMIT; + -- THIS TRANSACTION +COMMIT; +``` + +This ensures that when failures occur during a migration, your database is not left in an incomplete or mangled state. + +There are scenarios where you don't want a migration to run inside a transaction. Like when performing data migrations or when running commands such as `CREATE INDEX CONCURRENTLY` that can run in the background in the database after you issue the command and cannot be inside a transaction. + +You can disable this transaction by setting the module attribute `@disable_ddl_transaction true` in your migration. The migration then looks like this: + +```sql +BEGIN; + LOCK TABLE "schema_migrations" IN SHARE UPDATE EXCLUSIVE MODE + -- my_changes + INSERT INTO "schema_migrations" ("version","inserted_at") VALUES ($1,$2); +COMMIT; +``` + +> #### Tip {: .tip} +> +> For Postgres, when disabling transactions, you'll also want to disable the migration lock since that uses yet another transaction. When running these migrations in a multi-node environment, you'll need a process to ensure these migrations are only run once since there is no protection against multiple nodes running the same migration at the same exact time. + +Disabling both the migration lock and the DDL transaction, your migration will be pretty simple: + +```sql +-- my_changes +INSERT INTO "schema_migrations" ("version","inserted_at") VALUES ($1,$2); +``` + +### Transaction Callbacks + +In the examples above, you'll notice there are `after_begin` and `before_commit` hooks if the migration is occurring within a transaction: + +```sql +BEGIN; + -- after_begin hook + -- my_changes + -- before_commit hook + INSERT INTO "schema_migrations" ("version","inserted_at") VALUES ($1,$2); +COMMIT; +``` + +You can use these hooks by defining `after_begin/0` and `before_commit/0` in your migration. A good use case for this is setting migration lock timeouts as safeguards (see later Safeguards section). + +```elixir +defmodule MyApp.Repo.Migrations.CreateWeatherTable do + use Ecto.Migration + + def change do + # ... my potentially long-locking migration + end + + def after_begin do + execute "SET lock_timeout TO '5s'", "SET lock_timeout TO '10s'" + end +end +``` + +> #### Caution {: .warning} +> +> Be aware that these callbacks are not called when `@disable_ddl_transaction true` is configured because they rely on the transaction being present. + +## Inspecting Locks In a Query + +Before we dive into safer migration practices, we should cover how to check if a migration could potentially block your application. In Postgres, there is a `pg_locks` table that we can query that reveals the locks in the system. Let's query that table alongside our changes from the migration, but return the locks so we can see what locks were obtained from the changes. + +```sql +BEGIN; + -- Put your actions in here. For example, validating a constraint + ALTER TABLE addresses VALIDATE CONSTRAINT "my_table_locking_constraint"; + + -- end your transaction with a SELECT on pg_locks so you can see the locks + -- that occurred during the transaction + SELECT locktype, relation::regclass, mode, transactionid AS tid, virtualtransaction AS vtid, pid, granted FROM pg_locks; +COMMIT; +``` + +The result from this SQL command should return the locks obtained during the database transaction. Let's see an example: We'll add a unique index without concurrency so we can see the locks it obtains: + +```sql +BEGIN; + LOCK TABLE "schema_migrations" IN SHARE UPDATE EXCLUSIVE MODE; + -- we are going to squash the embedded transaction here for simplicity + CREATE UNIQUE INDEX IF NOT EXISTS "weather_city_index" ON "weather" ("city"); + INSERT INTO "schema_migrations" ("version","inserted_at") VALUES ('20210718210952',NOW()); + SELECT locktype, relation::regclass, mode, transactionid AS tid, virtualtransaction AS vtid, pid, granted FROM pg_locks; +COMMIT; + +-- locktype | relation | mode | tid | vtid | pid | granted +-- ---------------+--------------------+--------------------------+--------+-------+-----+--------- +-- relation | pg_locks | AccessShareLock | | 2/321 | 253 | t +-- relation | schema_migrations | RowExclusiveLock | | 2/321 | 253 | t +-- virtualxid | | ExclusiveLock | | 2/321 | 253 | t +-- relation | weather_city_index | AccessExclusiveLock | | 2/321 | 253 | t +-- relation | schema_migrations | ShareUpdateExclusiveLock | | 2/321 | 253 | t +-- transactionid | | ExclusiveLock | 283863 | 2/321 | 253 | t +-- relation | weather | ShareLock | | 2/321 | 253 | t +-- (7 rows) +``` + +Let's go through each of these: + +1. `relation | pg_locks | AccessShareLock` - This is us querying the `"pg_locks"` table in the transaction so we can see which locks are taken. It has the weakest lock which only conflicts with `AccessExclusive` which should never happen on the internal `"pg_locks"` table itself. +1. `relation | schema_migrations | RowExclusiveLock` - This is because we're inserting a row into the `"schema_migrations"` table. Reads are still allowed, but mutation on this table is blocked until the transaction is done. +1. `virtualxid | _ | ExlusiveLock` - Querying `pg_locks` created a virtual transaction on the `SELECT` query. We can ignore this. +1. `relation | weather_city_index | AccessExclusiveLock` - We're creating the index, so this new index will be completely locked to any reads and writes until this transaction is complete. +1. `relation | schema_migrations | ShareUpdateExclusiveLock` - This lock is acquired by Ecto to ensure that only one mutable operation is happening on the table. This is what allows multiple nodes able to run migrations at the same time safely. Other processes can still read the `"schema_migrations"` table, but you cannot write to it. +1. `transactionid | _ | ExclusiveLock` - This lock is on a transaction that is happening; in this case, it has an `ExclusiveLock` on itself; meaning that if another transaction occurring at the same time conflicts with this transaction, the other transaction will acquire a lock on this transaction so it knows when it's done. I call this "lockception". +1. `relation | weather | ShareLock` - Finally, the reason why we're here. Remember, we're creating a unique index on the `"weather"` table without concurrency. This lock is our red flag. Notice it acquires a ShareLock on the table. This means it blocks writes! That's not good if we deploy this and have processes or web requests that regularly write to this table. `UPDATE`, `DELETE`, and `INSERT` acquire a `RowExclusiveLock` which conflicts with the ShareLock. + +To avoid this lock, we change the command to `CREATE INDEX CONCURRENTLY ...`; when using `CONCURRENTLY`, it prevents us from using database transactions which is unfortunate because now we cannot easily see the locks the command obtains. We know this will be safer however because `CREATE INDEX CONCURRENTLY` acquires a `ShareUpdateExclusiveLock` which does not conflict with `RowExclusiveLock` (See Reference Material in the [Safe Migrations guide](safe_migrations.html)). + +This scenario is revisited later in [Safe Migrations](safe_migrations.html). + +## Safeguards in the database + +It's a good idea to add safeguards so no developer on the team accidentally locks up the database for too long. Even if you know all about databases and locks, you might have a forgetful day and try to add an index non-concurrently and bring down production. Safeguards are good. + +We can add one or more safeguards: + +1. Automatically cancel a statement if the lock is held for too long. There are two ways to do this: + 1. Apply to migrations. This can be done with a lock_timeout inside a transaction. + 2. Apply to any statements. This can be done by setting a lock_timeout on a Postgres role. +2. Automatically cancel statements that take too long. This is broader than #1 because it includes any statement, not just locks. + +Let's dive into these safeguards. + +### Add a `lock_timeout` + +One safeguard we can add to migrations is a lock timeout. A lock timeout ensures a lock will not last more than n seconds. This way, when an unsafe migration sneaks in, it only locks tables to updates and writes (and possibly reads) for n seconds instead of indefinitely when the migration finishes. + +From the Postgres docs: + +> Abort any statement that waits longer than the specified amount of time while attempting to acquire a lock on a table, index, row, or other database object. The time limit applies separately to each lock acquisition attempt. The limit applies both to explicit locking requests (such as LOCK TABLE, or SELECT FOR UPDATE without NOWAIT) and to implicitly-acquired locks. If this value is specified without units, it is taken as milliseconds. A value of zero (the default) disables the timeout. +> +> Unlike `statement_timeout`, this timeout can only occur while waiting for locks. Note that if `statement_timeout` is nonzero, it is rather pointless to set lock_timeout to the same or larger value, since the statement timeout would always trigger first. If `log_min_error_statement` is set to `ERROR` or lower, the statement that timed out will be logged. + +There are two ways to apply this lock: + +1. localized to the transaction +2. default for the user/role + +Let's go through those options: + +#### Transaction lock_timeout + +In SQL: + +```sql +SET LOCAL lock_timeout TO '5s'; +``` + +Let's move that to an Ecto migration transaction callback. Since this `lock_timeout` will be in a database transaction for Postgres, we will use `SET LOCAL lock_timeout` so that the `lock_timeout` only alters this database transaction and not the session. + +You can set a lock timeout in every migration: + +```elixir +def after_begin do + # execute/2 can be ran in both migration directions, up/down. + # The first argument will be ran when migrating up. + # The second argument will be ran when migrating down. You might give yourself + # a couple extra seconds when rolling back. + execute("SET LOCAL lock_timeout TO '5s'", "SET LOCAL lock_timeout TO '10s'") +end +``` + +But this can get tedious since you'll likely want this for every migration. Let's write a little macro to help with this boilerplate code. + +In every migration, you'll notice that we `use Ecto.Migration` which inserts some code into your migration. Let's use this same idea to inject a boilerplate of our own and leverage an option to set a lock timeout. We define the `after_begin/0` callback to set the lock timeout. + +```elixir +defmodule MyApp.Migration do + defmacro __using__(opts) do + lock_timeout = Keyword.get(opts, :lock_timeout, [up: "5s", down: "10s"]) + + quote do + use Ecto.Migration + + if unquote(lock_timeout) do + def after_begin do + execute( + "SET LOCAL lock_timeout TO '#{Keyword.fetch!(unquote(lock_timeout), :up)}'", + "SET LOCAL lock_timeout TO '#{Keyword.fetch!(unquote(lock_timeout), :down)}'" + ) + end + end + end + end +end +``` + +And adjust our migration: + +```diff +defmodule MyApp.Repo.Migrations.CreateWeatherTable do +- use Ecto.Migration ++ use MyApp.Migration + + def change do + # my changes + end +end +``` + +Now the migrations will only be allowed to acquire locks up to 5 seconds when migrating up and 10 seconds when rolling back. Remember, these callbacks are not called when `@disable_ddl_transaction true` is set. + +You can override the lock timeout if needed by passing in options: + +```elixir +# disable the lock_timeout +use MyApp.Migration, lock_timeout: false + +# or change the timeouts +use MyApp.Migration, lock_timeout: [up: "10s", down: "20s"] +``` + +Let's now make Ecto use our custom Migration module by default when generating new migrations: + +```elixir +# config/config.exs +config :ecto_sql, migration_module: MyApp.Migration +``` + +#### Role-level lock_timeout + +Alternatively, you can set a lock timeout for the user in all commands: + +```sql +ALTER ROLE myuser SET lock_timeout = '10s'; +``` + +If you have a different user that runs migrations, this could be a good option for that migration-specific Postgres user. The trade-off is that Elixir developers won't see this timeout as they write migrations and explore the call stack since database role settings are in the database which developers don't usually monitor. + +#### Statement Timeout + +Another way to ensure safety is to configure your Postgres database with statement timeouts. These timeouts apply to all statements, including migrations and the locks they obtain. + +From Postgres docs: + +> Abort any statement that takes more than the specified amount of time. If `log_min_error_statement` is set to `ERROR` or lower, the statement that timed out will also be logged. If this value is specified without units, it is taken as milliseconds. A value of zero (the default) disables the timeout. +> +> The timeout is measured from the time a command arrives at the server until it is completed by the server. If multiple SQL statements appear in a single simple-Query message, the timeout is applied to each statement separately. (PostgreSQL versions before 13 usually treated the timeout as applying to the whole query string.) In extended query protocol, the timeout starts running when any query-related message (Parse, Bind, Execute, Describe) arrives, and it is canceled by completion of an Execute or Sync message. + +You can specify this configuration for the Postgres user. For example: + +```sql +ALTER ROLE myuser SET statement_timeout = '10m'; +``` + +Now any statement automatically times out if it runs for more than 10 minutes; opposed to running indefinitely. This can help if you accidentally run a query that runs the database CPU hot, slowing everything else down; now the unoptimized query will be limited to 10 minutes or else it will fail and be canceled. + +Setting this `statement_timeout` requires discipline from the team; if there are runaway queries that fail (for example) at 10 minutes, an exception will likely occur somewhere. You will want to equip your application with sufficient logging, tracing, and reporting so you can replicate the query and the parameters it took to hit the timeout, and ultimately optimize the query. Without this discipline, you risk creating a culture that ignores exceptions. + +#### Timeouts for Non-Transactional Migrations + +When `@disable_ddl_transaction true` is set, the `after_begin/0` callback is not called, so you cannot rely on it to set timeouts. Instead, set the timeout directly in your migration: + +```elixir +@disable_ddl_transaction true +@disable_migration_lock true + +def change do + execute "SET lock_timeout TO '5s'" + create index("posts", [:slug], concurrently: true) +end +``` + +Note that `SET` without `LOCAL` sets the timeout for the session. Since there's no transaction, `SET LOCAL` would have no effect. + +### Handling Failed Concurrent Operations + +When `CREATE INDEX CONCURRENTLY` fails (due to timeout, deadlock, or other errors), PostgreSQL leaves behind an **invalid index**. This index: + +- Takes up disk space +- Slows down writes (PostgreSQL still updates it) +- Does not speed up queries (the planner ignores it) + +You can find invalid indexes with: + +```sql +SELECT indexrelid::regclass AS index_name, indrelid::regclass AS table_name +FROM pg_index WHERE NOT indisvalid; +``` + +To clean up, drop the invalid index and retry: + +```elixir +@disable_ddl_transaction true +@disable_migration_lock true + +def change do + # Drop any invalid index from a previous failed attempt + execute "DROP INDEX CONCURRENTLY IF EXISTS posts_slug_index" + create index("posts", [:slug], concurrently: true) +end +``` + +> #### Caution {: .warning} +> +> Always check for invalid indexes after a failed concurrent migration. They won't go away on their own and can silently degrade write performance. + +### Monitoring Locks During Migrations + +When running migrations, especially on large tables, it's helpful to monitor for lock contention. You can run this query in a separate session to see blocked queries: + +```sql +SELECT + blocked.pid AS blocked_pid, + blocked.query AS blocked_query, + blocked.wait_event_type, + blocking.pid AS blocking_pid, + blocking.query AS blocking_query, + now() - blocked.query_start AS blocked_duration +FROM pg_stat_activity blocked +JOIN pg_locks blocked_locks ON blocked.pid = blocked_locks.pid AND NOT blocked_locks.granted +JOIN pg_locks blocking_locks ON blocking_locks.locktype = blocked_locks.locktype + AND blocking_locks.database IS NOT DISTINCT FROM blocked_locks.database + AND blocking_locks.relation IS NOT DISTINCT FROM blocked_locks.relation + AND blocking_locks.page IS NOT DISTINCT FROM blocked_locks.page + AND blocking_locks.tuple IS NOT DISTINCT FROM blocked_locks.tuple + AND blocking_locks.virtualxid IS NOT DISTINCT FROM blocked_locks.virtualxid + AND blocking_locks.transactionid IS NOT DISTINCT FROM blocked_locks.transactionid + AND blocking_locks.classid IS NOT DISTINCT FROM blocked_locks.classid + AND blocking_locks.objid IS NOT DISTINCT FROM blocked_locks.objid + AND blocking_locks.objsubid IS NOT DISTINCT FROM blocked_locks.objsubid + AND blocking_locks.pid != blocked_locks.pid +JOIN pg_stat_activity blocking ON blocking_locks.pid = blocking.pid +WHERE blocked.wait_event_type = 'Lock'; +``` + +This shows you which queries are waiting for locks and what's blocking them. If you see your migration blocking many queries, you may want to cancel it and use a safer approach. + +--- + +This guide was originally published on [Fly.io Phoenix Files](https://fly.io/phoenix-files/anatomy-of-an-ecto-migration/). diff --git a/guides/safe_migrations.md b/guides/safe_migrations.md new file mode 100644 index 000000000..a335642f2 --- /dev/null +++ b/guides/safe_migrations.md @@ -0,0 +1,937 @@ +# Safe Ecto Migrations + +A guide on common migration recipes and how to avoid trouble. + +## Quick Reference + +| Operation | Risk | Safe Approach | +|-----------|------|---------------| +| Add index | Blocks writes | Use `concurrently: true` and disable transactions | +| Drop index | Blocks writes | Use `concurrently: true` and disable transactions | +| Add foreign key | Blocks writes on both tables | Use `validate: false`, then validate separately | +| Add column with default | Table rewrite (pre-PG11) | Add column first, then set default | +| Add NOT NULL | Full table scan | Use check constraint, validate, then add NOT NULL | +| Add check constraint | Full table scan | Create with `validate: false`, then validate separately | +| Change column type | Table rewrite | Create new column, migrate data, swap reads, drop old column | +| Remove column | Query failures | Remove from schema first, then drop column | +| Rename column | Query failures | Use `source:` option in schema instead | +| Rename table | Query failures | Rename schema module instead | +| Add enum value | Transaction error (pre-PG12) | disable transactions | +| Add extension | Transaction error | disable transactions | + +## All Scenarios + +The biggest factor in all the scenarios below is **scale**. For 1 million records +in tables, you may lock writes to the table when creating the column for +milliseconds which could be acceptable for you. However, once your table has +100+ million records, the difference becomes seconds which is more likely to be +felt and cause timeouts. Therefore, err on the side of safety, but +**always benchmark for your own database**. Also consider the hardware the +database is running; eg a Raspberry Pi 2B on a microSD will run much slower. + +## Table of Contents + +- [Adding an index](#adding-an-index) +- [Dropping an index](#dropping-an-index) +- [Adding a reference or foreign key](#adding-a-reference-or-foreign-key) +- [Adding a column with a default value](#adding-a-column-with-a-default-value) +- [Changing a column's default value](#changing-a-columns-default-value) +- [Changing the type of a column](#changing-the-type-of-a-column) +- [Removing a column](#removing-a-column) +- [Renaming a column](#renaming-a-column) +- [Renaming a table](#renaming-a-table) +- [Adding a check constraint](#adding-a-check-constraint) +- [Setting NOT NULL on an existing column](#setting-not-null-on-an-existing-column) +- [Adding a JSON column](#adding-a-json-column) +- [Adding a value to a PostgreSQL enum](#adding-a-value-to-a-postgresql-enum) +- [Removing or replacing a PostgreSQL enum value](#removing-or-replacing-a-postgresql-enum-value) +- [Adding a PostgreSQL extension](#adding-a-postgresql-extension) +- [Squashing migrations](#squashing-migrations) + +Read more about safe migration techniques: + +- [Migration locks in "Anatomy of a Migration"](migration_anatomy.html) +- [How to backfill data and change data in bulk (aka: DML)](backfilling_data.html) + +## Adding an index + +Creating an index will [block writes](https://www.postgresql.org/docs/8.2/sql-createindex.html) to the table in Postgres. + +MySQL is concurrent by default since [5.6](https://downloads.mysql.com/docs/mysql-5.6-relnotes-en.pdf) unless using `SPATIAL` or `FULLTEXT` indexes, which then it [blocks reads and writes](https://dev.mysql.com/doc/refman/8.0/en/innodb-online-ddl-operations.html#online-ddl-index-syntax-notes). + +### Bad + +```elixir +def change do + create index("posts", [:slug]) + + # This obtains a ShareLock on "posts" which will block writes to the table +end +``` + +### Good + +With Postgres, instead create the index concurrently which does not block writes. +There are two options: + +**Option 1** + +[Configure the Repo to use advisory locks](`Ecto.Adapters.Postgres#module-migration-options`) for locking migrations while running. Advisory locks are application-controlled database-level locks, and EctoSQL since v3.9.0 provides an option to use this type of lock. This is the safest option as it avoids the trade-off in Option 2. + +Disable the DDL transaction in the migration to avoid a database transaction which is not compatible with `CONCURRENTLY` database operations. + +```elixir +# in config/config.exs +config MyApp.Repo, migration_lock: :pg_advisory_lock + +# in the migration +@disable_ddl_transaction true + +def change do + create index("posts", [:slug], concurrently: true) +end +``` + +If you're using Phoenix and PhoenixEcto, you will likely appreciate disabling +the migration lock in the CheckRepoStatus plug during dev to avoid hitting and +waiting on the advisory lock with concurrent web processes. You can do this by +adding `migration_lock: false` to the CheckRepoStatus plug in your +`MyAppWeb.Endpoint`. + +**Option 2** + +Disable the DDL transaction and the migration lock for the migration. By default, EctoSQL with Postgres will run migrations with a DDL transaction and a migration lock which also (by default) uses another transaction. You must disable both of these database transactions to use `CONCURRENTLY`. However, disabling the migration lock will allow competing nodes to try to run the same migration at the same time (eg, in a multi-node Kubernetes environment that runs migrations before startup). Therefore, some nodes may fail startup for a variety of reasons. + +```elixir +@disable_ddl_transaction true +@disable_migration_lock true + +def change do + create index("posts", [:slug], concurrently: true) +end +``` + +For either option chosen, the migration may still take a while to run, but reads and updates to rows will continue to work. For example, for 100,000,000 rows it took 165 seconds to add run the migration, but SELECTS and UPDATES could occur while it was running. + +**Do not have other changes in the same migration**; only create the index concurrently and separate other changes to later migrations. + +## Dropping an index + +Dropping an index blocks reads and writes while acquiring an `ACCESS EXCLUSIVE` lock. + +### Bad + +```elixir +def change do + drop index("posts", [:slug]) + # Acquires ACCESS EXCLUSIVE lock, blocking all reads and writes +end +``` + +### Good + +Drop the index concurrently to avoid blocking reads and writes: + +```elixir +@disable_ddl_transaction true +@disable_migration_lock true + +def change do + drop index("posts", [:slug], concurrently: true) +end +``` + +Or with advisory locks (preferred): + +```elixir +# in config/config.exs +config MyApp.Repo, migration_lock: :pg_advisory_lock + +# in the migration +@disable_ddl_transaction true + +def change do + drop index("posts", [:slug], concurrently: true) +end +``` + +> #### Note {: .info} +> +> Like creating indexes concurrently, dropping concurrently cannot be done inside a transaction. The same caveats about multi-node deployments apply. + +## Adding a reference or foreign key + +Adding a foreign key blocks writes on both tables. + +### Bad + +```elixir +def change do + alter table("posts") do + add :group_id, references("groups") + # Obtains a ShareRowExclusiveLock which blocks writes on both tables + end +end +``` + + +### Good + +In the first migration + +```elixir +def change do + alter table("posts") do + add :group_id, references("groups", validate: false) + # Obtains a ShareRowExclusiveLock which blocks writes on both tables. + end +end +``` + +In the second migration + +```elixir +def change do + execute "ALTER TABLE posts VALIDATE CONSTRAINT group_id_fkey", "" + # Obtains a ShareUpdateExclusiveLock which doesn't block reads or writes +end +``` + +> #### Note {: .info} +> +> The down migration is an empty string because PostgreSQL does not have an "unvalidate" operation for constraints. This is safe because validation only confirms existing data meets the constraint—it doesn't modify data. If you need to rollback, the constraint will remain validated, which has no negative impact. + +These migrations can be in the same deployment, but make sure they are separate migrations. + +**Note on empty tables**: when the table creating the referenced column is empty, you may be able to +create the column and validate at the same time since the time difference would be milliseconds +which may not be noticeable, no matter if you have 1 million or 100 million records in the referenced table. + +**Note on populated tables**: the biggest difference depends on your scale. For 1 million records in +both tables, you may lock writes to both tables when creating the column for milliseconds +(you should benchmark for yourself) which could be acceptable for you. However, once your table has +100+ million records, the difference becomes seconds which is more likely to be felt and cause timeouts. +The differentiating metric is the time that both tables are locked from writes. Therefore, err on the side +of safety and separate constraint validation from referenced column creation when there is any data in the table. + +## Adding a column with a default value + +Adding a column with a default value to an existing table may cause the table to be rewritten. During this time, reads and writes are blocked in Postgres, and writes are blocked in MySQL and MariaDB. If the default column is an expression (volatile value) it will remain unsafe. + +### Bad + +Note: This becomes safe for non-volatile (static) defaults in: + +- [Postgres 11+](https://www.postgresql.org/docs/release/11.0/). Default applies to INSERT since 7.x, and UPDATE since 9.3. +- MySQL 8.0.12+ +- MariaDB 10.3.2+ + +```elixir +def change do + alter table("comments") do + add :approved, :boolean, default: false + # This took 10 minutes for 100 million rows with no fkeys, + + # Obtained an AccessExclusiveLock on the table, which blocks reads and + # writes. + end +end +``` + +```elixir +def change do + alter table("comments") do + add :some_timestamp, :utc_datetime, default: fragment("now()") + # A volatile value + end +end +``` + +### Good + +Add the column first, then alter it to include the default. + +First migration: + +```elixir +def change do + alter table("comments") do + add :approved, :boolean + # This took 0.27 milliseconds for 100 million rows with no fkeys, + end +end +``` + +Second migration: + +```elixir +def change do + execute "ALTER TABLE comments ALTER COLUMN approved SET DEFAULT false", + "ALTER TABLE comments ALTER COLUMN approved DROP DEFAULT" + # This took 0.28 milliseconds for 100 million rows with no fkeys, +end +``` + +Note: we cannot use `Ecto.Migration.modify/3` as it will include updating the column type as +well unnecessarily, causing Postgres to rewrite the table. For more information, +[see this example](https://github.com/fly-apps/safe-ecto-migrations/issues/10). + +Schema change to read the new column: + +```diff +schema "comments" do ++ field :approved, :boolean, default: false +end +``` + +> #### Note {: .info} +> +> The safe method will not materialize the default value on the column for existing rows because the default was not set when adding the column (avoiding a potential table lock so it can re-write it to _write_ the default). This may affect your queries where you'd expect the value to now be set to your default but is actually `null`. However, the next `UPDATE` operation on the row will materialize the default, additionally Ecto will apply the default on the application side when reading the record. If you want to materialize the value, then you will need to consider [backfilling](backfilling_data.html). + +## Changing a column's default value + +Changing an existing column's default may risk rewriting the table. + +### Bad + +```elixir +def change do + alter table("comments") do + # Previously, the default was `true` + modify :approved, :boolean, default: false + # This took 10 minutes for 100 million rows with no fkeys, + + # Obtained an AccessExclusiveLock on the table, which blocks reads and + # writes. + end +end +``` + +The issue is that we cannot use `Ecto.Migration.modify/3` as it will include updating the column type as +well unnecessarily, causing Postgres to rewrite the table. For more information, +[see this example](https://github.com/fly-apps/safe-ecto-migrations/issues/10). + +### Good + +Execute raw sql instead to alter the default: + +```elixir +def change do + execute "ALTER TABLE comments ALTER COLUMN approved SET DEFAULT false", + "ALTER TABLE comments ALTER COLUMN approved SET DEFAULT true" + # This took 0.28 milliseconds for 100 million rows with no fkeys, +end +``` + +> #### Note {: .info} +> +> This will not update the values of rows previously-set by the old default. This value has been materialized at the time of insert/update and therefore has no distinction between whether it was set by the column `DEFAULT` or set by the original operation. +> +> If you want to update the default of already-written rows, you must distinguish them somehow and modify them with a [backfill](backfilling_data.html) + +## Changing the type of a column + +Changing the type of a column may cause the table to be rewritten. During this time, reads and writes are blocked in Postgres, and writes are blocked in MySQL and MariaDB. + +### Bad + +Safe in Postgres: + +- increasing length on varchar or removing the limit +- changing varchar to text +- changing text to varchar with no length limit +- Postgres 9.2+ - increasing precision (NOTE: not scale) of decimal or numeric columns. eg, increasing 8,2 to 10,2 is safe. Increasing 8,2 to 8,4 is not safe. +- Postgres 9.2+ - changing decimal or numeric to be unconstrained +- Postgres 12+ - changing timestamp to timestamptz when session TZ is UTC + +Safe in MySQL/MariaDB: + +- increasing length of varchar from < 255 up to 255. +- increasing length of varchar from > 255 up to max. + +```elixir +def change do + alter table("posts") do + modify :my_column, :boolean, from: :text + end +end +``` + +### Good + +Take a phased approach: + +1. Create a new column +1. In application code, write to both columns +1. Backfill data from old column to new column +1. In application code, move reads from old column to the new column +1. In application code, remove old column from Ecto schemas. +1. Drop the old column. + +## Removing a column + +If Ecto is still configured to read a column in any running instances of the application, then queries will fail when loading data into your structs. This can happen in multi-node deployments or if you start the application before running migrations. + +### Bad + +```elixir +# Without a code change to the Ecto Schema + +def change do + alter table("posts") do + remove :no_longer_needed_column + end +end +``` + + +### Good + +Safety can be assured if the application code is first updated to remove references to the column so it's no longer loaded or queried. Then, the column can safely be removed from the table. + +1. Deploy code change to remove references to the field. +1. Deploy migration change to remove the column. + +First deployment: + +```diff +# First deploy, in the Ecto schema + +defmodule MyApp.Post do + schema "posts" do +- column :no_longer_needed_column, :text + end +end +``` + +Second deployment: + +```elixir +def change do + alter table("posts") do + remove :no_longer_needed_column + end +end +``` + +## Renaming a column + +Ask yourself: "Do I _really_ need to rename a column?". Probably not, but if you must, read on and be aware it requires time and effort. + +If Ecto is configured to read a column in any running instances of the application, then queries will fail when loading data into your structs. This can happen in multi-node deployments or if you start the application before running migrations. + +There is a shortcut: Don't rename the database column, and instead rename the schema's field name and configure it to point to the database column. + +### Bad + +```elixir +# In your schema +schema "posts" do + field :summary, :text +end + + +# In your migration +def change do + rename table("posts"), :title, to: :summary +end +``` + +The time between your migration running and your application getting the new code may encounter trouble. + +### Good + +**Strategy 1** + +Rename the field in the schema only, and configure it to point to the database column and keep the database column the same. Ensure all calling code relying on the old field name is also updated to reference the new field name. + +```elixir +defmodule MyApp.MySchema do + use Ecto.Schema + + schema "weather" do + field :temp_lo, :integer + field :temp_hi, :integer + field :precipitation, :float, source: :prcp + field :city, :string + + timestamps(type: :naive_datetime_usec) + end +end +``` + +```diff +## Update references in other parts of the codebase: + my_schema = Repo.get(MySchema, "my_id") +- my_schema.prcp ++ my_schema.precipitation +``` + +**Strategy 2** + +Take a phased approach and use a database view: + +1. In the same transaction: (1) Rename the table to a temporary name, (2) Create an updatable database view with the table's original name, selecting all of the table's columns as well as the renaming column selected again as the new name. +1. In application code, change the field source to the new name +1. In the same transaction: (1) Drop the database view, (2) Rename the database table back to the real name, (3) Rename the column to the new name + +**Strategy 3** + +Take a phased approach and physically rewrite the column: + +1. Create a new column +1. In application code, write to both columns +1. Backfill data from old column to new column +1. In application code, move reads from old column to the new column +1. In application code, remove old column from Ecto schemas. +1. Drop the old column. + +## Renaming a table + +Ask yourself: "Do I _really_ need to rename a table?". Probably not, but if you must, read on and be aware it requires time and effort. + +If Ecto is still configured to read a table in any running instances of the application, then queries will fail when loading data into your structs. This can happen in multi-node deployments or if you start the application before running migrations. + +There is a shortcut: rename the schema only, and do not change the underlying database table name. + +### Bad + +```elixir +def change do + rename table("posts"), to: table("articles") +end +``` + +### Good + +**Strategy 1** + +Rename the schema only and all calling code, and don't rename the table: + +```diff +- defmodule MyApp.Weather do ++ defmodule MyApp.Forecast do + use Ecto.Schema + + schema "weather" do + field :temp_lo, :integer + field :temp_hi, :integer + field :precipitation, :float, source: :prcp + field :city, :string + + timestamps(type: :naive_datetime_usec) + end +end + +# and in calling code: +- weather = MyApp.Repo.get(MyApp.Weather, "my_id") ++ forecast = MyApp.Repo.get(MyApp.Forecast, "my_id") +``` + +**Strategy 2** + +Take a phased approach and use a database view: + +For example, rename "weather" to "forecasts" + +1. Create an updatable database view of the table with the new name "forecasts" +1. In application code, change the schema source to the updatable view "forecasts" +1. In the same transaction: (1) drop the database view, (2) rename the database table to the intended name, eg "forecasts" + +**Strategy 3** + +Take a phased approach and physically rewrite the table: + +1. Create the new table. This should include creating new constraints (checks and foreign keys) that mimic behavior of the old table. +1. In application code, write to both tables, continuing to read from the old table. +1. Backfill data from old table to new table +1. In application code, move reads from old table to the new table +1. In application code, remove the old table from Ecto schemas. +1. Drop the old table. + +## Adding a check constraint + +Adding a check constraint blocks reads and writes to the table in Postgres, and blocks writes in MySQL/MariaDB while every row is checked. + +### Bad + +```elixir +def change do + create constraint("products", :price_must_be_positive, check: "price > 0") + # Creating the constraint with validate: true (the default when unspecified) + # will perform a full table scan and acquires a lock preventing updates +end +``` + +### Good + +There are two operations occurring: + +1. Creating a new constraint for new or updating records +1. Validating the new constraint for existing records + +If these commands are happening at the same time, it obtains a lock on the table as it validates the entire table and fully scans the table. To avoid this full table scan, we can separate the operations. + +In one migration: + +```elixir +def change do + create constraint("products", :price_must_be_positive, check: "price > 0", validate: false) + # Setting validate: false will prevent a full table scan, and therefore + # commits immediately. +end +``` + +In the next migration: + +```elixir +def change do + execute "ALTER TABLE products VALIDATE CONSTRAINT price_must_be_positive", "" + # Acquires SHARE UPDATE EXCLUSIVE lock, which allows updates to continue +end +``` + +These can be in the same deployment, but ensure there are 2 separate migrations. + +## Setting NOT NULL on an existing column + +Setting NOT NULL on an existing column blocks reads and writes while every row is checked. Just like the Adding a check constraint scenario, there are two operations occurring: + +1. Creating a new constraint for new or updating records +1. Validating the new constraint for existing records + +To avoid the full table scan, we can separate these two operations. + +### Bad + +```elixir +def change do + alter table("products") do + modify :active, :boolean, null: false + end +end +``` + +### Good + +Add a check constraint without validating it, backfill data to satiate the constraint and then validate it. This will be functionally equivalent. + +In the first migration: + +```elixir +# Deployment 1 +def change do + create constraint("products", :active_not_null, check: "active IS NOT NULL", validate: false) +end +``` + +This will enforce the constraint in all new rows, but not care about existing rows until that row is updated. + +You'll likely need a data migration at this point to ensure that the constraint is satisfied. + +Then, in the next deployment's migration, we'll enforce the constraint on all rows: + +```elixir +# Deployment 2 +def change do + execute "ALTER TABLE products VALIDATE CONSTRAINT active_not_null", "" +end +``` + +If you're using Postgres 12+, you can add the NOT NULL to the column after validating the constraint. From the Postgres 12 docs: + +> SET NOT NULL may only be applied to a column provided +> none of the records in the table contain a NULL value +> for the column. Ordinarily this is checked during the +> ALTER TABLE by scanning the entire table; however, if +> a valid CHECK constraint is found which proves no NULL +> can exist, then the table scan is skipped. + +**However** we cannot use `Ecto.Migration.modify/3` +as it will include updating the column type as well unnecessarily, causing +Postgres to rewrite the table. For more information, [see this example](https://github.com/fly-apps/safe-ecto-migrations/issues/10). + +```elixir +# **Postgres 12+ only** + +def change do + execute "ALTER TABLE products VALIDATE CONSTRAINT active_not_null", + "" + + execute "ALTER TABLE products ALTER COLUMN active SET NOT NULL", + "ALTER TABLE products ALTER COLUMN active DROP NOT NULL" + + drop constraint("products", :active_not_null) +end +``` + +If your constraint fails, then you should consider backfilling data first to cover the gaps in your desired data integrity, then revisit validating the constraint. + +## Adding a JSON column + +In Postgres, there is no equality operator for the json column type, which can cause errors for existing SELECT DISTINCT queries in your application. + +### Bad + +```elixir +def change do + alter table("posts") do + add :extra_data, :json + end +end +``` + +### Good + +Use jsonb instead. Some say it's like "json" but "better." + +```elixir +def change do + alter table("posts") do + add :extra_data, :jsonb + end +end +``` + +## Adding a value to a PostgreSQL enum + +Adding enum values inside a transaction fails in PostgreSQL < 12. + +### Bad + +```elixir +def change do + # Fails in PostgreSQL < 12: cannot run inside a transaction + execute "ALTER TYPE status ADD VALUE 'archived'" +end +``` + +### Good + +```elixir +@disable_ddl_transaction true +@disable_migration_lock true + +def up do + execute "ALTER TYPE status ADD VALUE IF NOT EXISTS 'archived'" +end + +def down do + # PostgreSQL does not support removing enum values + :ok +end +``` + +## Removing or replacing a PostgreSQL enum value + +PostgreSQL does not support removing or modifying enum values directly. Like renaming columns or tables, this requires coordinating application code changes with database changes. + +### Bad + +```elixir +def change do + # These operations do not exist in PostgreSQL + execute "ALTER TYPE status DROP VALUE 'obsolete'" +end +``` + +### Good + +Take a phased approach: + +1. **Deploy application code** that handles both old and new enum values (stops writing the value to be removed, reads both old and new values) +2. **Backfill data** to migrate rows from old value to new value (see [backfilling guide](backfilling_data.html)) +3. **Deploy migration** to replace the enum type +4. **Deploy application code** to remove handling of old value + +First deployment (application code): + +```diff +# Stop writing the old value, handle both when reading +defmodule MyApp.Post do + def changeset(post, attrs) do + post + |> cast(attrs, [:status]) +- |> validate_inclusion(:status, ~w(draft obsolete published archived)) ++ |> validate_inclusion(:status, ~w(draft published archived)) + end + + # Handle old value when reading + def display_status(%{status: "obsolete"}), do: "draft" + def display_status(%{status: status}), do: status +end +``` + +Second deployment (backfill existing rows): + +```elixir +def up do + execute "UPDATE posts SET status = 'draft' WHERE status = 'obsolete'" +end +``` + +For large tables, batch this operation. See [backfilling data](backfilling_data.html) for safe approaches. + +Third deployment (replace the enum type): + +```elixir +def up do + execute "CREATE TYPE status_new AS ENUM ('draft', 'published', 'archived')" + execute "ALTER TABLE posts ALTER COLUMN status TYPE status_new USING status::text::status_new" + execute "DROP TYPE status" + execute "ALTER TYPE status_new RENAME TO status" +end +``` + +> #### Warning {: .warning} +> +> The `ALTER COLUMN ... TYPE` operation rewrites the table and blocks reads and writes. For large tables, consider a phased migration using a new column instead. + +## Adding a PostgreSQL extension + +Extensions cannot be created inside a transaction. + +### Bad + +```elixir +def change do + # Fails: CREATE EXTENSION cannot run inside a transaction block + execute "CREATE EXTENSION \"uuid-ossp\"" +end +``` + +### Good + +```elixir +@disable_ddl_transaction true +@disable_migration_lock true + +def change do + execute "CREATE EXTENSION IF NOT EXISTS \"uuid-ossp\"", + "DROP EXTENSION IF EXISTS \"uuid-ossp\"" +end +``` + +> #### Note {: .info} +> +> Creating extensions typically requires superuser privileges. In managed database services (AWS RDS, Heroku), some extensions may not be available. + +## Squashing Migrations + +If you have a long list of migrations, sometimes it can take a while to migrate +each of those files every time the project is reset or spun up by a new +developer. Thankfully, Ecto comes with mix tasks to `dump` and `load` a database +structure which will represent the state of the database up to a certain point +in time, not including content. + +- `mix ecto.dump` +- `mix ecto.load` + +Schema dumping and loading is only supported by external binaries `pg_dump` and +`mysqldump`, which are used by the Postgres, MyXQL, and MySQL Ecto adapters (not +supported in MSSQL adapter). + +For example: + +``` +20210101000000 - First Migration +20210201000000 - Second Migration +20210701000000 - Third Migration <-- we are here now. run `mix ecto.dump` +``` + +We can "squash" the migrations up to the current day which will effectively +fast-forward migrations to that structure. The Ecto Migrator will detect that +the database is already migrated to the third migration, and so it begins there +and migrates forward. + +Let's add a new migration: + +``` +20210101000000 - First Migration +20210201000000 - Second Migration +20210701000000 - Third Migration <-- `structure.sql` represents up to here +20210801000000 - New Migration <-- This is where migrations will begin +``` + +The new migration will still run, but the first-through-third migrations will +not need to be run since the structure already represents the changes applied by +those migrations. At this point, you can safely delete the first, second, and +third migration files or keep them for historical auditing. + +Let's make this work: + +1. Run `mix ecto.dump` which will dump the current structure into + `priv/repo/structure.sql` by default. Check `mix help ecto.dump` for more + options. +2. During project setup with an empty database, run `mix ecto.load` to load + `structure.sql`. +3. Run `mix ecto.migrate` to run any additional migrations created after the + structure was dumped. + +To simplify these actions into one command, we can leverage mix aliases: + +```elixir +# mix.exs + +defp aliases do + [ + "ecto.reset": ["ecto.drop", "ecto.setup"], + "ecto.setup": ["ecto.load", "ecto.migrate"], + # ... + ] +end +``` + +Now you can run `mix ecto.setup` and it will load the database structure and run +remaining migrations. Or, run `mix ecto.reset` and it will drop and run setup. +Of course, you can continue running `mix ecto.migrate` as you create them. + +## Credits + +Created and written by David Bernheisel with recipes heavily inspired from Andrew Kane and his library [strong_migrations](https://github.com/ankane/strong_migrations). + +- [PostgreSQL at Scale by James Coleman](https://medium.com/braintree-product-technology/postgresql-at-scale-database-schema-changes-without-downtime-20d3749ed680) +- [Strong Migrations by Andrew Kane](https://github.com/ankane/strong_migrations) +- [Adding a NOT NULL CONSTRAINT on PG Faster with Minimal Locking by Christophe Escobar](https://medium.com/doctolib/adding-a-not-null-constraint-on-pg-faster-with-minimal-locking-38b2c00c4d1c) +- [Postgres Runtime Configuration](https://www.postgresql.org/docs/current/runtime-config-client.html) +- [Automatic and Manual Ecto Migrations by Wojtek Mach](https://dashbit.co/blog/automatic-and-manual-ecto-migrations) + +Special thanks for sponsorship: Fly.io + +Special thanks for the reviewers. + +## Reference Material + +[Postgres Lock Conflicts](https://www.postgresql.org/docs/12/explicit-locking.html) + +| | **Current Lock** | | | | | | | | +|---------------------|-------------------|-|-|-|-|-|-|-| +| **Requested Lock** | ACCESS SHARE | ROW SHARE | ROW EXCLUSIVE | SHARE UPDATE EXCLUSIVE | SHARE | SHARE ROW EXCLUSIVE | EXCLUSIVE | ACCESS EXCLUSIVE | +| ACCESS SHARE | | | | | | | | X | +| ROW SHARE | | | | | | | X | X | +| ROW EXCLUSIVE | | | | | X | X | X | X | +| SHARE UPDATE EXCLUSIVE | | | | X | X | X | X | X | +| SHARE | | | X | X | | X | X | X | +| SHARE ROW EXCLUSIVE | | | X | X | X | X | X | X | +| EXCLUSIVE | | X | X | X | X | X | X | X | +| ACCESS EXCLUSIVE | X | X | X | X | X | X | X | X | + +- `SELECT` acquires a `ACCESS SHARE` lock +- `SELECT FOR UPDATE` acquires a `ROW SHARE` lock +- `UPDATE`, `DELETE`, and `INSERT` will acquire a `ROW EXCLUSIVE` lock +- `CREATE INDEX CONCURRENTLY` and `VALIDATE CONSTRAINT` acquires `SHARE UPDATE EXCLUSIVE` +- `CREATE INDEX` acquires `SHARE` lock + +Reframed by operations: + +| | **Current Operation** | | | | | | | | +|---------------------|-------------------|-|-|-|-|-|-|-| +| **Blocks Operation** | `SELECT` | `SELECT FOR UPDATE` | `UPDATE` `DELETE` `INSERT` | `CREATE INDEX CONCURRENTLY` `VALIDATE CONSTRAINT` | `CREATE INDEX` | SHARE ROW EXCLUSIVE | EXCLUSIVE | `ALTER TABLE` `DROP TABLE` `TRUNCATE` `REINDEX` `CLUSTER` `VACUUM FULL` | +| `SELECT` | | | | | | | | X | +| `SELECT FOR UPDATE` | | | | | | | X | X | +| `UPDATE` `DELETE` `INSERT` | | | | | X | X | X | X | +| `CREATE INDEX CONCURRENTLY` `VALIDATE CONSTRAINT` | | | | X | X | X | X | X | +| `CREATE INDEX` | | | X | X | | X | X | X | +| SHARE ROW EXCLUSIVE | | | X | X | X | X | X | X | +| EXCLUSIVE | | X | X | X | X | X | X | X | +| `ALTER TABLE` `DROP TABLE` `TRUNCATE` `REINDEX` `CLUSTER` `VACUUM FULL` | X | X | X | X | X | X | X | X | diff --git a/lib/ecto/migration.ex b/lib/ecto/migration.ex index 7f342ac7b..eb56a68be 100644 --- a/lib/ecto/migration.ex +++ b/lib/ecto/migration.ex @@ -89,7 +89,7 @@ defmodule Ecto.Migration do For the rest of this document, we will cover the migration APIs provided by Ecto. For a in-depth discussion of migrations and how to use them safely within your application and data, see the - [Safe Ecto Migrations guide](https://github.com/fly-apps/safe-ecto-migrations). + [Safe Ecto Migrations guide](safe_migrations.html). ## Mix tasks @@ -405,7 +405,7 @@ defmodule Ecto.Migration do ## Additional resources - * The [Safe Ecto Migrations guide](https://github.com/fly-apps/safe-ecto-migrations) + * The [Safe Ecto Migrations guide](safe_migrations.html) """ @@ -1638,7 +1638,7 @@ defmodule Ecto.Migration do end ``` - See the [Safe Ecto Migrations guide](https://github.com/fly-apps/safe-ecto-migrations) for an + See the [Safe Ecto Migrations guide](safe_migrations.html) for an in-depth explanation of the benefits of this approach. """ def constraint(table, name, opts \\ []) diff --git a/mix.exs b/mix.exs index 0013472e3..6fc4cfcb3 100644 --- a/mix.exs +++ b/mix.exs @@ -65,7 +65,8 @@ defmodule EctoSQL.MixProject do {:jason, "~> 1.0", only: [:test, :bench, :docs]}, # Docs - {:ex_doc, "~> 0.21", only: :docs}, + {:ex_doc, "~> 0.21", only: :doc, runtime: false, warn_if_outdated: true}, + {:makeup_sql, ">= 0.1.3", only: :doc, runtime: false}, # Benchmarks {:benchee, "~> 1.0", only: :bench}, @@ -187,7 +188,19 @@ defmodule EctoSQL.MixProject do source_ref: "v#{@version}", canonical: "http://hexdocs.pm/ecto_sql", source_url: @source_url, - extras: ["CHANGELOG.md"], + extras: [ + "CHANGELOG.md", + "guides/safe_migrations.md", + "guides/migration_anatomy.md", + "guides/backfilling_data.md" + ], + groups_for_extras: [ + Guides: [ + "guides/safe_migrations.md", + "guides/migration_anatomy.md", + "guides/backfilling_data.md" + ] + ], skip_undefined_reference_warnings_on: ["CHANGELOG.md"], groups_for_modules: [ # Ecto.Adapters.SQL, diff --git a/mix.lock b/mix.lock index 7143ea6ee..15c5c8d0f 100644 --- a/mix.lock +++ b/mix.lock @@ -7,11 +7,12 @@ "deep_merge": {:hex, :deep_merge, "1.0.0", "b4aa1a0d1acac393bdf38b2291af38cb1d4a52806cf7a4906f718e1feb5ee961", [:mix], [], "hexpm", "ce708e5f094b9cd4e8f2be4f00d2f4250c4095be93f8cd6d018c753894885430"}, "earmark_parser": {:hex, :earmark_parser, "1.4.44", "f20830dd6b5c77afe2b063777ddbbff09f9759396500cdbe7523efd58d7a339c", [:mix], [], "hexpm", "4778ac752b4701a5599215f7030989c989ffdc4f6df457c5f36938cc2d2a2750"}, "ecto": {:git, "https://github.com/elixir-ecto/ecto.git", "bf242348cdf89c056a977668da707b9937208efe", [branch: "master"]}, - "ex_doc": {:hex, :ex_doc, "0.39.1", "e19d356a1ba1e8f8cfc79ce1c3f83884b6abfcb79329d435d4bbb3e97ccc286e", [:mix], [{:earmark_parser, "~> 1.4.44", [hex: :earmark_parser, repo: "hexpm", optional: false]}, {:makeup_c, ">= 0.1.0", [hex: :makeup_c, repo: "hexpm", optional: true]}, {:makeup_elixir, "~> 0.14 or ~> 1.0", [hex: :makeup_elixir, repo: "hexpm", optional: false]}, {:makeup_erlang, "~> 0.1 or ~> 1.0", [hex: :makeup_erlang, repo: "hexpm", optional: false]}, {:makeup_html, ">= 0.1.0", [hex: :makeup_html, repo: "hexpm", optional: true]}], "hexpm", "8abf0ed3e3ca87c0847dfc4168ceab5bedfe881692f1b7c45f4a11b232806865"}, + "ex_doc": {:hex, :ex_doc, "0.39.3", "519c6bc7e84a2918b737aec7ef48b96aa4698342927d080437f61395d361dcee", [:mix], [{:earmark_parser, "~> 1.4.44", [hex: :earmark_parser, repo: "hexpm", optional: false]}, {:makeup_c, ">= 0.1.0", [hex: :makeup_c, repo: "hexpm", optional: true]}, {:makeup_elixir, "~> 0.14 or ~> 1.0", [hex: :makeup_elixir, repo: "hexpm", optional: false]}, {:makeup_erlang, "~> 0.1 or ~> 1.0", [hex: :makeup_erlang, repo: "hexpm", optional: false]}, {:makeup_html, ">= 0.1.0", [hex: :makeup_html, repo: "hexpm", optional: true]}], "hexpm", "0590955cf7ad3b625780ee1c1ea627c28a78948c6c0a9b0322bd976a079996e1"}, "jason": {:hex, :jason, "1.4.4", "b9226785a9aa77b6857ca22832cffa5d5011a667207eb2a0ad56adb5db443b8a", [:mix], [{:decimal, "~> 1.0 or ~> 2.0", [hex: :decimal, repo: "hexpm", optional: true]}], "hexpm", "c5eb0cab91f094599f94d55bc63409236a8ec69a21a67814529e8d5f6cc90b3b"}, "makeup": {:hex, :makeup, "1.2.1", "e90ac1c65589ef354378def3ba19d401e739ee7ee06fb47f94c687016e3713d1", [:mix], [{:nimble_parsec, "~> 1.4", [hex: :nimble_parsec, repo: "hexpm", optional: false]}], "hexpm", "d36484867b0bae0fea568d10131197a4c2e47056a6fbe84922bf6ba71c8d17ce"}, "makeup_elixir": {:hex, :makeup_elixir, "1.0.1", "e928a4f984e795e41e3abd27bfc09f51db16ab8ba1aebdba2b3a575437efafc2", [:mix], [{:makeup, "~> 1.0", [hex: :makeup, repo: "hexpm", optional: false]}, {:nimble_parsec, "~> 1.2.3 or ~> 1.3", [hex: :nimble_parsec, repo: "hexpm", optional: false]}], "hexpm", "7284900d412a3e5cfd97fdaed4f5ed389b8f2b4cb49efc0eb3bd10e2febf9507"}, - "makeup_erlang": {:hex, :makeup_erlang, "1.0.2", "03e1804074b3aa64d5fad7aa64601ed0fb395337b982d9bcf04029d68d51b6a7", [:mix], [{:makeup, "~> 1.0", [hex: :makeup, repo: "hexpm", optional: false]}], "hexpm", "af33ff7ef368d5893e4a267933e7744e46ce3cf1f61e2dccf53a111ed3aa3727"}, + "makeup_erlang": {:hex, :makeup_erlang, "1.0.3", "4252d5d4098da7415c390e847c814bad3764c94a814a0b4245176215615e1035", [:mix], [{:makeup, "~> 1.0", [hex: :makeup, repo: "hexpm", optional: false]}], "hexpm", "953297c02582a33411ac6208f2c6e55f0e870df7f80da724ed613f10e6706afd"}, + "makeup_sql": {:hex, :makeup_sql, "0.1.3", "208d3b09471c100abd140318ef9f41dbce16efcf98a774c6e8bcc9830884c82e", [:mix], [{:makeup, "~> 1.0", [hex: :makeup, repo: "hexpm", optional: false]}, {:nimble_parsec, "~> 1.1", [hex: :nimble_parsec, repo: "hexpm", optional: false]}], "hexpm", "a9ec32cc16399b3b5a86565a289bab3fe56f6f789366358e15ee133ed71dddd4"}, "myxql": {:hex, :myxql, "0.8.0", "60c60e87c7320d2f5759416aa1758c8e7534efbae07b192861977f8455e35acd", [:mix], [{:db_connection, "~> 2.4.1 or ~> 2.5", [hex: :db_connection, repo: "hexpm", optional: false]}, {:decimal, "~> 1.6 or ~> 2.0", [hex: :decimal, repo: "hexpm", optional: false]}, {:geo, "~> 3.4 or ~> 4.0", [hex: :geo, repo: "hexpm", optional: true]}, {:jason, "~> 1.0", [hex: :jason, repo: "hexpm", optional: true]}, {:table, "~> 0.1.0", [hex: :table, repo: "hexpm", optional: true]}], "hexpm", "1ec0ceb26fb3cd0f8756519cf4f0e4f9348177a020705223bdf4742a2c44d774"}, "nimble_parsec": {:hex, :nimble_parsec, "1.4.2", "8efba0122db06df95bfaa78f791344a89352ba04baedd3849593bfce4d0dc1c6", [:mix], [], "hexpm", "4b21398942dda052b403bbe1da991ccd03a053668d147d53fb8c4e0efe09c973"}, "postgrex": {:hex, :postgrex, "0.19.0", "f7d50e50cb42e0a185f5b9a6095125a9ab7e4abccfbe2ab820ab9aa92b71dbab", [:mix], [{:db_connection, "~> 2.1", [hex: :db_connection, repo: "hexpm", optional: false]}, {:decimal, "~> 1.5 or ~> 2.0", [hex: :decimal, repo: "hexpm", optional: false]}, {:jason, "~> 1.0", [hex: :jason, repo: "hexpm", optional: true]}, {:table, "~> 0.1.0", [hex: :table, repo: "hexpm", optional: true]}], "hexpm", "dba2d2a0a8637defbf2307e8629cb2526388ba7348f67d04ec77a5d6a72ecfae"},