Automatic Migration Planning
The atlas migrate diff
command streamlines the process of writing schema migrations by automatically generating the
SQL scripts needed to migrate a database schema from its current state to the new desired state. How does it work?
Developers define the desired state and Atlas maintains the migrations
directory, which contains the explicit SQL
scripts to move from one version to the next. The desired state can be defined using an HCL or
SQL schema definition, a database URL, or an external schemas like ORM.
Summary
To get started with versioned migrations, run atlas migrate diff
. This command generates a new migration file that aligns
the migration directory with the state defined by the desired schema. Below are a few examples of how to use this command
to generate migrations from various sources:
- SQL Schema
- HCL Schema
- ORM
- Database Schema
- Database (multiple schemas)
MySQL/MariaDB:
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "docker://mysql/8/dev" # Or: "docker://mariadb/latest/dev"
PostgreSQL:
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "docker://postgres/15/dev?search_path=public"
MySQL/MariaDB:
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://mysql/8/dev" # Or: "docker://mariadb/latest/dev"
PostgreSQL:
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://postgres/15/dev?search_path=public"
MySQL/MariaDB:
atlas migrate diff create_users \
--env "gorm"
--dev-url "docker://mysql/8/dev" # Or: "docker://mariadb/latest/dev"
PostgreSQL:
atlas migrate diff create_users \
--env "gorm"
--dev-url "docker://postgres/15/dev?search_path=public"
To learn more on how to configure Atlas to read the desired state of a schema from an ORM definition, see the external schema documentation.
MySQL/MariaDB:
atlas migrate diff create_users \
--dir "file://migrations" \
--to "mysql://root:pass@:3306/public" \
--dev-url "docker://mysql/8/dev" # Or: "docker://mariadb/latest/dev"
PostgreSQL:
atlas migrate diff create_users \
--dir "file://migrations" \
--to "postgres://postgres:pass@localhost:5432/database?search_path=public&sslmode=disable" \
--dev-url "docker://postgres/15/dev?search_path=public"
MySQL/MariaDB:
atlas migrate diff create_users \
--dir "file://migrations" \
--to "mysql://root:pass@:3306/" \
--dev-url "docker://mysql/8" # Or: "docker://mariadb"
PostgreSQL:
atlas migrate diff create_users \
--dir "file://migrations" \
--to "postgres://postgres:pass@localhost:5432/database?sslmode=disable" \
--dev-url "docker://postgres/15/dev"
Teams that have connected their project to Atlas Cloud (see setup) will get a prompt in the CLI if their migration directory is out of sync with the latest version in Atlas Cloud. This ensures that new migration files are added in a sequential order, preventing unexpected behavior. For example:
atlas migrate diff --env dev
? Your directory is outdated (2 migrations behind). Continue or Abort:
▸ Continue (Rebase later)
Abort (Pull changes and re-run the command)
Additionally, the atlas migrate lint
command helps enforce this requirement during the CI stage.
Learn more on how to integrate Atlas into your GitHub Actions or GitLab CI pipelines.
Generate migrations from HCL schemas
Suppose we have an Atlas schema with one table and an empty migration directory:
- MySQL
- MariaDB
- PostgreSQL
- SQLite
- SQL Server
- ClickHouse
- Redshift
schema "test" {}
table "users" {
schema = schema.test
column "id" {
type = int
}
}
schema "test" {}
table "users" {
schema = schema.test
column "id" {
type = int
}
}
schema "test" {}
table "users" {
schema = schema.test
column "id" {
type = int
}
}
schema "default" {}
table "users" {
schema = schema.default
engine = Memory
column "id" {
type = Int
}
}
schema "dbo" {}
table "users" {
schema = schema.dbo
column "id" {
type = int
}
}
schema "default" {}
table "users" {
schema = schema.default
engine = Memory
column "id" {
type = Int
}
}
schema "test" {}
table "users" {
schema = schema.test
column "id" {
type = int
}
}
Let's run atlas migrate diff
with the necessary parameters to generate a migration script for
creating our users
table:
--dir
the URL to the migration directory, by default it isfile://migrations
.--to
the URL of the desired state, an HCL or SQL schema definition, or a database URL.--dev-url
a URL to a Dev Database that will be used to compute the diff.--format
(optional) - Go template to use to format the output.
- MySQL
- MariaDB
- PostgreSQL
- SQLite
- SQL Server
- ClickHouse
- Redshift
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://mysql/8/test"
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://mariadb/latest/test"
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://postgres/15/test?search_path=public"
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "sqlite://file?mode=memory"
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://sqlserver/2022-latest/test"
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://clickhouse/23.11/test"
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "redshift://user:pass@redshift-cluster:5439/dev?search_path=public&sslmode=disable"
If you are working with multiple schemas and want qualified identifiers to appear in the diff output, omit the schema
name in the --dev-url
flag. In PostgreSQL, this corresponds to the search_path
; in MySQL/MariaDB, it is the database
in the URL path.
Run ls migrations
, and you will notice Atlas created 2 files:
- 20220811074144_create_users.sql
- atlas.sum
By default, migration files are named with the following format {{ now }}_{{ name }}.sql
.
If you wish to use a different file format, use the format
query parameter in the directory URL.
-- create "users" table
CREATE TABLE `users` (`id` int NOT NULL) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
In addition to the migration directory, Atlas maintains a file name atlas.sum
which is used
to ensure the integrity of the migration directory and force developers to deal with situations
where migration order or contents was modified after the fact.
h1:t1fEP1rSsGf1gYrYCjsGyEyuM0cnhATlq93B7h8uXxY=
20220811074144_create_users.sql h1:liZcCBbAn/HyBTqBAEVar9fJNKPTb2Eq+rEKZeCFC9M=
Let's repeat the process above by changing our HCL schema file and running Atlas migration authoring again.
We add a new column name
to our HCL schema:
- MySQL
- MariaDB
- SQLite
- PostgreSQL
- SQL Server
- ClickHouse
- Redshift
schema "test" {}
table "users" {
schema = schema.test
column "id" {
type = int
}
column "name" {
type = varchar(255)
}
}
schema "test" {}
table "users" {
schema = schema.test
column "id" {
type = int
}
column "name" {
type = varchar(255)
}
}
schema "test" {}
table "users" {
schema = schema.test
column "id" {
type = int
}
column "name" {
type = varchar(255)
}
}
schema "test" {}
table "users" {
schema = schema.test
column "id" {
type = int
}
column "name" {
type = varchar(255)
}
}
schema "dbo" {}
table "users" {
schema = schema.dbo
column "id" {
type = int
}
column "name" {
type = nvarchar(255)
}
}
schema "default" {}
table "users" {
schema = schema.test
engine = Memory
column "id" {
type = Int
}
column "name" {
type = String
}
}
schema "test" {}
table "users" {
schema = schema.test
column "id" {
type = int
}
column "name" {
type = varchar(255)
}
}
Then, run atlas migrate diff
:
- MySQL
- MariaDB
- PostgreSQL
- SQLite
- SQL Server
- ClickHouse
- Redshift
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://mysql/8/dev"
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://mariadb/latest/dev"
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://postgres/15/dev?search_path=public"
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "sqlite://dev?mode=memory"
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://sqlserver/2022-latest"
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://clickhouse/23.11/dev"
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "redshift://user:pass@redshift-cluster:5439/dev?search_path=public&sslmode=disable"
If you are working with multiple schemas and want qualified identifiers to appear in the diff output, omit the schema
name in the --dev-url
flag. In PostgreSQL, this corresponds to the search_path
; in MySQL/MariaDB, it is the database
in the URL path.
You will notice Atlas added a new file to the migration directory:
- 20220811074144_create_users.sql
- 20220811074314_add_users_name.sql
- atlas.sum
-- create "users" table
CREATE TABLE `users` (`id` int NOT NULL) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
-- modify "users" table
ALTER TABLE `users` ADD COLUMN `name` varchar(255) NOT NULL;
h1:w2ODzVxhTKdBVBdzqntHw7rHV8lKQF98TmNevOEZfIo=
20220811074144_create_users_table.sql h1:KnMSZM/E4TBGidYCZ+UHxkHEWaRWeyuPIUjSHRybQqA=
20220811074314_add_users_name.sql h1:jUpaANgD0SjI5DjaHuJxtHZ6Wq98act0MmE5oZ+NRU0=
The following diagram explains how it works. Atlas loads the current state by replaying the migration directory onto the provided dev database, compares it against the desired state and writes a new migration script for moving from the current to the desired state.
Generate migrations from SQL schemas
Atlas allows you to define your desired state using SQL schemas. An SQL schema can be a single file containing CREATE
and ALTER
statements, or a directory with multiple SQL files. As an example, suppose we have an SQL schema with one
table and an empty migration directory:
- MySQL
- MariaDB
- PostgreSQL
- SQLite
- SQL Server
- ClickHouse
- Redshift
CREATE TABLE `users` (
`id` int NOT NULL
)
CREATE TABLE `users` (
`id` int NOT NULL
)
CREATE TABLE `users` (
`id` int NOT NULL
)
CREATE TABLE `users` (
`id` int NOT NULL
)
CREATE TABLE [users] (
[id] int NOT NULL
)
CREATE TABLE `users` (
`id` int NOT NULL
) ENGINE = Memory
CREATE TABLE "users" (
"id" int NOT NULL
)
Let's run atlas migrate diff
with the necessary parameters to generate a migration script for
creating our users
table:
--dir
the URL to the migration directory, by default it isfile://migrations
.--to
the URL of the desired state, an HCL or SQL schema definition, or a database URL.--dev-url
a URL to a Dev Database that will be used to compute the diff.
- MySQL
- MariaDB
- PostgreSQL
- SQLite
- SQL Server
- ClickHouse
- Redshift
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "docker://mysql/8/dev"
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "docker://mariadb/latest/dev"
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "docker://postgres/15/dev?search_path=public"
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "sqlite://file?mode=memory"
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "docker://sqlserver/2022-latest/dev"
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "docker://clickhouse/23.11/dev"
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "redshift://user:pass@redshift-cluster:5439/dev?search_path=public&sslmode=disable"
If you are working with multiple schemas and want qualified identifiers to appear in the diff output, omit the schema
name in the --dev-url
flag. In PostgreSQL, this corresponds to the search_path
; in MySQL/MariaDB, it is the database
in the URL path.
Run ls migrations
, and you will notice Atlas created 2 files:
- 20220811074144_create_users.sql
- atlas.sum
By default, migration files are named with the following format {{ now }}_{{ name }}.sql
.
If you wish to use a different file format, use the format
query parameter in the directory URL.
-- create "users" table
CREATE TABLE `users` (`id` int NOT NULL) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
In addition to the migration directory, Atlas maintains a file name atlas.sum
which is used
to ensure the integrity of the migration directory and force developers to deal with situations
where migration order or contents was modified after the fact.
h1:t1fEP1rSsGf1gYrYCjsGyEyuM0cnhATlq93B7h8uXxY=
20220811074144_create_users.sql h1:liZcCBbAn/HyBTqBAEVar9fJNKPTb2Eq+rEKZeCFC9M=
Let's repeat the process above by changing our SQL schema file and running Atlas migration authoring again.
We add a new column name
to our SQL schema:
- MySQL
- MariaDB
- PostgreSQL
- SQLite
- SQL Server
- ClickHouse
- Redshift
CREATE TABLE `users` (
`id` int NOT NULL,
`name` varchar(255) NOT NULL
)
CREATE TABLE `users` (
`id` int NOT NULL,
`name` varchar(255) NOT NULL
)
CREATE TABLE "users" (
"id" int NOT NULL,
"name" varchar(255) NOT NULL
)
CREATE TABLE `users` (
`id` int NOT NULL,
`name` varchar(255) NOT NULL
)
CREATE TABLE [users] (
[id] int NOT NULL,
[name] nvarchar(255) NOT NULL
)
CREATE TABLE `users` (
`id` int NOT NULL,
`name` varchar(255) NOT NULL
) ENGINE = Memory
CREATE TABLE "users" (
"id" int NOT NULL,
"name" varchar(255) NOT NULL
)
Then, run atlas migrate diff
:
- MySQL
- MariaDB
- PostgreSQL
- SQLite
- SQL Server
- ClickHouse
- Redshift
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "docker://mysql/8/dev"
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "docker://mariadb/latest/dev"
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "docker://postgres/15/dev?search_path=public"
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "sqlite://file?mode=memory"
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "docker://sqlserver/2022-latest/dev"
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "docker://clickhouse/23.11/dev"
atlas migrate diff add_users_name \
--dir "file://migrations" \
--to "file://schema.sql" \
--dev-url "redshift://user:pass@redshift-cluster:5439/dev?search_path=public&sslmode=disable"
If you are working with multiple schemas and want qualified identifiers to appear in the diff output, omit the schema
name in the --dev-url
flag. In PostgreSQL, this corresponds to the search_path
; in MySQL/MariaDB, it is the database
in the URL path.
You will notice Atlas added a new file to the migration directory:
- 20220811074144_create_users.sql
- 20220811074314_add_users_name.sql
- atlas.sum
-- create "users" table
CREATE TABLE `users` (`id` int NOT NULL) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
-- modify "users" table
ALTER TABLE `users` ADD COLUMN `name` varchar(255) NOT NULL;
h1:w2ODzVxhTKdBVBdzqntHw7rHV8lKQF98TmNevOEZfIo=
20220811074144_create_users_table.sql h1:KnMSZM/E4TBGidYCZ+UHxkHEWaRWeyuPIUjSHRybQqA=
20220811074314_add_users_name.sql h1:jUpaANgD0SjI5DjaHuJxtHZ6Wq98act0MmE5oZ+NRU0=
To summarize, the example above explains how Atlas loads the current state by replaying the migration directory onto the specified dev-database, compares it to the desired state defined in the SQL schema file, and writes a new migration script for moving from the current to the desired state.
Generate migrations from database schemas
Suppose we have a database with a users
table that was created manually or by an ORM like Ent,
we can tell Atlas that this is our desired state, and we want to generate a migration script to create this table.
mysql> describe users;
+-------+------+------+-----+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+-------+------+------+-----+---------+-------+
| id | int | YES | | NULL | |
+-------+------+------+-----+---------+-------+
Let's run atlas migrate diff
with the necessary parameters to generate a migration script for
creating our users
table:
atlas migrate diff create_users \
--dir "file://migrations" \
--to "mysql://root:pass@:3306/public" \
--dev-url "docker://mysql/8/dev"
Run ls migrations
, and you will notice Atlas created 2 files:
- 20220811102532_create_users.sql
- atlas.sum
By default, migration files are named with the following format {{ now }}_{{ name }}.sql
.
If you wish to use a different file format, use the format
query parameter in the directory URL.
-- create "users" table
CREATE TABLE `users` (`id` int NOT NULL) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
In addition to the migration directory, Atlas maintains a file name atlas.sum
which is used
to ensure the integrity of the migration directory and force developers to deal with situations
where migration order or contents was modified after the fact.
h1:/6UW2WaPV1laJpEB7oVesKB9RuL59dgDhlTp5atDbNg=
20220811102532_create_users.sql h1:IJiVpbh3FLMeDJSzxxKPuFU3m4AHBgThBfs3VFXAXVo=
Generate migrations with custom qualifiers
When working on a specific database schema, Atlas generates migration scripts without schema qualifiers
to allow executing them multiple times on different schemas. However, in some cases, it is necessary
to have those qualifiers. To address this, Atlas allows passing another flag to migrate diff
named --qualifier
.
Let's run the example above, with the --qualifier
flag and compare
the output:
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://mysql/8/dev" \
--qualifier "market"
Running cat migrations/*.sql
will print the same migration script but the users
table will be qualified with
the market
schema:
-- create "users" table
CREATE TABLE `market`.`users` (`id` int NOT NULL, `name` varchar(255) NOT NULL) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
Generate migrations with custom formats
Some migration tools use a different file format than the one used by Atlas. You can control the format of the migration
directory by passing in the format
query parameter to the migration directory URL.
atlas migrate diff create_users \
--dir "file://migrations?format=golang-migrate" \
--to "file://schema.hcl" \
--dev-url "docker://mysql/8/dev"
Run ls migrations
, and you will notice Atlas created 3 files:
- 20220811114629_create_users.up.sql
- 20220811114629_create_users.down.sql
- atlas.sum
-- create "users" table
CREATE TABLE `users` (`name` int NOT NULL) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
-- reverse: create "users" table
DROP TABLE `users`;
In addition to the migration directory, Atlas maintains a file name atlas.sum
which is used
to ensure the integrity of the migration directory and force developers to deal with situations
where migration order or contents was modified after the fact.
h1:NRHsNIjvSSzprr/EzMdtszQg3t3pVLk4G4N1tX4rMfk=
20220811114629_create_users.up.sql h1:Ng3GHrdk2davokjOctgVdxC+6QsK4JzaLX6RT3QstJc=
Generate migrations for the entire database
Atlas supports generating migrations for databases or multiple schemas. In PostgreSQL, a database can
be created with the CREATE DATABASE
command and can hold multiple schemas. In MySQL however, a database
is an instance with one or more schemas.
Suppose we have an Atlas schema that defines two database schemas where each one contains a single table.
schema "auth" {}
schema "market" {}
table "users" {
schema = schema.market
column "name" {
type = int
}
}
table "tokens" {
schema = schema.auth
column "value" {
type = int
}
}
Let's run atlas migrate diff
to generate migration scripts for creating the entire schema.
However, unlike the previous examples where the --dev-url
flag was set to a URL
of a specific schema, in this case we omit the schema name from the connection string.
- MySQL
- PostgreSQL
atlas migrate diff create_all \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://mysql/8"
Running cat migrations/*.sql
will print the followings:
-- add new schema named "auth"
CREATE DATABASE `auth`;
-- add new schema named "market"
CREATE DATABASE `market`;
-- create "tokens" table
CREATE TABLE `auth`.`tokens` (`value` int NOT NULL) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
-- create "users" table
CREATE TABLE `market`.`users` (`name` int NOT NULL) CHARSET utf8mb4 COLLATE utf8mb4_0900_ai_ci;
atlas migrate diff create_all \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://postgres/15"
Running cat migrations/*.sql
will print the followings:
-- Add new schema named "auth"
CREATE SCHEMA "auth";
-- Add new schema named "market"
CREATE SCHEMA "market";
-- create "tokens" table
CREATE TABLE "auth"."tokens" ("value" integer NOT NULL);
-- create "users" table
CREATE TABLE "market"."users" ("name" integer NOT NULL);
As you can see, Atlas generates statements for creating the auth
and market
schemas,
and added them as qualifiers in the created tables.
Diff Policy
Atlas allows configuring the schema diffing policy in project configuration to fine-tune or modify suggested changes before they are written to the migration directory:
- Skip Destructive
- Concurrent Indexes
variable "destructive" {
type = bool
default = false
}
env "local" {
migration {
dir = "file://migrations"
}
diff {
skip {
drop_schema = !var.destructive
drop_table = !var.destructive
}
}
}
The usage is as follows:
atlas migrate diff --env "local" --var "destructive=true"
env "local" {
diff {
// By default, indexes are not created or dropped concurrently.
concurrent_index {
add = true
drop = true
}
}
}
Indented SQL
The migrate diff
command generates a list of SQL statements without indentation by default. If you would like to
generate the SQL statements with indentation, use the --format
flag. For example:
# Indent SQL statements with 2 spaces.
atlas migrate diff create_users \
--dir "file://migrations" \
--to "file://schema.hcl" \
--dev-url "docker://mysql/8/dev" \
--format '{{ sql . " " }}'
Exclude Objects
This option is not recommended for general use. It is intended for use when you encounter limitations in the Atlas schema definition or when your schema references objects that are not part of the desired state (schema) and you want Atlas to ignore their existence.
Atlas allows setting exclusion patterns for the migrations directory. Objects that match the exclusion patterns are not
considered during the migrate diff
stage.
Using this option, users can (manually) define objects such as tables, functions, and foreign keys in the migration
directory that are not part of the desired state (schema), and instruct Atlas not to drop them during the
migrate diff
stage - essentially, to ignore their existence.
env "dev" {
migration {
exclude = ["*.constraint_name"]
}
}
For more examples, see the exclude documentation.