The Perl Toolchain Summit needs more sponsors. If your company depends on Perl, please support this very important event.

Name

sqitchtutorial - A tutorial introduction to Sqitch

Synopsis

  sqitch *

Description

This tutorial explains how to create a sqitch-enabled project, use a VCS for deployment planning, and work with other developers to make sure changes remain in sync and in the proper order.

We'll start by creating new project from scratch, a fictional antisocial networking site called Flipr. All examples use Git as the VCS and PostgreSQL as the storage engine, but for the most part you can substitute other VCSes and database engines in the examples as appropriate.

Starting a New Project

Usually the first thing to do when starting a new project is to create a source code repository. So let's do that with Git:

  > mkdir flipr
  > cd flipr 
  > git init .
  Initialized empty Git repository in /flipr/.git/
  > touch README.md
  > git add .
  > git commit -am 'Fist post!'

If you're a Git user and want to follow along the history, the repository used in these examples is on GitHub.

Now that we have a repository, let's get started with Sqitch. Every Sqitch project must have a name associated with it, and, optionally, a unique URI. We recommend including the URI, as it increases the uniqueness of object identifiers internally, so let's specify one when we initialize Sqitch:

  > sqitch --engine pg init flipr --uri https://github.com/theory/sqitch-intro/
  Created sqitch.conf
  Created sqitch.plan
  Created deploy/
  Created revert/
  Created test/

Let's have a look at sqitch.conf:

  [core]
      engine = pg
      # plan_file = sqitch.plan
      # top_dir = .
      # deploy_dir = deploy
      # revert_dir = revert
      # test_dir = test
      # extension = sql
  # [core "pg"]
      # db_name = 
      # client = /usr/local/pgsql/bin/psql
      # sqitch_schema = sqitch
      # password = 
      # port = 
      # host = 
      # username = 

Good, it picked up on the fact that we're creating changes for the PostgreSQL engine, thanks to the --engine pg option, and saved it to the file. Furthermore, it wrote a commented-out [core "pg"] section with all the available PostgreSQL engine-specific settings commented out and ready to be edited as appropriate.

By default, Sqitch will read sqitch.conf in the current directory for settings. But it will also read ~/.sqitch/sqitch.conf for global settings. Since PostgreSQL's psql client is not in the path on my system, let's go ahead an tell it globally where to find the client:

  > sqitch config --user core.pg.client /usr/local/pgsql/bin/psql

And let's also tell it who we are, since this data will be used in all of our projects:

  > sqitch config --user user.name 'Marge N. O’Vera'
  > sqitch config --user user.email 'marge@example.com'

Have a look at ~/.sqitch/sqitch.conf and you'll see this:

  [core "pg"]
        client = /usr/local/pgsql/bin/psql
  [user]
        name = Marge N. O’Vera
        email = marge@example.com

Which means that Sqitch should be able to find psql for any project, and that it will always properly identify us when planning and committing changes.

Back to the repository. Have a look at the plan file, sqitch.plan:

  %syntax-version=1.0.0-b1
  %project=flipr
  %uri=https://github.com/theory/sqitch-intro/
  

Note that it has picked up on the name and URI of the app we're building. This data will be used in the future to allow for cross-project dependency specification. The %syntax-version pragma is always set by Sqitch, so that it always knows how to parse the plan, even if the format changes in the future.

Let's commit these changes and start creating the database changes.

  > git add .
  > git commit -am 'Initialize Sqitch configuration.'
  [master bd7e3f0] Initialize Sqitch configuration.
   2 files changed, 20 insertions(+)
   create mode 100644 sqitch.conf
   create mode 100644 sqitch.plan

Our First Change

First, our project will need a schema. This creates a nice namespace for all of the objects that will be part of the flipr app. Run this command:

  > sqitch add appschema -n 'App schema for all flipr objects.'
  Created deploy/appschema.sql
  Created revert/appschema.sql
  Created test/appschema.sql
  Added "appschema" to sqitch.plan

The add command adds a database change to the plan and writes deploy, revert, and test scripts that represent the change. Now we edit these files. The deploy script's job is to create the schema. So we add this to deploy/appschema.sql:

  CREATE SCHEMA flipr;

The revert script's job is to precisely revert the change to the deploy script, so we add this to revert/appschema.sql:

  DROP SCHEMA flipr;

Now we can try deploying this change:

  > createdb flipr_test
  > sqitch --db-name flipr_test deploy
  Adding metadata tables to flipr_test
  Deploying to flipr_test
    + appschema

First Sqitch created the metadata tables used to track database changes. The structure and name of the metadata tables varies between databases (PostgreSQL uses a schema to namespace its metadata; MySQL and SQLite use a prefix). Next, Sqitch deploys changes. We only have one so far; the + reinforces the idea that the change is being added to the database.

With this change deployed, if you connect to the database, you'll be able to see the role:

  > psql -d flipr_test -c '\dn flipr'
  List of schemas
   Name  | Owner 
  -------+-------
   flipr | david
x
And we can also see how the deployment was recorded via the C<status> command,
which reads the metadata tables from the database:

  > sqitch -d flipr_test status
  # On database flipr_test
  # Project:  flipr
  # Change:   9b24259744da156552479197872adba6a01a1ace
  # Name:     appschema
  # Deployed: 2012-08-16 18:52:40 -0700
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Let's make sure that we can revert the change:

  > sqitch --db-name flipr_test revert
  Reverting all changes from flipr_test
    - appschema

Note the - reinforces that the change is being removed from the database. And now the user should be gone:

  > psql -d flipr_test -c '\dn flipr'
              List of roles
  List of schemas
   Name | Owner 
  ------+-------

And the status message should reflect as much:

  > sqitch -d flipr_test status
  # On database flipr_test
  No changes deployed

We still have a record that the change happened, visible via the log command:

  > sqitch -d flipr_test log
  On database flipr_test
  Revert 9b24259744da156552479197872adba6a01a1ace
  Name:      appschema
  Committer: Marge N. O’Vera <marge@example.com>
  Date:      2012-08-16 18:54:55 -0700

      App schema for all flipr objects.

  Deploy 9b24259744da156552479197872adba6a01a1ace
  Name:      appschema
  Committer: Marge N. O’Vera <marge@example.com>
  Date:      2012-08-16 18:52:40 -0700

      App schema for all flipr objects.

Note that the actions we took are shown in reverse chronological order, with the revert first and then the deploy.

Cool. Now let's commit it.

  > git add .
  > git commit -m 'Add flipr schema.'
  [master 0fcb493] Add flipr schema.
   4 files changed, 23 insertions(+), 1 deletion(-)
   create mode 100644 deploy/appschema.sql
   create mode 100644 revert/appschema.sql
   create mode 100644 test/appschema.sql

And then deploy again:

  > sqitch --db-name flipr_test deploy
  Deploying changes to flipr_test
    + appschema

And now the user should be back:

  > psql -d flipr_test -c '\dn flipr'
  List of schemas
   Name  | Owner 
  -------+-------
   flipr | david

When we look at the status, the deployment will be there:

  > sqitch -d flipr_test status
  # On database flipr_test
  # Project:  flipr
  # Change:   9b24259744da156552479197872adba6a01a1ace
  # Name:     appschema
  # Deployed: 2012-08-16 18:57:03 -0700
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

More Configuration

I'm getting a little tired of always having to type --db-name flipr_test, aren't you? Let's just make that the default, shall we?

  > sqitch config core.pg.db_name flipr_test

Now we can leave it out, unless we need to deploy to another database. Which we will, eventually, but at least our examples will be simpler from here on in, e.g.:

  > sqitch status
  # On database flipr_test
  # Project:  flipr
  # Change:   9b24259744da156552479197872adba6a01a1ace
  # Name:     appschema
  # Deployed: 2012-08-16 18:57:03 -0700
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Yay, that allows things to be a little more concise. Let's make some more changes! a =head1 Deploy with Dependency

Let's add another change, this time to create a table. Our app will need users, of course, so we'll create a table for them. First, add the new change:

  > sqitch add users --requires appschema -n 'Creates table to track our users.'
  Created deploy/users.sql
  Created revert/users.sql
  Created test/users.sql
  Added "users [appschema]" to sqitch.plan

Note that we're requiring the appschema change as a dependency of the new users change. Although that change has already been added to the plan and therefore should always be applied before the users change, it's a good idea to be explicit about dependencies.

Now edit the scripts. When you're done, deploy/users.sql should look like this:

  -- Deploy users
  -- requires: appschema
  BEGIN;
  SET client_min_messages = 'warning';

  CREATE TABLE flipr.users (
      nickname  TEXT        PRIMARY KEY,
      password  TEXT        NOT NULL,
      timestamp TIMESTAMPTZ NOT NULL DEFAULT NOW()
  );

  COMMIT;

A few things to notice here. On the second line, the dependence on the appschema change has been listed. This doesn't do anything, but the default templates lists it here for your reference while editing the file. Useful, right?

Notice that all of the SQL code is wrapped in a transaction. This is handy for PostgreSQL deployments, because PostgreSQL DDLs are transactional. The upshot is that if any part of the deployment fails, the whole change fails. Such may work less-well for database engines that don't support transactional DDLs.

The table itself has been created in the flipr schema. This is why we need to require the appschema change.

Now for the revert script. Add this to revert/users.sql:

  DROP TABLE flipr.users;

Couldn't be much simpler, right? Let's deploy this bad boy:

  > sqitch deploy
  Deploying changes to flipr_test
    + users

The users table should have been created:

  > psql -d flipr_test -c '\d flipr.users'
                        Table "flipr.users"
    Column   |           Type           |       Modifiers        
  -----------+--------------------------+------------------------
   nickname  | text                     | not null
   password  | text                     | not null
   timestamp | timestamp with time zone | not null default now()
  Indexes:
      "users_pkey" PRIMARY KEY, btree (nickname)

Now have a look at the status:

  > sqitch status
  # On database flipr_test
  # Project:  flipr
  # Change:   0521530ed75365d16163e3b46d292c2a29e13dfa
  # Name:     users
  # Deployed: 2012-08-16 19:01:06 -0700
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Success! Let's make sure we can revert the change, as well:

  > sqitch revert --to appschema
  Reverting from flipr_test to appschema
    - users

Note that we've used the --to option to revert only to appschema. The users table should be gone, but the flipr user should still be around:

  > psql -d flipr_test -c '\d flipr.users'
  Did not find any relation named "flipr.users".

Now commit and deploy again:

  > git add .
  > git commit -am 'Add users table.'
  [master dfa6952] Add users table.
   5 files changed, 30 insertions(+)
   create mode 100644 deploy/users.sql
   create mode 100644 revert/users.sql
   create mode 100644 test/users.sql
  > sqitch deploy
  Deploying changes to flipr_test
    + users

Looks good. Check the status:

  > sqitch status
  # On database flipr_test
  # Project:  flipr
  # Change:   0521530ed75365d16163e3b46d292c2a29e13dfa
  # Name:     users
  # Deployed: 2012-08-16 19:03:48 -0700
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Excellent. Let's do some more!

Add Two at Once

Let's add a couple more changes to add functions for managing users.

  > sqitch add insert_user --requires users --requires appschema \
    -n 'Creates a function to insert a user.'
  Created deploy/insert_user.sql
  Created revert/insert_user.sql
  Created test/insert_user.sql
  Added "insert_user [users appschema]" to sqitch.plan

  > sqitch add change_pass --requires users --requires appschema \
    -n 'Creates a function to change a user password.'
  Created deploy/change_pass.sql
  Created revert/change_pass.sql
  Created test/change_pass.sql
  Added "change_pass [users appschema]" to sqitch.plan

Now might be a good time to have a look at the deployment plan:

  > cat sqitch.plan
  %syntax-version=1.0.0-b2
  %project=flipr
  %uri=https://github.com/theory/sqitch-intro/

  appschema 2012-08-17T01:49:33Z Marge N. O’Vera <marge@example.com> # App schema for all flipr objects.
  users [appschema] 2012-08-17T01:58:43Z Marge N. O’Vera <marge@example.com> # Creates table to track our users.
  insert_user [users appschema] 2012-08-17T02:07:53Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a user.
  change_pass [users appschema] 2012-08-17T02:08:10Z Marge N. O’Vera <marge@example.com> # Creates a function to change a user password.

Each change appears on a single line with the name of the change, a bracketed list of dependencies, a timestamp, the name and email address of the user who planned the change, and a note.

Let's write the code for the new changes. Here's what deploy/insert_user.sql should look like:

  -- Deploy insert_user
  -- requires: users
  -- requires: appschema
  
  BEGIN;

  CREATE OR REPLACE FUNCTION flipr.insert_user(
      nickname TEXT,
      password TEXT
  ) RETURNS VOID LANGUAGE SQL SECURITY DEFINER AS $$
      INSERT INTO flipr.users VALUES($1, md5($2));
  $$;

  COMMIT;

And revert/insert_user.sql should look something like this:

  -- Revert insert_user
  BEGIN;
  DROP FUNCTION flipr.insert_user(TEXT, TEXT);
  COMMIT;

Now for change_pass; deploy/change_pass.sql might look like this:

  -- Deploy change_pass
  -- requires: users
  -- requires: appschema

  BEGIN;

  CREATE OR REPLACE FUNCTION flipr.change_pass(
      nick    TEXT,
      oldpass TEXT,
      newpass TEXT
  ) RETURNS BOOLEAN LANGUAGE plpgsql SECURITY DEFINER AS $$
  BEGIN
      UPDATE flipr.users
         SET password = md5($3)
       WHERE nickname = $1
         AND password = md5($2);
      RETURN FOUND;
  END;
  $$;

  COMMIT;

And of course, its revert script, revert/change_pass.sql, should look something like:

  -- Revert change_pass
  BEGIN;
  DROP FUNCTION flipr.change_pass(TEXT, TEXT, TEXT);
  COMMIT;

Test em out!

  > sqitch deploy
  Deploying changes to flipr_test
    + insert_user
    + change_pass

Do we have the functions?

  > psql -d flipr_test -c '\df flipr.*'
                                      List of functions
   Schema |    Name     | Result data type |          Argument data types          |  Type  
  --------+-------------+------------------+---------------------------------------+--------
   flipr  | change_pass | boolean          | nick text, oldpass text, newpass text | normal
   flipr  | insert_user | void             | nickname text, password text          | normal

And what's the status?

  > sqitch status 
  # On database flipr_test
  # Project:  flipr
  # Change:   99408db589f6031b6e851bce17aec7f870ed11e6
  # Name:     change_pass
  # Deployed: 2012-08-16 19:10:58 -0700
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Looks good. Let's make sure revert works:

  > sqitch revert --to users
  Reverting from flipr_test to users
    - change_pass
    - insert_user
  > psql -d flipr_test -c '\df flipr.*'
                         List of functions
   Schema | Name | Result data type | Argument data types | Type 
  --------+------+------------------+---------------------+------

Looks good. Let's do the commit and re-deploy dance:

  > git add .
  > git commit -m 'Add `insert_user()` and `change_pass()`.'
  [master 75be062] Add `insert_user()` and `change_pass()`.
   7 files changed, 65 insertions(+)
   create mode 100644 deploy/change_pass.sql
   create mode 100644 deploy/insert_user.sql
   create mode 100644 revert/change_pass.sql
   create mode 100644 revert/insert_user.sql
   create mode 100644 test/change_pass.sql
   create mode 100644 test/insert_user.sql
 
  > sqitch deploy
  Deploying changes to flipr_test
    + insert_user
    + change_pass

  > sqitch status
  # On database flipr_test
  # Project:  flipr
  # Change:   99408db589f6031b6e851bce17aec7f870ed11e6
  # Name:     change_pass
  # Deployed: 2012-08-16 19:12:35 -0700
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Great, we're fully up-to-date!

Ship It!

Let's do a first release of our app. Let's call it 1.0.0-dev1 Since we want to have it go out with deployments tied to the release, let's tag it:

  > sqitch tag v1.0.0-dev1 -n 'Tag v1.0.0-dev1.'
  Tagged "change_pass" with @v1.0.0-dev1
  > git commit -am 'Tag the database with v1.0.0-dev1.'
  [master 067ef73] Tag the database with v1.0.0-dev1.
   1 file changed, 1 insertion(+)
  > git tag v1.0.0-dev1 -am 'Tag v1.0.0-dev1'

We can test deployment to make sure the tag gets picked up like so:

  > createdb flipr_dev
  > sqitch --db-name flipr_dev deploy
  Adding metadata tables to flipr_dev
  Deploying changes to flipr_dev
    + appschema
    + users
    + insert_user
    + change_pass @v1.0.0-dev1

Great, all four changes were deployed and change_pass was tagged with @v1.0.0-dev1. Let's have a look at the state:

  > sqitch --db-name flipr_dev status
  # On database flipr_dev
  # Project:  flipr
  # Change:   99408db589f6031b6e851bce17aec7f870ed11e6
  # Name:     change_pass
  # Tag:      @v1.0.0-dev1
  # Deployed: 2012-08-16 19:17:23 -0700
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Note the listing of the tag as part of the stats message. Now let's bundle everything up for release:

  > sqitch bundle
  Bundling in bundle/
    + appschema
    + users
    + insert_user
    + change_pass @v1.0.0-dev1
  Plan written to bundle/sqitch.plan
  Config written to bundle/sqitch.conf

Now we can package up the bundle directory and distribute it. When it gets installed somewhere, users can use Sqitch to deploy to the database. Let's test deploying it:

  > cd bundle
  > createdb flipr_prod
  > sqitch --db-name flipr_prod deploy
  Adding metadata tables to flipr_prod
  Deploying changes to flipr_prod
    + appschema
    + users
    + insert_user
    + change_pass @v1.0.0-dev1

Looks much the same as before, eh? Package it up and ship it!

Flip Out

Now that we've got the basics of user management done, let's get to work on the core of our product, the "flip." Since other folks are working on other tasks in the repository, we'll work on a branch, so we can all stay out of each other's way. So let's branch:

  > git checkout -b flips
  Switched to a new branch 'flips'

Now we can add a new change to create a table for our flips.

  > sqitch add flips --requires users -n 'Adds table for storing flips.'
  Created deploy/flips.sql
  Created revert/flips.sql
  Created test/flips.sql
  Added "flips [:users]" to sqitch.plan

You know the drill by now. Edit deploy/flips.sql:

  -- Deploy flips
  -- requires: users

  BEGIN;
  SET client_min_messages = 'warning';

  CREATE TABLE flipr.flips (
      id        BIGSERIAL   PRIMARY KEY,
      nickname  TEXT        NOT NULL REFERENCES flipr.users(nickname),
      body      TEXT        NOT NULL DEFAULT '' CHECK ( length(body) <= 180 ),
      timestamp TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp()
  );

  COMMIT;

And edit revert/flips.sql:

  -- Revert flips
  BEGIN;
  DROP TABLE flipr.flips;
  COMMIT;

And give it a whirl:

  > sqitch revert --to insert_user
    - change_pass
  > sqitch deploy
  Deploying changes to flipr_test
    + change_pass @v1.0.0-dev1
    + flips

We first revert to insert_user because the @v1.0.0-dev1 tag was never applied to the test database. It gets applied on the new deploy, along with the flips change. Look good?

  > sqitch status --show-tags
  # On database flipr_test
  # Project:  flipr
  # Change:   7a36d796b5c3163a92970ad795ab3f5c27b8cad3
  # Name:     flips
  # Deployed: 2012-08-17 15:50:42 -0700
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  # Tag:
  #   @v1.0.0-dev1 - 2012-08-17 15:50:41 -0700 - Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Note the use of --show tags to show all the deployed tags. Now make it so:

  > git add .
  > git commit -am 'Add flips table.'
  [flips c5a4590] Add flips table.
   4 files changed, 28 insertions(+)
   create mode 100644 deploy/flips.sql
   create mode 100644 revert/flips.sql
   create mode 100644 test/flips.sql

Wash, Rinse, Repeat

Now comes the time to add functions to manage flips. I'm sure you have things nailed down now. Go ahead and add insert_flip and delete_flip changes and commit them. The insert_flip deploy script might look something like:

  -- Deploy insert_flip
  -- requires: flips
  -- requires: appschema
  BEGIN;

  CREATE OR REPLACE FUNCTION flipr.insert_flip(
     nickname TEXT,
     body     TEXT
  ) RETURNS BIGINT LANGUAGE sql SECURITY DEFINER AS $$
      INSERT INTO flipr.flips (body, nickname)
      VALUES ($1, $2)
      RETURNING id;
  $$;

  COMMIT;

And the delete_flip deploy script might look something like:

  -- Deploy delete_flip
  -- requires: flips
  -- requires: appschema
  BEGIN;

  CREATE OR REPLACE FUNCTION flipr.delete_flip(
     flip_id BIGINT
  ) RETURNS BOOLEAN LANGUAGE plpgsql SECURITY DEFINER AS $$
  BEGIN
      DELETE FROM flipe.flips WHERE id = flip_id;
      RETURN FOUND;
  END;
  $$;

  COMMIT;

The revert scripts are:

  DROP FUNCTION flipr.insert_flip(TEXT, TEXT);

And:

  DROP FUNCTION flipr.delete_flip(BIGINT);

Check the example git repository for the complete details. Test deploy and revert, commit, and retag. The status should end up looking something like this:

  > sqitch status --show-tags
  # On database flipr_test
  # Project:  flipr
  # Change:   1bdf1db703e7dab40df9c8b7bcbc3f286ecd76f0
  # Name:     delete_flip
  # Deployed: 2012-08-17 16:13:31 -0700
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  # Tag:
  #   @v1.0.0-dev1 - 2012-08-17 16:12:25 -0700 - Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

Good, we've finished this feature. Time to merge back into master.

Emergency

Let's do it:

  > git checkout master
  Switched to branch 'master'
  > git pull
  Updating 067ef73..cabc5e3
  Fast-forward
   deploy/delete_list.sql |   19 +++++++++++++++++++
   deploy/insert_list.sql |   16 ++++++++++++++++
   deploy/lists.sql       |   15 +++++++++++++++
   revert/delete_list.sql |    5 +++++
   revert/insert_list.sql |    5 +++++
   revert/lists.sql       |    5 +++++
   sqitch.plan            |    4 ++++
   test/delete_list.sql   |    7 +++++++
   test/insert_list.sql   |    7 +++++++
   test/lists.sql         |    7 +++++++
   10 files changed, 90 insertions(+)
   create mode 100644 deploy/delete_list.sql
   create mode 100644 deploy/insert_list.sql
   create mode 100644 deploy/lists.sql
   create mode 100644 revert/delete_list.sql
   create mode 100644 revert/insert_list.sql
   create mode 100644 revert/lists.sql
   create mode 100644 test/delete_list.sql
   create mode 100644 test/insert_list.sql
   create mode 100644 test/lists.sql

Hrm, that's interesting. Looks like someone made some changes to master. They added list support. Well, let's see what happens when we merge our changes.

  > git merge --no-ff flips
  Auto-merging sqitch.plan
  CONFLICT (content): Merge conflict in sqitch.plan
  Automatic merge failed; fix conflicts and then commit the result.

Oh, a conflict in sqitch.plan. Not too surprising, since both the merged lists branch and our flips branch added changes to the plan. Let's try a different approach.

The truth is, we got lazy. Those changes when we pulled master from the origin should have raised a red flag. In truth, it's considered a bad practice not to look at what's changed in master before merging in a branch. What one should do is either:

  • Rebase the branch from master before merging. This "rewinds" the branch changes, pulls from master, and then replays the changes back on top of master.

  • Create a patch and apply that to master. This is the sort of thing you might have to do if you're sending changes to another user, especially if the VCS is not Git.

So let's restore things to how they were at master:

  > git reset --hard HEAD
  HEAD is now at cabc5e3 Merge branch 'lists'

That throws out our botched merge. Now let's go back to our branch and rebase it on master:

  > git checkout flips
  > git rebase master
  First, rewinding head to replay your work on top of it...
  Applying: Add flips table.
  Using index info to reconstruct a base tree...
  Falling back to patching base and 3-way merge...
  Auto-merging sqitch.plan
  CONFLICT (content): Merge conflict in sqitch.plan
  Failed to merge in the changes.
  Patch failed at 0001 Add flips table.

  When you have resolved this problem run "git rebase --continue".
  If you would prefer to skip this patch, instead run "git rebase --skip".
  To check out the original branch and stop rebasing run "git rebase --abort".

Oy, that's kind of a pain. It seems like no matter what we do, we'll need to resolve conflicts in that file. Except in Git. Fortunately, we can tell Git to resolve conflicts differently in sqitch.plan. Because we only ever append lines to the file, we can have it use the "union" merge driver, which, according to its docs:

    Run 3-way file level merge for text files, but take lines from both versions, instead of leaving conflict markers. This tends to leave the added lines in the resulting file in random order and the user should verify the result. Do not use this if you do not understand the implications.

This has the effect of appending lines from all the merging files, which is exactly what we need. So let's give it a try. First, back out the botched rebase:

  > git rebase --abort

Now add the union merge driver to .gitattributes for sqitch.plan and rebase again:

  > echo sqitch.plan merge=union > .gitattributes
  > git rebase master                            
  First, rewinding head to replay your work on top of it...
  Applying: Add flips table.
  Using index info to reconstruct a base tree...
  Falling back to patching base and 3-way merge...
  Auto-merging sqitch.plan
  Applying: Add functions to insert and delete flips.
  Using index info to reconstruct a base tree...
  Falling back to patching base and 3-way merge...
  Auto-merging sqitch.plan

Ah, that looks a bit better. Let's have a look at the plan:

  > cat sqitch.plan 
  %syntax-version=1.0.0-b2
  %project=flipr
  %uri=https://github.com/theory/sqitch-intro/

  appschema 2012-08-17T01:49:33Z Marge N. O’Vera <marge@example.com> # App schema for all flipr objects.
  users [appschema] 2012-08-17T01:58:43Z Marge N. O’Vera <marge@example.com> # Creates table to track our users.
  insert_user [users appschema] 2012-08-17T02:07:53Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a user.
  change_pass [users appschema] 2012-08-17T02:08:10Z Marge N. O’Vera <marge@example.com> # Creates a function to change a user password.
  @v1.0.0-dev1 2012-08-17T05:24:20Z Marge N. O’Vera <marge@example.com> # Tag v1.0.0-dev1.

  lists [users] 2012-08-17T22:56:58Z Marge N. O’Vera <marge@example.com> # Adds table for storing lists.
  insert_list [lists appschema] 2012-08-17T23:10:19Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a list.
  delete_list [lists appschema] 2012-08-17T23:10:24Z Marge N. O’Vera <marge@example.com> # Creates a function to delete a list.
  flips [users] 2012-08-17T22:48:39Z Marge N. O’Vera <marge@example.com> # Adds table for storing flips.
  insert_flip [flips appschema] 2012-08-17T23:05:22Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a flip.
  delete_flip [flips appschema] 2012-08-17T23:05:30Z Marge N. O’Vera <marge@example.com> # Creates a function to delete a flip.

Note that it has appended the changes from the merged "lists" branch, and then merged the changes from our "flips" branch. Test it to make sure it works as expected:

  > sqitch revert
  Reverting all changes from flipr_test
    - delete_flip
    - insert_flip
    - flips
    - change_pass @v1.0.0-dev1
    - insert_user
    - users
    - appschema
  > sqitch deploy
  Deploying changes to flipr_test
    + appschema
    + users
    + insert_user
    + change_pass @v1.0.0-dev1
    + lists
    + insert_list
    + delete_list
    + flips
    + insert_flip
    + delete_flip

Excellent! It correctly reverted our changes, and then deployed them all again in the proper order. So let's commit .gitattributes; seems worthwhile to keep that change:

  > git add .
  > git ci -m 'Add `.gitattributes` with union merge for `sqitch.plan`.'
  [flips 47e35c4] Add `.gitattributes` with union merge for `sqitch.plan`.
   1 file changed, 1 insertion(+)
   create mode 100644 .gitattributes

Merges Mastered

And now, finally, we can merge into master:

  > git checkout master
  Switched to branch 'master'
  > git merge --no-ff flips
  Merge made by the 'recursive' strategy.
   .gitattributes         |    1 +
   deploy/delete_flip.sql |   16 ++++++++++++++++
   deploy/flips.sql       |   14 ++++++++++++++
   deploy/insert_flip.sql |   16 ++++++++++++++++
   revert/delete_flip.sql |    5 +++++
   revert/flips.sql       |    5 +++++
   revert/insert_flip.sql |    5 +++++
   sqitch.plan            |    3 +++
   test/delete_flip.sql   |    7 +++++++
   test/flips.sql         |    7 +++++++
   test/insert_flip.sql   |    7 +++++++
   11 files changed, 86 insertions(+)
   create mode 100644 .gitattributes
   create mode 100644 deploy/delete_flip.sql
   create mode 100644 deploy/flips.sql
   create mode 100644 deploy/insert_flip.sql
   create mode 100644 revert/delete_flip.sql
   create mode 100644 revert/flips.sql
   create mode 100644 revert/insert_flip.sql
   create mode 100644 test/delete_flip.sql
   create mode 100644 test/flips.sql
   create mode 100644 test/insert_flip.sql

And double-check our work:

  > cat sqitch.plan 
  %syntax-version=1.0.0-b2
  %project=flipr
  %uri=https://github.com/theory/sqitch-intro/

  appschema 2012-08-17T01:49:33Z Marge N. O’Vera <marge@example.com> # App schema for all flipr objects.
  users [appschema] 2012-08-17T01:58:43Z Marge N. O’Vera <marge@example.com> # Creates table to track our users.
  insert_user [users appschema] 2012-08-17T02:07:53Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a user.
  change_pass [users appschema] 2012-08-17T02:08:10Z Marge N. O’Vera <marge@example.com> # Creates a function to change a user password.
  @v1.0.0-dev1 2012-08-17T05:24:20Z Marge N. O’Vera <marge@example.com> # Tag v1.0.0-dev1.

  lists [users] 2012-08-17T22:56:58Z Marge N. O’Vera <marge@example.com> # Adds table for storing lists.
  insert_list [lists appschema] 2012-08-17T23:10:19Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a list.
  delete_list [lists appschema] 2012-08-17T23:10:24Z Marge N. O’Vera <marge@example.com> # Creates a function to delete a list.
  flips [users] 2012-08-17T22:48:39Z Marge N. O’Vera <marge@example.com> # Adds table for storing flips.
  insert_flip [flips appschema] 2012-08-17T23:05:22Z Marge N. O’Vera <marge@example.com> # Creates a function to insert a flip.
  delete_flip [flips appschema] 2012-08-17T23:05:30Z Marge N. O’Vera <marge@example.com> # Creates a function to delete a flip.

Much much better, a nice clean master now. And because it is now identical to the "flips" branch, we can just carry on. Go ahead and tag it, bundle, and release:

  > sqitch tag v1.0.0-dev2 -n 'Tag v1.0.0-dev2.'
  Tagged "delete_flip" with @v1.0.0-dev2
  > git commit -am 'Tag the database with v1.0.0-dev2.'
  [master b6cb90d] Tag the database with v1.0.0-dev2.
   1 file changed, 1 insertion(+)
  > git tag v1.0.0-dev2 -am 'Tag v1.0.0-dev2'
  > sqitch bundle
  Bundling in bundle/
    + appschema
    + users
    + insert_user
    + change_pass @v1.0.0-dev1
    + lists
    + insert_list
    + delete_list
    + flips
    + insert_flip
    + delete_flip @v1.0.0-dev2
  Plan written to bundle/sqitch.plan
  Config written to bundle/sqitch.conf

In Place Changes

Uh-oh, someone just noticed that MD5 hashing is not particularly secure. Why? Have a look at this:

  > psql -d flipr_test -c "
      SELECT flipr.insert_user('foo', 'secr3t'), flipr.insert_user('bar', 'secr3t');
      SELECT * FROM flipr.users;
  "
   nickname |             password             |           timestamp           
  ----------+----------------------------------+-------------------------------
   foo      | 9695da4dd567a19f9b92065f240c6725 | 2012-08-17 23:21:42.489121+00
   bar      | 9695da4dd567a19f9b92065f240c6725 | 2012-08-17 23:21:42.489121+00

If user "foo" ever got access to the database, she could quickly discover that user "bar" has the same password and thus be able to exploit the account. Not a great idea. So we need to modify the insert_user() and change_pass() functions to fix that. How? we'll use pgcrypto's crypt() function to encrypt passwords with a salt, so that they're all unique. We just add a change to add pgcrypto to the database, and then we can use it. The deploy script should be:

 CREATE EXTENSION pgcrypto;

And the revert script should just DROP EXTENSION pgcrypto. Then we can use it. But how to deploy the changes to insert_user() and change_pass()?

Normally, modifying functions in database changes is a PITA. You have to take changes like these:

  1. Copy deploy/insert_user.sql to deploy/insert_user_crypt.sql.

  2. Edit deploy/insert_user_crypt.sql to switch from MD5() to crypt() and to add a dependency on the pgcrypto change.

  3. Copy deploy/insert_user.sql to revert/insert_user_crypt.sql. Yes, copy the original change script to the new revert change.

  4. Test the changes to make sure you can deploy and revert the insert_user_crypt change.

  5. Now do the same for the change_pass scripts.

But you can have Sqitch do it for you. The only requirement is that a tag appear between the two instances of a change we want to modify. In general, you're going to make a change like this after a release, which you've tagged anyway, right? Well we have, with @v1.0.0-dev2 added in the previous section. With that, we can let Sqitch do most of the hard work for us, thanks to the rework command, which is similar to add, including support for the --requires option:

  > sqitch rework insert_user --requires pgcrypto -n 'Change insert_user to use pgcrypto.'
  Added "insert_user [insert_user@v1.0.0-dev2 pgcrypto]" to sqitch.plan.
  Modify these files as appropriate:
    * deploy/insert_user.sql
    * revert/insert_user.sql
    * test/insert_user.sql

Oh, so we can edit those files in place. Nice! How does Sqitch do it? Well, in point of fact, it has copied the files to stand in for the previous instance of the insert_user change, which we can see via git status:

  > git status
  # On branch master
  # Your branch and 'origin/master' have diverged,
  # and have 13 and 14 different commits each, respectively.
  #
  # Changes not staged for commit:
  #   (use "git add <file>..." to update what will be committed)
  #   (use "git checkout -- <file>..." to discard changes in working directory)
  #
  #     modified:   revert/insert_user.sql
  #     modified:   sqitch.plan
  #
  # Untracked files:
  #   (use "git add <file>..." to include in what will be committed)
  #
  #     deploy/insert_user@v1.0.0-dev2.sql
  #     revert/insert_user@v1.0.0-dev2.sql
  #     test/insert_user@v1.0.0-dev2.sql
  no changes added to commit (use "git add" and/or "git commit -a")

The "untracked files" part of the output is the first thing to notice. They are all named insert_user@v1.0.0-dev2.sql. What that means is: "the insert_user change as it was implemented as of the @v1.0.0-dev2 tag." These are copies of the original scripts, and thereafter Sqitch will find them when it needs to run scripts for the first instance of the insert_user change. As such, it's important not to change them again. But hey, if you're reworking them, you shouldn't need to.

The other thing to notice is that revert/insert_user.sql has changed. Sqitch replaced it with The original deploy script. As of now, deploy/insert_user.sql and revert/insert_user.sql are identical. This is on the assumption that the deploy script will be changed (we're reworking it, remember?), and that the revert script should actually change things back to how they were before. Of course, the original deploy script may not be idempotent -- that is, able to be applied multiple times without changing the result beyond the initial application. If it's not, you will likely need to modify it so that it properly restores things to how they were after the original deploy script was deployed. Or, more simply, it should revert changes back to how they were as-of the deployment of deploy/insert_user@v1.0.0-dev2.sql.

Fortunately, our function deployment scripts are already idempotent, thanks to the use of the OR REPLACE expression. No matter how many times a deployment script is run, the end result will be the same instance of the function, with no duplicates or errors.

As a result, there is no need to explicitly add changes. So go ahead. Modify the script to switch to crypt(). Make this change to deploy/insert_user.sql:

  @@ -1,6 +1,7 @@
   -- Deploy insert_user
   -- requires: users
   -- requires: appschema
  +-- requires: pgcrypto
 
   BEGIN;
 
  @@ -8,7 +9,7 @@ CREATE OR REPLACE FUNCTION flipr.insert_user(
       nickname TEXT,
       password TEXT
   ) RETURNS VOID LANGUAGE SQL SECURITY DEFINER AS $$
  -    INSERT INTO flipr.users VALUES($1, md5($2));
  +    INSERT INTO flipr.users values($1, crypt($2, gen_salt('md5')));
   $$;
 
   COMMIT;

Go ahead and rework the change_pass change, too:

  > sqitch rework change_pass --requires pgcrypto -n 'Change change_pass to use pgcrypto.' 
  Added "change_pass [:change_pass@v1.0.0-dev2 :pgcrypto]" to sqitch.plan.
  Modify these files as appropriate:
    * deploy/change_pass.sql
    * revert/change_pass.sql
    * test/change_pass.sql

And make this change to deploy/change_pass.sql:

  @@ -1,6 +1,7 @@
   -- Deploy change_pass
   -- requires: users
   -- requires: appschema
  +-- requires: pgcrypto
 
   BEGIN;
 
  @@ -11,9 +12,9 @@ CREATE OR REPLACE FUNCTION flipr.change_pass(
   ) RETURNS BOOLEAN LANGUAGE plpgsql SECURITY DEFINER AS $$
   BEGIN
       UPDATE flipr.users
  -       SET password = md5($3)
  +       SET password = crypt($3, gen_salt('md5'))
        WHERE nickname = $1
  -       AND password = md5($2);
  +       AND password = crypt($2, password);
       RETURN FOUND;
   END;
   $$;

And then test deployment:

  > sqitch deploy
  Deploying changes to flipr_test
    + insert_user
    + change_pass

So, are the changes deployed?

  > psql -d flipr_test -c "
      DELETE FROM flipr.users;
      SELECT flipr.insert_user('foo', 'secr3t'), flipr.insert_user('bar', 'secr3t');
      SELECT * FROM flipr.users;
  "
   nickname |              password              |           timestamp           
  ----------+------------------------------------+-------------------------------
   foo      | $1$MuWWLE4t$83EuG49Hpeb9rYCz7T1OX/ | 2012-08-17 23:29:34.568335+00
   bar      | $1$bENvWj9k$gfq81YuEG7QcSotaskMkd0 | 2012-08-17 23:29:34.568335+00

Awesome, the stored passwords are different now. But can we revert, even though we haven't written any reversion scripts?

  > sqitch revert --to pgcrypto
  Reverting from flipr_test to pgcrypto
    - change_pass
    - insert_user

Did that work, are the MD5() passwords back?

  > psql -d flipr_test -c "
      DELETE FROM flipr.users;
      SELECT flipr.insert_user('foo', 'secr3t'), flipr.insert_user('bar', 'secr3t');
      SELECT * FROM flipr.users;
  "
   nickname |             password             |           timestamp           
  ----------+----------------------------------+-------------------------------
   foo      | 9695da4dd567a19f9b92065f240c6725 | 2012-08-17 23:30:36.513217+00
   bar      | 9695da4dd567a19f9b92065f240c6725 | 2012-08-17 23:30:36.513217+00

Yes, it works! Sqitch properly finds the original instances of these changes in the new script files that include tags.So let's go ahead and commit these changes and bring the database up-to-date:

  > git add .
  > git commit -m 'Use pgcrypto to encrypt passwords.'
  [master f555cf9] Use pgcrypto to encrypt passwords.
   11 files changed, 95 insertions(+), 7 deletions(-)
   create mode 100644 deploy/change_pass@v1.0.0-dev2.sql
   create mode 100644 deploy/insert_user@v1.0.0-dev2.sql
   create mode 100644 revert/change_pass@v1.0.0-dev2.sql
   create mode 100644 revert/insert_user@v1.0.0-dev2.sql
   create mode 100644 test/change_pass@v1.0.0-dev2.sql
   create mode 100644 test/insert_user@v1.0.0-dev2.sql

  > sqitch deploy
  Deploying changes to flipr_test
    + insert_user
    + change_pass

  > sqitch status
  # On database flipr_test
  # Project:  flipr
  # Change:   d0eb9c5ff822877696e834d686a4d9ee8a5cd2a9
  # Name:     change_pass
  # Deployed: 2012-08-17 16:31:13 -0700
  # By:       Marge N. O’Vera <marge@example.com>
  # 
  Nothing to deploy (up-to-date)

More to Come

Sqitch is a work in progress. Better integration with version control systems is planned to make managing idempotent reworkings even easier. Stay tuned.

Author

David E. Wheeler <david@justatheory.com>

License

Copyright (c) 2012 iovation Inc.

Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions:

The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software.

THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.