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 unique URI associated with it. Sqitch will create a random URI for you, but it's nicer to have a formal project URI, so let's specify one when we initialize Sqitch:
> sqitch --uri https://github.com/theory/sqitch-intro/ --engine pg init
Created sqitch.conf
Created sqitch.plan
Created deploy/
Created revert/
Created test/
Let's have a look at sqitch.conf:
[core]
uri = https://github.com/theory/sqitch-intro/
engine = pg
# plan_file = sqitch.plan
# top_dir = .
# deploy_dir = deploy
# revert_dir = revert
# test_dir = test
# extension = sql
# [core "pg"]
# db_name =
# client = /var/lib/pgsql/bin/psql
# sqitch_schema = sqitch
# password =
# port =
# host =
# username =
Good, it saved our custom URI. It also 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
Have a look at ~/.sqitch/sqitch.conf and you'll see this:
[core "pg"]
client = /usr/local/pgsql/bin/psql
Which means that Sqitch should be able to find psql
for any project.
Back to the repository. Let's commit these changes and start creating the database changes.
> git add .
> git commit -am 'Initialize Sqitch configuration.'
[master ba6eeb8] Initialize Sqitch configuration.
2 files changed, 19 insertions(+)
create mode 100644 sqitch.conf
create mode 100644 sqitch.plan
Our First Deployment
First, our project will need a database user. This is the application user, who will have only limited access to objects in the database. Run this command:
> sqitch add appuser
Created deploy/appuser.sql
Created revert/appuser.sql
Created test/appuser.sql
Added "appuser" 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 user. So we add this to deploy/appuser.sql:
CREATE ROLE flipr WITH LOGIN;
The revert
script's job is to precisely revert the change to the deploy script, so we add this to revert/appuser.sql:
DROP ROLE 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
+ appuser
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 '\du flipr'
List of roles
Role name | Attributes | Member of
-----------+------------+-----------
flipr | | {}
And we can also see how the deployment was recorded via the status
command, which reads the metadata tables from the database:
> sqitch -d flipr_test status
# On database flipr_test
# Change: 9df095ad10d799c3acdd74f7986ee1ed9a75e766
# Name: appuser
# Deployed: 2012-07-06 18:59:08 +0200
# By: david
#
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
- appuser
Note the -
reinforces that the change is being removed from the database. And now the user should be gone:
> psql -d flipr_test -c '\du flipr'
List of roles
Role name | Attributes | Member of
-----------+------------+-----------
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 9df095ad10d799c3acdd74f7986ee1ed9a75e766
Name: appuser
Date: 2012-07-06 19:00:45 +0200
Deploy 9df095ad10d799c3acdd74f7986ee1ed9a75e766
Name: appuser
Date: 2012-07-06 18:59:08 +0200
Cool. Now let's commit it.
> git add .
> git commit -m 'Add app user.'
[master a29fb74] Add app user.
2 files changed, 2 insertions(+)
create mode 100644 deploy/appuser.sql
create mode 100644 revert/appuser.sql
And then deploy again:
> sqitch --db-name flipr_test deploy
Deploying changes to flipr_test
+ appuser
And now the user should be back:
> psql -d flipr_test -c '\du flipr'
List of roles
Role name | Attributes | Member of
-----------+------------+-----------
flipr | | {}
When we look at the status, the deployment will be there:
> sqitch -d flipr_test status
# On database flipr_test
# Change: 9df095ad10d799c3acdd74f7986ee1ed9a75e766
# Name: appuser
# Deployed: 2012-07-06 19:01:19 +0200
# By: david
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
# Change: 9df095ad10d799c3acdd74f7986ee1ed9a75e766
# Name: appuser
# Deployed: 2012-07-06 19:01:19 +0200
# By: david
Yay, that allows things to be a little more concise. Let's make some more changes!
Deploy with Dependency
Let's add another deployment, 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 appuser
Created deploy/users.sql
Created revert/users.sql
Created test/users.sql
Added "users :appuser" to sqitch.plan
Note that we're requiring the appuser
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: appuser
BEGIN;
SET client_min_messages = 'warning';
CREATE TABLE users (
nickname TEXT PRIMARY KEY,
password TEXT NOT NULL,
timestamp TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
GRANT SELECT ON users TO flipr;
COMMIT;
A few things to notice here. On the second line, the dependence on the appuser
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.
Just before the commit, the GRANT
command grants SELECT
access on the table to the flipr
user created by the appuser
change. This is why we need to require the appuser
change.
Now for the revert script. Add this to revert/users.sql
:
DROP TABLE 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 users'
Table "public.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
# Change: 9d078bbc05a0950e7175c067bd2662de180e17a6
# Name: users
# Deployed: 2012-07-06 19:18:17 +0200
# By: david
#
Nothing to deploy (up-to-date)
Success! Let's make sure we can revert the change, as well:
> sqitch revert --to appuser
Reverting from flipr_test to appuser
- users
Note that we've used the --to
option to revert only to appuser
. The users
table should be gone, but the flipr
user should still be around:
> psql -d flipr_test -c '\d users'
Did not find any relation named "users".
> psql -d flipr_test -c '\du flipr'
List of roles
Role name | Attributes | Member of
-----------+------------+-----------
flipr | | {}
Now commit and deploy again:
> git add .
> git commit -am 'Add users table.'
[master 36590a3] Add users table.
4 files changed, 31 insertions(+)
create mode 100644 deploy/users.sql
create mode 100644 /users.sql
> sqitch deploy
Deploying changes to flipr_test
+ users
Looks good. Check the status:
> sqitch status
# On database flipr_test
# Change: 9d078bbc05a0950e7175c067bd2662de180e17a6
# Name: users
# Deployed: 2012-07-06 19:19:02 +0200
# By: david
#
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 appuser
Created deploy/insert_user.sql
Created revert/insert_user.sql
Created test/insert_user.sql
Added "insert_user :users :appuser" to sqitch.plan
> sqitch add change_pass --requires users --requires appuser
Created deploy/change_pass.sql
Created revert/change_pass.sql
Created test/change_pass.sql
Added "change_pass :users :appuser" 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-a1
appuser
users :appuser
insert_user :users :appuser
change_pass :users :appuser
Just a simple list of changes and their dependencies. 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: appuser
BEGIN;
CREATE OR REPLACE FUNCTION insert_user(
nickname TEXT,
password TEXT
) RETURNS VOID LANGUAGE SQL SECURITY DEFINER AS $$
INSERT INTO users VALUES($1, md5($2));
$$;
GRANT EXECUTE ON FUNCTION insert_user(TEXT, TEXT) TO flipr;
COMMIT;
And revert/insert_user.sql
should look something like this:
-- Revert insert_user
BEGIN;
DROP FUNCTION insert_user(TEXT, TEXT);
COMMIT;
Now for change_pass
; deploy/change_pass.sql
might look like this:
-- Deploy change_pass
-- requires: users
-- requires: appuser
BEGIN;
CREATE OR REPLACE FUNCTION change_pass(
nick TEXT,
oldpass TEXT,
newpass TEXT
) RETURNS BOOLEAN LANGUAGE plpgsql SECURITY DEFINER AS $$
BEGIN
UPDATE users
SET password = md5($3)
WHERE nickname = $1
AND password = md5($2);
RETURN FOUND;
END;
$$;
GRANT EXECUTE ON FUNCTION change_pass(TEXT, TEXT, TEXT) TO flipr;
COMMIT;
And of course, its revert
script, revert/change_pass.sql
, should look something like:
-- Revert change_pass
BEGIN;
DROP FUNCTION 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'
List of functions
Schema | Name | Result data type | Argument data types | Type
--------+-------------+------------------+---------------------------------------+--------
public | change_pass | boolean | nick text, oldpass text, newpass text | normal
public | insert_user | void | nickname text, password text | normal
And what's the status?
> sqitch status
# On database flipr_test
# Change: 02c5592d1db6c22c0a8d5e7ff963d5aa5ce065a3
# Name: change_pass
# Deployed: 2012-07-06 19:21:34 +0200
# By: david
#
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'
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 657a2e2] Add `insert_user()` and `change_pass()`.
7 files changed, 69 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
# Change: 02c5592d1db6c22c0a8d5e7ff963d5aa5ce065a3
# Name: change_pass
# Deployed: 2012-07-06 19:22:52 +0200
# By: david
#
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
Tagged "change_pass" with @v1.0.0-dev1
> git commit -am 'Tag the database with v1.0.0-dev1.'
> 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
+ appuser
+ 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_test
# Change: 02c5592d1db6c22c0a8d5e7ff963d5aa5ce065a3
# Name: change_pass
# Tag: @v1.0.0-dev1
# Deployed: 2012-07-06 19:24:58 +0200
# By: david
#
Nothing to deploy (up-to-date)
Note that all the tag is now listed as part of the stats message. Now let's bundle everything up for release:
> sqitch bundle
Bundling in bundle/
+ appuser
+ 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
+ appuser
+ 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
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 flips (
id BIGSERIAL PRIMARY KEY,
nickname TEXT NOT NULL REFERENCES users(nickname),
body TEXT NOT NULL DEFAULT '' CHECK ( length(body) <= 180 ),
timestamp TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp()
);
GRANT SELECT ON flips TO flipr;
COMMIT;
And edit revert/flips.sql:
-- Revert flips
BEGIN;
DROP TABLE flips;
COMMIT;
And give it a whirl:
> sqitch deploy
Deploying changes to flipr_test
+ flips
Look good?
> sqitch status --show tags
# On database flipr_test
# Change: 540359a3892d1476f9ca6ccf7d3f9993ac383b68
# Name: delete_flip
# Deployed: 2012-07-06 19:27:33 +0200
# By: david
#
# Tags: None.
#
Nothing to deploy (up-to-date)
Note the use of --show tags
to show all the deployed tags. But there are none. Wait, what?
Oh, we added @v1.0.0-dev1
since the last deploy to the flipr_test
database, so of course it's not there. So let's revert to insert_user
and then deploy again to get it.
> sqitch revert insert_user
Reverting from flipr_test to insert_user
- flips
- change_pass @v1.0.0-dev1
> sqitch deploy
Deploying changes to flipr_test
+ change_pass @v1.0.0-dev1
+ flips
> sqitch status --show tags
# On database flipr_test
# Change: 540359a3892d1476f9ca6ccf7d3f9993ac383b68
# Name: delete_flip
# Deployed: 2012-07-06 19:28:56 +0200
# By: david
#
# Tags:
# @v1.0.0-dev1 - 2012-04-09 20:45:23 - david
#
Nothing to deploy (up-to-date)
Ah, that's more like it. Now make it so:
> git add .
> git commit -am 'Add flipr table.'
[flips efca0a9] Add flipr table.
4 files changed, 32 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:
-- requires: flips, appuser
BEGIN;
CREATE OR REPLACE FUNCTION insert_flip(
nickname TEXT,
body TEXT
) RETURNS BIGINT LANGUAGE sql SECURITY DEFINER AS $$
INSERT INTO flips (body, nickname)
VALUES ($1, $2)
RETURNING id;
$$;
GRANT EXECUTE ON FUNCTION insert_flip(TEXT, TEXT) to flipr;
COMMIT;
And the delete_flip
deploy script might look something like:
-- requires: flips, appuser
BEGIN;
CREATE OR REPLACE FUNCTION delete_flip(
flip_id BIGINT
) RETURNS BOOLEAN LANGUAGE plpgsql SECURITY DEFINER AS $$
BEGIN
DELETE FROM flips WHERE id = flip_id;
RETURN FOUND;
END;
$$;
GRANT EXECUTE ON FUNCTION delete_flip(BIGINT) to flipr;
COMMIT;
The revert
scripts are:
DROP FUNCTION insert_flip(TEXT, TEXT);
And:
DROP FUNCTION 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
# Change: 540359a3892d1476f9ca6ccf7d3f9993ac383b68
# Name: delete_flip
# Deployed: 2012-07-06 19:29:17 +0200
# By: david
#
# Tag:
# @v1.0.0-dev1 - 2012-07-06 19:29:17 +0200 - david
#
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 c9473fc..966ba2e
Fast-forward
deploy/delete_list.sql | 20 ++++++++++++++++++++
deploy/insert_list.sql | 17 +++++++++++++++++
deploy/lists.sql | 18 ++++++++++++++++++
revert/delete_list.sql | 7 +++++++
revert/insert_list.sql | 7 +++++++
revert/lists.sql | 7 +++++++
sqitch.plan | 3 +++
test/delete_list.sql | 7 +++++++
test/insert_list.sql | 7 +++++++
test/lists.sql | 7 +++++++
10 files changed, 100 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
. Looks like some list support was added. 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 ofmaster
.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 966ba2e 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
Switched to branch 'flips'
> git rebase master
First, rewinding head to replay your work on top of it...
Applying: Add flipr 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 flipr 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 flipr table.
Using index info to reconstruct a base tree...
Falling back to patching base and 3-way merge...
Auto-merging sqitch.plan
Applying: Add `insert_flip()` and `delete_flip()`.
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-a1
appuser
users :appuser
insert_user :users :appuser
change_pass :users :appuser
@v1.0.0-dev1
lists :users :appuser
insert_list :lists :appuser
delete_list :lists :appuser
flips :users
insert_flip :flips :appuser
delete_flip :flips :appuser
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
- appuser
> sqitch deploy
Deploying changes to flipr_test
+ appuser
+ 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 ci -m 'Add `.gitattributes` with union merge for `sqitch.plan`.'
[flips 691ee81] 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 | 17 +++++++++++++++++
deploy/flips.sql | 17 +++++++++++++++++
deploy/insert_flip.sql | 17 +++++++++++++++++
revert/delete_flip.sql | 7 +++++++
revert/flips.sql | 7 +++++++
revert/insert_flip.sql | 7 +++++++
sqitch.plan | 3 +++
test/delete_flip.sql | 7 +++++++
test/flips.sql | 7 +++++++
test/insert_flip.sql | 7 +++++++
11 files changed, 97 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-a1
appuser
users :appuser
insert_user :users :appuser
change_pass :users :appuser
@v1.0.0-dev1
lists :users :appuser
insert_list :lists :appuser
delete_list :lists :appuser
flips :users
insert_flip :flips :appuser
delete_flip :flips :appuser
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
Tagged "delete_flip" with @v1.0.0-dev2
> git commit -am 'Tag the database with v1.0.0-dev2.'
[master 54e2b6c] 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/
+ appuser
+ 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 insert_user('foo', 'secr3t'), insert_user('bar', 'secr3t');
SELECT * FROM users;
"
nickname | password | timestamp
----------+----------------------------------+-------------------------------
foo | 9695da4dd567a19f9b92065f240c6725 | 2012-04-11 23:00:02.135612+00
bar | 9695da4dd567a19f9b92065f240c6725 | 2012-04-11 23:00:02.135612+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:
Copy deploy/insert_user.sql to deploy/insert_user_crypt.sql.
Edit deploy/insert_user_crypt.sql to switch from
MD5()
tocrypt()
and to add a dependency on thepgcrypto
change.Copy deploy/insert_user.sql to revert/insert_user_crypt.sql. Yes, copy the original change script to the new revert change.
Test the changes to make sure you can deploy and revert the
insert_user_crypt
change.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
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
# 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: appuser
+-- requires: pgcrypto
BEGIN;
@@ -8,7 +9,7 @@ CREATE OR REPLACE FUNCTION insert_user(
nickname TEXT,
password TEXT
) RETURNS VOID LANGUAGE SQL SECURITY DEFINER AS $$
- INSERT INTO users VALUES($1, md5($2));
+ INSERT INTO users values($1, crypt($2, gen_salt('md5')));
$$;
GRANT EXECUTE ON FUNCTION insert_user(TEXT, TEXT) TO flipr;
Go ahead and rework the change_pass
change, too:
> sqitch rework change_pass --requires 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: appuser
+-- requires: pgcrypto
BEGIN;
@@ -11,9 +12,9 @@ CREATE OR REPLACE FUNCTION change_pass(
) RETURNS BOOLEAN LANGUAGE plpgsql SECURITY DEFINER AS $$
BEGIN
UPDATE 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 users;
SELECT insert_user('foo', 'secr3t'), insert_user('bar', 'secr3t');
SELECT * FROM users;
"
nickname | password | timestamp
----------+------------------------------------+-------------------------------
foo | $1$l6OEKyF3$kv5ae7505ROub75d9QKTh/ | 2012-04-12 18:55:43.422211+00
bar | $1$J4NJDgaJ$578i9Lt6b8ohJwi6WhNNO1 | 2012-04-12 18:55:43.422211+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 users;
SELECT insert_user('foo', 'secr3t'), insert_user('bar', 'secr3t');
SELECT * FROM users;
"
nickname | password | timestamp
----------+----------------------------------+-------------------------------
foo | 9695da4dd567a19f9b92065f240c6725 | 2012-04-12 18:56:03.292423+00
bar | 9695da4dd567a19f9b92065f240c6725 | 2012-04-12 18:56:03.292423+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 bf926f4] Use pgcrypto to encrypt passwords.
11 files changed, 101 insertions(+), 12 deletions(-)
create mode 100644 deploy/change_pass@v1.0.0-dev2.sql
create mode 100644 deploy/insert_user@v1.0.0-dev2.sql
rewrite revert/change_pass.sql (78%)
rename revert/{change_pass.sql => change_pass@v1.0.0-dev2.sql} (100%)
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
# Change: 02c5592d1db6c22c0a8d5e7ff963d5aa5ce065a3
# Name: change_pass
# Deployed: 2012-07-06 19:30:45 +0200
# By: david
#
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.