Automatic Migrations for PostgreSQL with Atlas
PostgreSQL is an open-source relational database management system known for its reliability and robust feature set. It offers powerful capabilities for handling complex queries, ensuring data integrity, and scaling to meet the needs of growing applications.
However, managing a large database schema in Postgres can be challenging due to the complexity of related data structures and the need for coordinated schema changes across multiple teams and applications.
Enter: Atlas
Atlas helps developers manage their database schema as code - abstracting away the intricacies of database schema management. With Atlas, users provide the desired state of the database schema and Atlas automatically plans the required migrations.
In this guide, we will dive into setting up Atlas for PostgreSQL, and introduce the different workflows available.
Prerequisites
- Docker
- Atlas installed on your machine:
- macOS + Linux
- Homebrew
- Docker
- Windows
- Manual Installation
To download and install the latest release of the Atlas CLI, simply run the following in your terminal:
curl -sSf https://atlasgo.sh | sh
Get the latest release with Homebrew:
brew install ariga/tap/atlas
To pull the Atlas image and run it as a Docker container:
docker pull arigaio/atlas
docker run --rm arigaio/atlas --help
If the container needs access to the host network or a local directory, use the --net=host
flag and mount the desired
directory:
docker run --rm --net=host \
-v $(pwd)/migrations:/migrations \
arigaio/atlas migrate apply
--url "mysql://root:pass@:3306/test"
Download the latest release and move the atlas binary to a file location on your system PATH.
Inspecting our Database
Let's start off by spinning up a database using Docker:
docker run --rm -d --name atlas-demo -e POSTGRES_PASSWORD=pass -e POSTGRES_DB=demo -p 5432:5432 postgres
For this example we will begin with a minimal database with a users
table and an id
as the primary key.
CREATE TABLE "users" (
"id" bigint,
"name" varchar NOT NULL,
PRIMARY KEY ("id")
);
To create the table above on our local database, we can run the following command:
docker exec -i atlas-demo psql -U postgres -c "CREATE TABLE \"users\" (\"id\" bigint, \"name\" varchar NOT NULL, PRIMARY KEY (\"id\"));" demo
The atlas schema inspect
command supports reading the database description provided by a URL and outputting it in
different formats, including Atlas DDL (default), SQL, and JSON. In this guide, we will
demonstrate the flow using both the Atlas DDL and SQL formats, as the JSON format is often used for processing the
output using jq
.
- Atlas DDL (HCL)
- SQL
To inspect our locally-running Postgres instance, use the -u
flag and write the output to a file named schema.hcl
:
atlas schema inspect -u "postgres://postgres:pass@:5432/demo?search_path=public&sslmode=disable" > schema.hcl
Open the schema.hcl
file to view the Atlas schema that describes our database.
table "users" {
schema = schema.public
column "id" {
null = false
type = bigint
}
column "name" {
null = false
type = character_varying
}
primary_key {
columns = [column.id]
}
}
schema "public" {
comment = "standard public schema"
}
This first block represents a table resource with id
and name
columns. The schema
field references the public
schema that is defined in the block below. In addition, the primary_key
sub-block defines the id
column as the primary key for the table. Atlas strives to mimic the syntax of the database
that the user is working against. In this case, the type for the id
column is bigint
, and character_varying
for the name
column.
To inspect our locally-running Postgres instance, use the -u
flag and write the output to a file named schema.sql
:
atlas schema inspect -u "postgres://postgres:pass@:5432/demo?search_path=public&sslmode=disable" --format '{{ sql . }}' > schema.sql
Open the schema.sql
file to view the inspected SQL schema that describes our database.
-- Create "users" table
CREATE TABLE "users" (
"id" bigint NOT NULL,
"name" character varying NOT NULL,
PRIMARY KEY ("id")
);
For in-depth details on the atlas schema inspect
command, covering aspects like inspecting specific schemas,
handling multiple schemas concurrently, excluding tables, and more, refer to our documentation
here.
To generate an Entity Relationship Diagram (ERD), or a visual representation of our schema, we can add the -w
flag
to the inspect command:
atlas schema inspect -u "postgres://postgres:pass@:5432/demo?search_path=public&sslmode=disable" -w
Declarative Migrations
The declarative approach lets users manage schemas by defining the desired state of the database as code. Atlas then inspects the target database and calculates an execution plan to reconcile the difference between the desired and actual states. Let's see this in action.
We will start off by making a change to our schema file, such as adding a repos
table:
- Atlas DDL (HCL)
- SQL
table "users" {
schema = schema.public
column "id" {
null = false
type = bigint
}
column "name" {
null = false
type = character_varying
}
primary_key {
columns = [column.id]
}
}
table "repos" {
schema = schema.public
column "id" {
type = bigint
null = false
}
column "name" {
type = character_varying
null = false
}
column "owner_id" {
type = bigint
null = false
}
primary_key {
columns = [column.id]
}
foreign_key "fk_repo_owner" {
columns = [column.owner_id]
ref_columns = [table.users.column.id]
}
schema "public" {
comment = "standard public schema"
}
-- Create "users" table
CREATE TABLE "users" (
"id" bigint NOT NULL,
"name" character varying NOT NULL,
PRIMARY KEY ("id")
);
-- Create "repos" table
CREATE TABLE "repos" (
"id" bigint NOT NULL,
"name" character varying NOT NULL,
"owner_id" bigint NOT NULL,
PRIMARY KEY ("id"),
FOREIGN KEY ("id") REFERENCES "users" ("id")
);
Now that our desired state has changed, to apply these changes to our database, Atlas will plan a migration for us
by running the atlas schema apply
command:
- Atlas DDL (HCL)
- SQL
atlas schema apply \
-u "postgres://postgres:pass@:5432/demo?search_path=public&sslmode=disable" \
--to file://schema.hcl \
--dev-url "docker://postgres/15/dev?search_path=public"
atlas schema apply \
-u "postgres://postgres:pass@:5432/demo?search_path=public&sslmode=disable" \
--to file://schema.sql \
--dev-url "docker://postgres/15/dev?search_path=public"
Approve the proposed changes, and that's it! You have successfully run a declarative migration.
For a more detailed description of the atlas schema apply
command refer to our documentation
here.
To ensure that the changes have been made to the schema, let's run the inspect
command with the -w
flag once more
and view the ERD:
Versioned Migrations
Alternatively, the versioned migration workflow, sometimes called "change-based migrations", allows each change to the database schema to be checked-in to source control and reviewed during code-review. Users can still benefit from Atlas intelligently planning migrations for them, however they are not automatically applied.
Creating the first migration
In the versioned migration workflow, our database state is managed by a migration directory. The migration directory holds all of the migration files created by Atlas, and the sum of all files in lexicographical order represents the current state of the database.
To create our first migration file, we will run the atlas migrate diff
command, and we will provide the necessary parameters:
--dir
the URL to the migration directory, by default it is file://migrations.--to
the URL of the desired state. A state can be specified using a database URL, HCL or SQL schema, or another migration directory.--dev-url
a URL to a Dev Database that will be used to compute the diff.
- Atlas DDL (HCL)
- SQL
atlas migrate diff initial \
--to file://schema.hcl \
--dev-url "docker://postgres/15/dev?search_path=public"
atlas migrate diff initial \
--to file://schema.sql \
--dev-url "docker://postgres/15/dev?search_path=public"
Run ls migrations
, and you'll notice that Atlas has automatically created a migration directory for us, as well as
two files:
- 20240221153232_initial.sql
- atlas.sum
-- Create "users" table
CREATE TABLE "public"."users" (
"id" bigint NOT NULL,
"name" character varying NOT NULL,
PRIMARY KEY ("id")
);
-- Create "repos" table
CREATE TABLE "public"."repos" (
"id" bigint NOT NULL,
"name" character varying NOT NULL,
"owner_id" bigint NOT NULL,
PRIMARY KEY ("id"),
CONSTRAINT "fk_repo_owner" FOREIGN KEY ("owner_id") REFERENCES "public"."users" ("id") ON UPDATE NO ACTION ON DELETE NO ACTION
);
h1:19FfvbJvenroC2lBiH2G46Oeao6YDJSqz7co+bNKCFY=
20240221153232_initial.sql h1:ACoDqBEQ80lC6pTSyjEL1wsjZhc5RLzOrVisBb+SEDQ=
The migration file represents the current state of our database, and the sum file is used by Atlas to maintain the integrity of the migration directory. To learn more about the sum file, read the documentation.