Name
sqitchtutorial-firebird - A tutorial introduction to Sqitch change management on Firebird
Synopsis
sqitch *
Description
This tutorial explains how to create a sqitch-enabled Firebird 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 Firebird as the storage engine.
If you'd like to manage an PostgreSQL database, see sqitchtutorial.
If you'd like to manage an SQLite database, see sqitchtutorial-sqlite.
If you'd like to manage an Oracle database, see sqitchtutorial-oracle.
If you'd like to manage an MySQL database, see sqitchtutorial-mysql.
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 'Initialize project, add README.'
[master (root-commit) 0b85704] Initialize project, add README.
1 files changed, 39 insertions(+), 0 deletions(-)
create mode 100644 README.md
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 firebird init flipr --uri https://github.com/theory/sqitch-firebird-intro/
Created sqitch.conf
Created sqitch.plan
Created deploy/
Created revert/
Created verify/
Let's have a look at sqitch.conf:
> cat sqitch.conf
[core]
engine = firebird
# plan_file = sqitch.plan
# top_dir = .
# deploy_dir = deploy
# revert_dir = revert
# verify_dir = verify
# extension = sql
# [core "firebird"]
# target = db:firebird:
# registry = sqitch
# client = /usr/bin/isql-fb
Good, it picked up on the fact that we're creating changes for the Firebird engine, thanks to the --engine firebird
option, and saved it to the file. Furthermore, it wrote a commented-out [core "firebird"]
section with all the available Firebird 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 user-specific settings.
The current implementation of the engine will try to find Firebird's firebird
client (implemented for GNU/Linux and Microsoft Windows). This might fail, so we go ahead an tell it where to find the client on our computer, for example on GNU/Linux with the standard location of the Firebird installation the command is:
> sqitch config --user core.firebird.client /opt/firebird/bin/isql
Note: On some GNU/Linux distributions the firebird client is renamed to isql-fb
, for example in Debian and Fedora, or fbsql
in Gentoo.
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 something like this:
> cat ~/.sqitch/sqitch.conf
[core "firebird"]
client = /opt/local/bin/isql
[user]
name = Marge N. O’Vera
email = marge@example.com
Which means that Sqitch should be able to find isql
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:
> cat sqitch.plan
%syntax-version=1.0.0-b2
%project=flipr
%uri=https://github.com/theory/sqitch-firebird-intro/
Note that it has picked up on the name and URI of the app we're building. Sqitch uses this data to manage cross-project dependencies. 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 728f9af] Initialize Sqitch configuration.
2 files changed, 19 insertions(+), 0 deletions(-)
create mode 100644 sqitch.conf
create mode 100644 sqitch.plan
Let's create our flipr test database using isql
:
> sudo -u firebird mkdir /tmp/flipr_test
> echo "CREATE DATABASE 'localhost:/tmp/flipr_test/flipr.fdb'; exit;" \
| isql-fb -u SYSDBA -p masterkey
Use CONNECT or CREATE DATABASE to specify a database
Our First Change
Let's create a table. Our app will need users, of course, so we'll create a table for them. Run this command:
> sqitch add users -n 'Creates table to track our users.'
Created deploy/users.sql
Created revert/users.sql
Created verify/users.sql
Added "users" to sqitch.plan
The add
command adds a database change to the plan and writes deploy, revert, and verify scripts that represent the change. Now we edit these files. The deploy
script's job is to create the table. By default, the deploy/users.sql file looks like this:
-- Deploy users
-- XXX Add DDLs here.
COMMIT;
What we want to do is to replace the XXX
comment with the CREATE TABLE
statement, like so:
-- Deploy users
CREATE TABLE users (
nickname VARCHAR(50) PRIMARY KEY,
password VARCHAR(512) NOT NULL,
fullname VARCHAR(512) NOT NULL,
twitter VARCHAR(512) NOT NULL,
timestmp TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
COMMIT;
The revert
script's job is to precisely revert the change to the deploy script, so we edit this to revert/users.sql to look like this:
-- Revert users
DROP TABLE users;
COMMIT;
Now we can try deploying this change:
> sqitch deploy db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb
Adding registry tables to db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/sqitch.fdb
Deploying changes to db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb
+ users .. ok
First Sqitch created the registry database and tables used to track database changes. The registry is separate from the database to which the users
change was deployed; by default, its name is sqitch.$suffix
, where $suffix
is the same as the suffix on the target database, if any. It lives in the same directory as the target database, which means that one registry database is used for all the databases with the same suffix in a single directory.
Next, Sqitch deploys changes to the target database. We only have one change so far; the +
reinforces the idea that the change is being added to the database.
If you'd like it to have a different name for the registry database, use sqitch config core.firebird.registry $name
to configure it (or via the target
command; more below). This will be useful if you don't want to use the same registry database to manage multiple databases, or if you do, but they live in different directories.
Next, Sqitch deploys changes to the target database, which we specified on the command-line. 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 users
table:
> echo "CONNECT 'localhost:/tmp/flipr_test/flipr.fdb'; SHOW TABLES; quit;" \
| isql-fb -u SYSDBA -p masterkey
Use CONNECT or CREATE DATABASE to specify a database
USERS
Trust, But Verify
But that's too much work. do you really want to do something like that after every deploy?
Here's where the verify
script comes in. Its job is to test that the deploy did was it was supposed to. It should do so without regard to any data that might be in the database, and should throw an error if the deploy was not successful. The easiest way to do that with a table is to simply SELECT
from it. Put this query into verify/users.sql:
SELECT nickname, password, fullname, twitter
FROM users
WHERE 1=2;
Now you can run the verify
script with the verify
command:
> sqitch verify db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb
Verifying db:firebird://sysdba:@localhost//tmp/flipr_test/flipr.fdb
* users .. ok
Verify successful
Looks good! If you want to make sure that the verify script correctly dies if the table doesn't exist, temporarily change the table name in the script to something that doesn't exist, something like:
SELECT nickname, password, timestmp
FROM users_nonesuch
WHERE 1=2;
Then verify
again:
> sqitch verify db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb
Verifying db:firebird://sysdba:@localhost//tmp/flipr_test/flipr.fdb
* users .. Statement failed, SQLSTATE = 42S02
Dynamic SQL Error
-SQL error code = -204
-Table unknown
-USERS_NONESUCH
-At line 3, column 2
At line 3 in file verify/users.sql
# Verify script "verify/users.sql" failed.
not ok
Verify Summary Report
---------------------
Changes: 1
Errors: 1
Verify failed
Firebird is kind enough to tell us what the problem is. Don't forget to change the table name back before continuing!
Status, Revert, Log, Repeat
For purely informational purposes, we can always see how a deployment was recorded via the status
command, which reads the tables from the registry database:
> sqitch status db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb
# On database db:firebird://sysdba:@localhost//tmp/flipr_test/flipr.fdb
# Project: flipr
# Change: ee2161d26c0c288c3435cf44802920f428fb1928
# Name: users
# Deployed: 2014-01-03 14:12:50 -0800
# 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 revert db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb
Revert all changes from db:firebird://sysdba:@localhost//tmp/flipr_test/flipr.fdb? [Yes]
- users .. ok
The revert
command first prompts to make sure that we really do want to revert. This is to prevent unnecessary accidents. You can pass the -y
option to disable the prompt. Also, notice the -
before the change name in the output, which reinforces that the change is being removed from the database. And now the users
table should be gone:
> echo "CONNECT 'localhost:/tmp/flipr_test/flipr.fdb'; SHOW TABLES; quit;" \
| isql-fb -u SYSDBA -p masterkey
Use CONNECT or CREATE DATABASE to specify a database
There are no tables in this database
And the status message should reflect as much:
> sqitch status db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb
# On database db:firebird://sysdba:@localhost//tmp/flipr_test/flipr.fdb
No changes deployed
Of course, since nothing is deployed, the verify
command has nothing to verify:
> sqitch verify db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb
Verifying db:firebird://sysdba:@localhost//tmp/flipr_test/flipr.fdb
No changes deployed
However, we still have a record that the change happened, visible via the log
command:
> sqitch log db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb
On database db:firebird://sysdba:@localhost//tmp/flipr_test/flipr.fdb
Revert ee2161d26c0c288c3435cf44802920f428fb1928
Name: users
Committer: Marge N. O’Vera <marge@example.com>
Date: 2014-01-03 14:25:22 -0800
Creates table to track our users.
Deploy ee2161d26c0c288c3435cf44802920f428fb1928
Name: users
Committer: Marge N. O’Vera <marge@example.com>
Date: 2014-01-03 14:12:50 -0800
Creates table to track our users.
Note that the actions we took are shown in reverse chronological order, with the revert first and then the deploy.
With this change deployed, if you connect to the database, you'll be able to see the schema:
> psql -d flipr_test -c '\dn flipr'
List of schemas
Name | Owner
-------+-------
flipr | marge
Trust, But Verify
But that's too much work. Do you really want to do something like that after every deploy?
Here's where the verify
script comes in. Its job is to test that the deploy did was it was supposed to. It should do so without regard to any data that might be in the database, and should throw an error if the deploy was not successful. In PostgreSQL, the simplest way to do so for non-queryable objects such as schemas is to take advantage the access privilege inquiry functions. These functions conveniently throw exceptions if the object being inquired does not exist. For our new schema, has_schema_privilege()
will do very nicely. Put this query into verify/appschema.sql:
SELECT pg_catalog.has_schema_privilege('flipr', 'usage');
Such functionality may not be available to other databases, but you can use any query that will throw an exception if the schema doesn't exist. One handy way to do that is to divide by zero if an object doesn't exist. So for other databases, assuming division by zero is fatal, you could do something like this:
SELECT 1/COUNT(*) FROM information_schema.schemata WHERE schema_name = 'flipr';
Either way, run the verify
script with the verify
command:
> sqitch verify db:pg:flipr_test
Verifying db:pg:flipr_test
* appschema .. ok
Verify successful
Looks good! If you want to make sure that the verify script correctly dies if the schema doesn't exist, temporarily change the schema name in the script to something that doesn't exist, something like:
SELECT pg_catalog.has_schema_privilege('nonesuch', 'usage');
Then verify
again:
> sqitch verify db:pg:flipr_test
Verifying db:pg:flipr_test
* appschema .. psql:verify/appschema.sql:5: ERROR: schema "nonesuch" does not exist
# Verify script "verify/appschema.sql" failed.
not ok
Verify Summary Report
---------------------
Changes: 1
Errors: 1
Verify failed
It's even nice enough to tell us what the problem is. Or, for the divide-by-zero example, change the schema name:
SELECT 1/COUNT(*) FROM information_schema.schemata WHERE schema_name = 'nonesuch';
Then the verify will look something like:
> sqitch verify db:pg:flipr_test
Verifying db:pg:flipr_test
* appschema .. psql:verify/appschema.sql:5: ERROR: division by zero
# Verify script "verify/appschema.sql" failed.
not ok
Verify Summary Report
---------------------
Changes: 1
Errors: 1
Verify failed
Less useful error output, but enough to alert us that something has gone wrong.
Don't forget to change the schema name back before continuing!
Status, Revert, Log, Repeat
For purely informational purposes, we can always see how a deployment was recorded via the status
command, which reads the registry tables from the database:
> sqitch status db:pg:flipr_test
# On database db:pg:flipr_test
# Project: flipr
# Change: c7981df861183412b01be706889e508a63d445ca
# Name: appschema
# Deployed: 2013-12-30 15:27:15 -0800
# 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 revert db:pg:flipr_test
Revert all changes from db:pg:flipr_test? [Yes]
- appschema .. ok
The revert
command first prompts to make sure that we really do want to revert. This is to prevent unnecessary accidents. You can pass the -y
option to disable the prompt. Also, notice the -
before the change name in the output, which reinforces that the change is being removed from the database. And now the schema 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 status db:pg:flipr_test
# On database db:pg:flipr_test
No changes deployed
Of course, since nothing is deployed, the verify
command has nothing to verify:
> sqitch verify db:pg:flipr_test
Verifying db:pg:flipr_test
No changes deployed
However, we still have a record that the change happened, visible via the log
command:
> sqitch log db:pg:flipr_test
On database db:pg:flipr_test
Revert c7981df861183412b01be706889e508a63d445ca
Name: appschema
Committer: Marge N. O’Vera <marge@example.com>
Date: 2013-12-30 15:38:17 -0800
Add schema for all flipr objects.
Deploy c7981df861183412b01be706889e508a63d445ca
Name: appschema
Committer: Marge N. O’Vera <marge@example.com>
Date: 2013-12-30 15:27:15 -0800
Add 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 users table.'
[master 1125529] Add users table.
4 files changed, 24 insertions(+), 0 deletions(-)
create mode 100644 deploy/users.sql
create mode 100644 revert/users.sql
create mode 100644 verify/users.sql
And then deploy again. This time, let's use the --verify
option, so that the verify
script is applied when the change is deployed:
> sqitch deploy db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb --verify
Deploying changes to db:firebird://sysdba:@localhost//tmp/flipr_test/flipr.fdb
+ users .. ok
And now the users
table should be back:
> echo "CONNECT 'localhost:/tmp/flipr_test/flipr.fdb'; SHOW TABLES; quit;"
| isql-fb -u SYSDBA -p masterkey
Use CONNECT or CREATE DATABASE to specify a database
USERS
When we look at the status, the deployment will be there:
> sqitch status db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb
# On database db:firebird://sysdba:@localhost//tmp/flipr_test/flipr.fdb
# Project: flipr
# Change: ee2161d26c0c288c3435cf44802920f428fb1928
# Name: users
# Deployed: 2014-01-03 14:31:16 -0800
# By: Marge N. O’Vera <marge@example.com>
#
Nothing to deploy (up-to-date)
On Target
I'm getting a little tired of always having to type db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb
, aren't you? This database connection URI tells Sqitch how to connect to the deployment target, but we don't have to keep using the URI. We can name the target:
> sqitch target add flipr_test db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb
The target
command, inspired by git-remote
, allows management of one or more named deployment targets. We've just added a target named flipr_test
, which means we can use the string flipr_test
for the target, rather than the URI. But since we're doing so much testing, we can also tell Sqitch to deploy to the flipr_test
target by default:
> sqitch config core.firebird.target flipr_test
Now we can omit the target argument altogether, 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: ee2161d26c0c288c3435cf44802920f428fb1928
# Name: users
# Deployed: 2014-01-03 14:31:16 -0800
# 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 also make sure that changes are verified after deploying them:
> sqitch config --bool deploy.verify true
> sqitch config --bool rebase.verify true
We'll see the rebase
command a bit later. In the meantime, let's commit the new configuration and and make some more changes!
> git commit -am 'Set default target and always verify.'
[master 62d8a06] Set default target and always verify.
1 files changed, 4 insertions(+), 0 deletions(-)
Deploy with Dependency
Let's add another change. Our app will need to store status messages from users. Let's call them -- and the table to store them -- "flips". First, add the new change:
> sqitch add flips --requires users -n 'Adds table for storing flips.'
Created deploy/flips.sql
Created revert/flips.sql
Created verify/flips.sql
Added "flips [users]" to sqitch.plan
Note that we're requiring the users
change as a dependency of the new flips
change. Although that change has already been added to the plan and therefore should always be applied before the flips
change, it's a good idea to be explicit about dependencies.
Now edit the scripts. When you're done, deploy/flips.sql should look like this:
-- Deploy flips
-- requires: users
CREATE TABLE flips (
id INTEGER NOT NULL PRIMARY KEY,
nickname VARCHAR(50) NOT NULL REFERENCES users(nickname),
body VARCHAR(512) NOT NULL CHECK ( char_length(body) <= 180 ),
timestmp TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
COMMIT;
A couple things to notice here. On the second line, the dependence on the users
change has been listed. This doesn't do anything, but the default deploy
template lists it here for your reference while editing the file. Useful, right?
The users.nickname
column references the users
table. This is why we need to require the users
change.
Now for the verify script. Again, all we need to do is SELECT
from the table. I recommend selecting each column by name, too, to be sure that no column is missing. Here's the verify/flips.sql:
-- Verify flips
SELECT id, nickname, body, timestmp
FROM flips
WHERE 1=2;
ROLLBACK;
Now for the revert script: all we have to do is drop the table. Add this to revert/flips.sql:
-- Revert flips
DROP TABLE flips;
COMMIT;
Couldn't be much simpler, right? Let's deploy this bad boy:
> sqitch deploy
Deploying changes to flipr_test
+ flips .. ok
We know, since verification is enabled, that the table must have been created. But for the purposes of visibility, let's have a quick look:
> echo "CONNECT 'localhost:/tmp/flipr_test/flipr.fdb'; SHOW TABLES; quit;" \
| isql-fb -u SYSDBA -p masterkey
Use CONNECT or CREATE DATABASE to specify a database
FLIPS USERS
We can also verify all currently deployed changes with the verify
command:
> sqitch verify
Verifying flipr_test.db
* users .. ok
* flips .. ok
Verify successful
Now have a look at the status:
> sqitch status
# On database flipr_test
# Project: flipr
# Change: 3821940f7b7d81a4af861424da967011ebf00ac6
# Name: flips
# Deployed: 2014-01-03 14:39:13 -0800
# 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 @HEAD^ -y
Reverting changes to users from flipr_test
- flips .. ok
Note that we've used the --to
option to specify the change to revert to. And what do we revert to? The symbolic tag @HEAD
, when passed to revert
, always refers to the last change deployed to the database. (For other commands, it refers to the last change in the plan.) Appending the caret (^
) tells Sqitch to select the change prior to the last deployed change. So we revert to users
, the penultimate change. The other potentially useful symbolic tag is @ROOT
, which refers to the first change deployed to the database (or in the plan, depending on the command).
Back to the database. The flips
table should be gone but the users
table should still be around:
> echo "CONNECT 'localhost:/tmp/flipr_test/flipr.fdb'; SHOW TABLES; quit;" \
| isql-fb -u SYSDBA -p masterkey
Use CONNECT or CREATE DATABASE to specify a database
USERS
The status
command politely informs us that we have undeployed changes:
> sqitch status
# On database flipr_test
# Project: flipr
# Change: ee2161d26c0c288c3435cf44802920f428fb1928
# Name: users
# Deployed: 2014-01-03 14:31:16 -0800
# By: Marge N. O’Vera <marge@example.com>
#
Undeployed change:
* flips
As does the verify
command:
> sqitch --db-name /home/fbdb/flipr_test.fdb verify
Verifying flipr_test
* users .. ok
Undeployed change:
* flips
Verify successful
Note that the verify is successful, because all currently-deployed changes are verified. The list of undeployed changes (just "flips" here) reminds us about the current state.
Okay, let's commit and deploy again:
> git add .
> git commit -am 'Add flips table.'
[master 469477c] Add flips table.
4 files changed, 24 insertions(+), 0 deletions(-)
create mode 100644 deploy/flips.sql
create mode 100644 revert/flips.sql
create mode 100644 verify/flips.sql
> sqitch deploy
Deploying changes to flipr_test
+ flips .. ok
Looks good. Check the status:
> sqitch status
# On database flipr_test
# Project: flipr
# Change: 3821940f7b7d81a4af861424da967011ebf00ac6
# Name: flips
# Deployed: 2014-01-03 14:42:58 -0800
# By: Marge N. O’Vera <marge@example.com>
#
Nothing to deploy (up-to-date)
View to a Thrill
One more thing to add before we are ready to ship a first beta release. Let's create a view that lists user names with their flips.
> sqitch add userflips --requires users --requires flips \
-n 'Creates the userflips view.'
Created deploy/userflips.sql
Created revert/userflips.sql
Created verify/userflips.sql
Added "userflips [users flips]" to sqitch.plan
Now add this SQL to deploy/userflips.sql:
CREATE VIEW userflips AS
SELECT f.id, u.nickname, u.fullname, f.body, f.timestmp
FROM users u
JOIN flips f ON u.nickname = f.nickname;
Add this SQL to verify/userflips.sql
SELECT id, nickname, fullname, body, timestmp
FROM userflips
WHERE 1=2;
And add the DROP VIEW
statement to revert/userflips.sql:
DROP VIEW userflips;
Now Try it out!
> sqitch deploy
Deploying changes to flipr_test
+ userflips .. ok
> sqitch revert -y
Reverting all changes from flipr_test
- userflips .. ok
- flips ...... ok
- users ...... ok
> sqitch deploy
Deploying changes to flipr_test
+ users ...... ok
+ flips ...... ok
+ userflips .. ok
Looks good! Commit it.
> git add .
> git commit -m 'Add the userflips view.'
[master 3140c99] Add the userflips view.
4 files changed, 23 insertions(+), 0 deletions(-)
create mode 100644 deploy/userflips.sql
create mode 100644 revert/userflips.sql
create mode 100644 verify/userflips.sql
Ship It!
Now we're ready for the first development 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 "userflips" with @v1.0.0-dev1
> git commit -am 'Tag the database with v1.0.0-dev1.'
[master 3a7da20] Tag the database with v1.0.0-dev1.
1 files changed, 1 insertions(+), 0 deletions(-)
> git tag v1.0.0-dev1 -am 'Tag v1.0.0-dev1'
We can try deploying to make sure the tag gets picked up like so:
> sudo -u firebird mkdir /tmp/flipr_dev
> echo "CREATE DATABASE 'localhost:/tmp/flipr_dev/flipr.fdb'; exit;" \
| isql-fb -u SYSDBA -p masterkey
> sqitch deploy db:firebird://sysdba:masterkey@localhost//tmp/flipr_dev/flipr.fdb
Adding registry tables to db:firebird://sysdba:@localhost//tmp/flipr_dev/sqitch.fdb
Deploying changes to db:firebird://sysdba:@localhost//tmp/flipr_dev/flipr.fdb
+ users ................... ok
+ flips ................... ok
+ userflips @v1.0.0-dev1 .. ok
Great, both changes were deployed and userflips
was tagged with @v1.0.0-dev1
. Let's have a look at the status:
> sqitch status db:firebird://sysdba:masterkey@localhost//tmp/flipr_dev/flipr.fdb
# On database db:firebird://sysdba:@localhost//tmp/flipr_dev/flipr.fdb
# Project: flipr
# Change: 7b554d973f84680dbe1e9af44a52a2caf4d185d1
# Name: userflips
# Tag: @v1.0.0-dev1
# Deployed: 2014-01-03 14:49:57 -0800
# By: Marge N. O’Vera <marge@example.com>
#
Nothing to deploy (up-to-date)
Note the listing of the tag as part of the status message. Now let's bundle everything up for release:
> sqitch bundle
Bundling into bundle
Writing config
Writing plan
Writing scripts
+ users
+ flips
+ userflips @v1.0.0-dev1
Now we can package the bundle directory and distribute it. When it gets installed somewhere, users can use Sqitch to deploy to the database. Let's try deploying it:
> cd bundle
> sudo -u firebird mkdir /tmp/flipr_prod
> echo "CREATE DATABASE 'localhost:/tmp/flipr_prod/flipr.fdb'; exit;" \
| isql-fb -u SYSDBA -p masterkey
> sqitch deploy db:firebird://sysdba:masterkey@localhost//tmp/flipr_prod/flipr.fdb
Adding registry tables to db:firebird://sysdba:@localhost//tmp/flipr_prod/sqitch.fdb
Deploying changes to db:firebird://sysdba:@localhost//tmp/flipr_prod/flipr.fdb
+ users ................... ok
+ flips ................... ok
+ userflips @v1.0.0-dev1 .. ok
Looks much the same as before, eh? Package it up and ship it!
> cd ..
> mv bundle flipr-v1.0.0-dev1
> tar -czf flipr-v1.0.0-dev1.tgz flipr-v1.0.0-dev1
Making a Hash of Things
Now that we've got the basics of the app done, let's add a feature. Gotta track the hashtags associated with flips, right? Let's add a table for them. But 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 hashtags
Switched to a new branch 'hashtags'
Now we can add a new change to create a table for hashtags.
> sqitch add hashtags --requires flips -n 'Adds table for storing hashtags.'
Created deploy/hashtags.sql
Created revert/hashtags.sql
Created verify/hashtags.sql
Added "hashtags [flips]" to sqitch.plan
You know the drill by now. Add this to deploy/hashtags.sql
CREATE TABLE hashtags (
flip_id INTEGER NOT NULL REFERENCES flips(id),
hashtag VARCHAR(512) NOT NULL CHECK(char_length(hashtag) > 0),
PRIMARY KEY (flip_id, hashtag)
);
Again, select from the table in verify/hashtags.sql:
SELECT flip_id, hashtag FROM hashtags WHERE 1=2;
And drop it in revert/hashtags.sql
DROP TABLE hashtags;
And give it a whirl:
> sqitch deploy
Deploying changes to flipr_test
+ hashtags .. ok
Look good?
> sqitch status --show-tags
# On database flipr_test
# Project: flipr
# Change: 30501a00b1411219942b568343e92fb4d60abc04
# Name: hashtags
# Deployed: 2014-01-03 15:02:44 -0800
# By: Marge N. O’Vera <marge@example.com>
#
# Tag:
# @v1.0.0-dev1 - 2014-01-03 14:59:06 -0800 - 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 hashtags table.'
[hashtags 1cff809] Add hashtags table.
4 files changed, 22 insertions(+), 0 deletions(-)
create mode 100644 deploy/hashtags.sql
create mode 100644 revert/hashtags.sql
create mode 100644 verify/hashtags.sql
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 3a7da20..4d6ba93
Fast-forward
deploy/lists.sql | 11 +++++++++++
revert/lists.sql | 5 +++++
sqitch.plan | 2 ++
verify/lists.sql | 7 +++++++
4 files changed, 25 insertions(+), 0 deletions(-)
create mode 100644 deploy/lists.sql
create mode 100644 revert/lists.sql
create mode 100644 verify/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 hashtags
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 hashtags
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. 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 hashtags branch from master before merging. This "rewinds" the branch changes, pulls from
master
, and then replays the changes back on top of the pulled changes.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 d5e7e86 Merge branch 'lists'
That throws out our botched merge. Now let's go back to our branch and rebase it on master
:
> git checkout hashtags
Switched to branch 'hashtags'
> git rebase master
First, rewinding head to replay your work on top of it...
Applying: Add hashtags table.
Using index info to reconstruct a base tree...
M sqitch.plan
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 hashtags table.
The copy of the patch that failed is found in:
.git/rebase-apply/patch
When you have resolved this problem, run "git rebase --continue".
If you prefer to skip this patch, run "git rebase --skip" instead.
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 for us, we can tell Git to resolve conflicts in sqitch.plan differently. 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 hashtags table.
Using index info to reconstruct a base tree...
M sqitch.plan
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-firebird-intro/
users 2014-01-03T22:04:55Z Marge N. O’Vera <marge@example.com> # Creates table to track our users.
flips [users] 2014-01-03T22:36:57Z Marge N. O’Vera <marge@example.com> # Adds table for storing flips.
userflips [users flips] 2014-01-03T22:43:36Z Marge N. O’Vera <marge@example.com> # Creates the userflips view.
@v1.0.0-dev1 2014-01-03T22:46:16Z Marge N. O’Vera <marge@example.com> # Tag v1.0.0-dev1.
lists [flips] 2014-01-03T22:53:44Z Marge N. O’Vera <marge@example.com> # Adds table for storing lists.
hashtags [flips] 2014-01-03T23:02:04Z Marge N. O’Vera <marge@example.com> # Adds table for storing hashtags.
Note that it has appended the changes from the merged "lists" branch, and then merged the changes from our "hashtags" branch. Test it to make sure it works as expected:
> sqitch rebase -y
Reverting all changes from flipr_test
- hashtags ................ ok
- userflips @v1.0.0-dev1 .. ok
- flips ................... ok
- users ................... ok
Deploying changes to flipr_test
+ users ................... ok
+ flips ................... ok
+ userflips @v1.0.0-dev1 .. ok
+ lists ................... ok
+ hashtags ................ ok
Note the use of rebase
, which combines a revert
and a deploy
into a single command. Handy, right? 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 commit -m 'Add `.gitattributes` with union merge for `sqitch.plan`.'
[hashtags d91ceb1] Add `.gitattributes` with union merge for `sqitch.plan`.
1 files changed, 1 insertions(+), 0 deletions(-)
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 hashtags -n "Merge branch 'hashtags'"
Merge made by the 'recursive' strategy.
.gitattributes | 1 +
deploy/hashtags.sql | 10 ++++++++++
revert/hashtags.sql | 5 +++++
sqitch.plan | 1 +
verify/hashtags.sql | 5 +++++
5 files changed, 22 insertions(+), 0 deletions(-)
create mode 100644 .gitattributes
create mode 100644 deploy/hashtags.sql
create mode 100644 revert/hashtags.sql
create mode 100644 verify/hashtags.sql
And double-check our work:
> cat sqitch.plan
%syntax-version=1.0.0-b2
%project=flipr
%uri=https://github.com/theory/sqitch-firebird-intro/
users 2014-01-03T22:04:55Z Marge N. O’Vera <marge@example.com> # Creates table to track our users.
flips [users] 2014-01-03T22:36:57Z Marge N. O’Vera <marge@example.com> # Adds table for storing flips.
userflips [users flips] 2014-01-03T22:43:36Z Marge N. O’Vera <marge@example.com> # Creates the userflips view.
@v1.0.0-dev1 2014-01-03T22:46:16Z Marge N. O’Vera <marge@example.com> # Tag v1.0.0-dev1.
lists [flips] 2014-01-03T22:53:44Z Marge N. O’Vera <marge@example.com> # Adds table for storing lists.
hashtags [flips] 2014-01-03T23:02:04Z Marge N. O’Vera <marge@example.com> # Adds table for storing hashtags.
Much much better, a nice clean master now. And because it is now identical to the "hashtags" 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 "hashtags" with @v1.0.0-dev2
> git commit -am 'Tag the database with v1.0.0-dev2.'
[master a6b9135] 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 --dest-dir flipr-1.0.0-dev2
Bundling into flipr-1.0.0-dev2
Writing config
Writing plan
Writing scripts
+ users
+ flips
+ userflips @v1.0.0-dev1
+ lists
+ hashtags @v1.0.0-dev2
Note the use of the --dest-dir
option to sqitch bundle
. Just a nicer way to create the top-level directory name so we don't have to rename it from bundle.
In Place Changes
Well, some folks have been testing the 1.0.0-dev2
release and have demanded that Twitter user links be added to Flipr pages. Why anyone would want to include social network links in an anti-social networking app is beyond us programmers, but we're just the plumbers, right? Gotta go with what Marketing demands. The upshot is that we need to update the userflips
view, which is used for the feature in question, to include the Twitter user names.
Normally, modifying views in database changes is a PITA. You have to make changes like these:
Copy deploy/userflips.sql to deploy/userflips_twitter.sql.
Edit deploy/userflips_twitter.sql to re-create the view with the new
twitter
column added to the view.Copy deploy/userflips.sql to revert/userflips_twitter.sql. Yes, copy the original change script to the new revert change.
Add a
DROP VIEW
statement to revert/userflips_twitter.sql.Copy verify/userflips.sql to verify/userflips_twitter.sql.
Modify verify/userflips_twitter.sql to include a check for the
twiter
column.Test the changes to make sure you can deploy and revert the
userflips_twitter
change.
But you can have Sqitch do most of the work 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
:
> sqitch rework userflips -n 'Adds userflips.twitter.'
Added "userflips [userflips@v1.0.0-dev2]" to sqitch.plan.
Modify these files as appropriate:
* deploy/userflips.sql
* revert/userflips.sql
* verify/userflips.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 userflips
change, which we can see via git status
:
> git status
# On branch master
# Your branch is ahead of 'origin/master' by 4 commits.
# (use "git push" to publish your local commits)
#
# 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/userflips.sql
# modified: sqitch.plan
#
# Untracked files:
# (use "git add <file>..." to include in what will be committed)
#
# deploy/userflips@v1.0.0-dev2.sql
# revert/userflips@v1.0.0-dev2.sql
# verify/userflips@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 userflips@v1.0.0-dev2.sql
. What that means is: "the userflips
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 userflips
change. As such, it's important not to change them again. But hey, if you're reworking the change, you shouldn't need to.
The other thing to notice is that revert/userflips.sql has changed. Sqitch replaced it with the original deploy script. As of now, deploy/userflips.sql and revert/userflips.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.
Fortunately, our view deploy scripts are already almost idempotent -- that is, able to be applied multiple times without changing the result beyond the initial application use. We just need to take advantage of Firebird's support for the CREATE OR ALTER VIEW
expression. No matter how many times the deployment script runs, the end result will be the same instance of the view, with no duplicates or errors.
Modify deploy/userflips.sql to add the twitter
column; and also use the OR ALTER
statement:
@@ -2,8 +2,8 @@
-- requires: users
-- requires: flips
-CREATE VIEW userflips AS
-SELECT f.id, u.nickname, u.fullname, f.body, f.timestmp
+CREATE OR ALTER VIEW userflips AS
+SELECT f.id, u.nickname, u.fullname, u.twitter, f.body, f.timestmp
FROM users u
JOIN flips f ON u.nickname = f.nickname;
Next, modify verify/userflips.sql to check for the twitter
column. Here's the diff:
@@ -1,6 +1,6 @@
-- Verify userflips
-SELECT id, nickname, fullname, body, timestmp
+SELECT id, nickname, fullname, twitter, body, timestmp
FROM userflips
WHERE 1=2;
And finally, modify both deploy/userflips@v1.0.0-dev2.sql and revert/userflips.sql to add the OR ALTER
statement:
@@ -2,7 +2,7 @@
-- requires: users
-- requires: flips
-CREATE VIEW userflips AS
+CREATE OR ALTER VIEW userflips AS
SELECT f.id, u.nickname, u.fullname, f.body, f.timestmp
FROM users u
JOIN flips f ON u.nickname = f.nickname;
Note that if we had included that statement when we originally created the userflips
change, we wouldn't have to change this file at all.
Now try a deployment:
> sqitch deploy
Deploying changes to flipr_test
+ userflips .. ok
So, are the changes deployed?
> echo "CONNECT 'localhost:/tmp/flipr_test/flipr.fdb'; SHOW VIEW userflips; quit;" \
| isql-fb -u SYSDBA -p masterkey
Use CONNECT or CREATE DATABASE to specify a database
ID INTEGER Not Null
NICKNAME VARCHAR(50) Not Null
FULLNAME VARCHAR(512) Not Null
TWITTER VARCHAR(512) Not Null
BODY VARCHAR(512) Not Null
TIMESTMP TIMESTAMP Nullable
View Source:
==== ======
SELECT f.id, u.nickname, u.fullname, u.twitter, f.body, f.timestmp
FROM users u
JOIN flips f ON u.nickname = f.nickname
Awesome, the view now includes the twitter
column. But can we revert?
> sqitch revert --to @HEAD^ -y
Reverting changes to hashtags @v1.0.0-dev2 from flipr_test
- userflips .. ok
Did that work, is the twitter
column gone?
> echo "CONNECT 'localhost:/tmp/flipr_test/flipr.fdb'; SHOW VIEW userflips; quit;" \
| isql-fb -u SYSDBA -p masterkey
Use CONNECT or CREATE DATABASE to specify a database
ID INTEGER Not Null
NICKNAME VARCHAR(50) Not Null
FULLNAME VARCHAR(512) Not Null
BODY VARCHAR(512) Not Null
TIMESTMP TIMESTAMP Nullable
View Source:
==== ======
SELECT f.id, u.nickname, u.fullname, f.body, f.timestmp
FROM users u
JOIN flips f ON u.nickname = f.nickname
Yes, it works! Sqitch properly finds the original instances of these changes in the new script files that include tags.
Excellent. Let's go ahead and commit these changes:
> rm -rf flipr-1.0.0-dev2
> git add .
> git commit -m 'Add the twitter column to the userflips view.'
[master aefc04c] Add the twitter column to the userflips view.
7 files changed, 33 insertions(+), 5 deletions(-)
create mode 100644 deploy/userflips@v1.0.0-dev2.sql
create mode 100644 revert/userflips@v1.0.0-dev2.sql
create mode 100644 verify/userflips@v1.0.0-dev2.sql
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.
Authors
Ștefan Suciu <stefbv70@gmail.com>
David E. Wheeler <david@justatheory.com>
License
Copyright (c) 2012-2013 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.