sqitchtutorial-firebird(3pm) | User Contributed Perl Documentation | sqitchtutorial-firebird(3pm) |
sqitchtutorial-firebird - A tutorial introduction to Sqitch change management on Firebird
sqitch *
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 <https://git-scm.com/> as the VCS and Firebird <https://www.firebirdsql.org/> as the storage engine.
If you'd like to manage a 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 a MySQL database, see sqitchtutorial-mysql.
If you'd like to manage a Vertica database, see sqitchtutorial-vertica.
If you'd like to manage an Exasol database, see sqitchtutorial-exasol.
If you'd like to manage a Snowflake database, see sqitchtutorial-snowflake.
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.' [main (root-commit) 761ffcd] 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 <https://github.com/sqitchers/sqitch-firebird-intro>.
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, and will prevent the deployment of a different project with the same name. So let's specify one when we initialize Sqitch:
> sqitch init flipr --uri https://github.com/sqitchers/sqitch-firebird-intro/ --engine firebird 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 = . # [engine "firebird"] # target = db:firebird: # registry = sqitch # client = 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 "[engine "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 <https://www.firebirdsql.org/manual/isql-commands.html> (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 (don't bother if you're using the Docker image <https://hub.docker.com/r/sqitch/sqitch/> because it uses the client inside the container, not on your host machine):
> sqitch config --user engine.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. OXVera' > 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 [engine "firebird"] client = /opt/local/bin/isql [user] name = Marge N. OXVera 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 %project=flipr %uri=https://github.com/sqitchers/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.' [main 2177ce4] 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 -q -u SYSDBA -p masterkey
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 flipr:users to firebird -- XXX Add DDLs here. COMMIT;
What we want to do is to replace the "XXX" comment with the "CREATE TABLE" statement, like so:
-- Deploy flipr:users to firebird CREATE TABLE users ( nickname VARCHAR(50) PRIMARY KEY, password VARCHAR(512) NOT NULL, fullname VARCHAR(512) NOT NULL, twitter VARCHAR(512) NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP NOT NULL ); 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 flipr:users from firebird DROP TABLE users; COMMIT;
Now we can try deploying this change. We tell Sqitch where to send the change via a database URI <https://github.com/libwww-perl/uri-db/>. Here we've specified a database file, /tmp/flipr_test/flipr.fdb:
> sqitch deploy db:firebird://sysdba:masterkey@localhost//tmp/flipr_test/flipr.fdb Adding registry tables to db:firebird://sysdba:@localhost//tmp/flipr_test/sqitch.fdb Deploying changes to db:firebird://sysdba:@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. In this case, we should end up with two databases:
The Sqitch registry database.
The database Sqitch manages.
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 engine add firebird $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 -q -u SYSDBA -p masterkey USERS
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, fullname, twitter, created_at 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!
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: 2cde9cc8c19161e9837de57741502243b2ad380e # Name: users # Deployed: 2014-01-05 14:05:22 -0800 # By: Marge N. OXVera <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 -q -u SYSDBA -p masterkey 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 2cde9cc8c19161e9837de57741502243b2ad380e Name: users Committer: Marge N. OXVera <marge@example.com> Date: 2014-01-05 14:06:59 -0800 Creates table to track our users. Deploy 2cde9cc8c19161e9837de57741502243b2ad380e Name: users Committer: Marge N. OXVera <marge@example.com> Date: 2014-01-05 14:05:22 -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.
Cool. Now let's commit it.
> git add . > git commit -m 'Add users table.' [main ec72105] 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 -q -u SYSDBA -p masterkey 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: 2cde9cc8c19161e9837de57741502243b2ad380e # Name: users # Deployed: 2014-01-05 14:19:32 -0800 # By: Marge N. OXVera <marge@example.com> # Nothing to deploy (up-to-date)
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 <https://github.com/libwww-perl/uri-db/> 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" <https://git-scm.com/docs/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 engine add 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: 2cde9cc8c19161e9837de57741502243b2ad380e # Name: users # Deployed: 2014-01-05 14:19:32 -0800 # By: Marge N. OXVera <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.' [main cfc9fea] Set default target and always verify. 1 files changed, 8 insertions(+), 0 deletions(-)
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 flipr:flips to firebird -- requires: users CREATE TABLE flips ( id INTEGER NOT NULL PRIMARY KEY, nickname VARCHAR(50) NOT NULL REFERENCES users(nickname), body VARCHAR(512) DEFAULT '' NOT NULL CHECK ( char_length(body) <= 180 ), created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP NOT NULL ); COMMMIT;
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 flipr:flips on firebird SELECT id, nickname, body, created_at FROM flips WHERE 1=2;
Now for the revert script: all we have to do is drop the table. Add this to revert/flips.sql:
-- Revert flipr:flips from firebird 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 -q -u SYSDBA -p masterkey 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: dfe72351c686bd36017a2b586042b5336301e809 # Name: flips # Deployed: 2014-01-05 14:22:33 -0800 # By: Marge N. OXVera <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 -q -u SYSDBA -p masterkey USERS
The "status" command politely informs us that we have undeployed changes:
> sqitch status # On database flipr_test # Project: flipr # Change: 2cde9cc8c19161e9837de57741502243b2ad380e # Name: users # Deployed: 2014-01-05 14:19:32 -0800 # By: Marge N. OXVera <marge@example.com> # Undeployed change: * flips
As does the "verify" command:
> sqitch 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.' [main 09c636c] 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: dfe72351c686bd36017a2b586042b5336301e809 # Name: flips # Deployed: 2014-01-05 14:24:06 -0800 # By: Marge N. OXVera <marge@example.com> # Nothing to deploy (up-to-date)
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 OR ALTER VIEW userflips AS SELECT f.id, u.nickname, u.fullname, f.body, f.created_at FROM users u JOIN flips f ON u.nickname = f.nickname;
Add this SQL to verify/userflips.sql
SELECT id, nickname, fullname, body, created_at 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.' [main 28ffa63] 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
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.' [main 696a891] 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 -q -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: 785a0d14a5e26b2ae24882a137db45d34f71b5ff # Name: userflips # Tag: @v1.0.0-dev1 # Deployed: 2014-01-05 14:43:28 -0800 # By: Marge N. OXVera <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 -q -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
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: 9474af3b057294633ccf81b9e8d7771a9588ac67 # Name: hashtags # Deployed: 2014-01-05 14:55:56 -0800 # By: Marge N. OXVera <marge@example.com> # # Tag: # @v1.0.0-dev1 - 2014-01-05 14:49:56 -0800 - Marge N. OXVera <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:
> rm -rf flipr-v1.0.0-dev1* > git add . > git commit -am 'Add hashtags table.' [hashtags 9c40bf5] 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 "main".
Let's do it:
> git checkout main Switched to branch 'main' > git pull Updating 696a891..9af80a1 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 "main". 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 main from the origin should have raised a red flag. It's considered a bad practice not to look at what's changed in "main" before merging in a branch. What one should do is either:
So let's restore things to how they were at main:
> 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 "main":
> git checkout hashtags Switched to branch 'hashtags' > git rebase main 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 <https://git-scm.com/docs/gitattributes#_built-in_merge_drivers>:
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 main 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 %project=flipr %uri=https://github.com/sqitchers/sqitch-firebird-intro/ users 2014-01-05T22:01:30Z Marge N. OXVera <marge@example.com> # Creates table to track our users. flips [users] 2014-01-05T22:21:24Z Marge N. OXVera <marge@example.com> # Adds table for storing flips. userflips [users flips] 2014-01-05T22:40:29Z Marge N. OXVera <marge@example.com> # Creates the userflips view. @v1.0.0-dev1 2014-01-05T22:42:36Z Marge N. OXVera <marge@example.com> # Tag v1.0.0-dev1. lists [flips] 2014-01-05T22:44:41Z Marge N. OXVera <marge@example.com> # Adds table for storing lists. hashtags [flips] 2014-01-05T22:54:27Z Marge N. OXVera <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 52ed9a2] Add `.gitattributes` with union merge for `sqitch.plan`. 1 files changed, 1 insertions(+), 0 deletions(-) create mode 100644 .gitattributes
And now, finally, we can merge into "main":
> git checkout main Switched to branch 'main' > git merge --no-ff hashtags -m "Merge branch 'hashtags'" Merge made by recursive. .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 %project=flipr %uri=https://github.com/sqitchers/sqitch-firebird-intro/ users 2014-01-05T22:01:30Z Marge N. OXVera <marge@example.com> # Creates table to track our users. flips [users] 2014-01-05T22:21:24Z Marge N. OXVera <marge@example.com> # Adds table for storing flips. userflips [users flips] 2014-01-05T22:40:29Z Marge N. OXVera <marge@example.com> # Creates the userflips view. @v1.0.0-dev1 2014-01-05T22:42:36Z Marge N. OXVera <marge@example.com> # Tag v1.0.0-dev1. lists [flips] 2014-01-05T22:44:41Z Marge N. OXVera <marge@example.com> # Adds table for storing lists. hashtags [flips] 2014-01-05T22:54:27Z Marge N. OXVera <marge@example.com> # Adds table for storing hashtags.
Much much better, a nice clean main 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.' [main 7d07ee3] 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.
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 <https://www.urbandictionary.com/define.php?term=pita>. You have to make changes like these:
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 main # Your branch is ahead of 'origin/main' 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 <https://en.wikipedia.org/wiki/Idempotence> -- 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/userflips@v1.0.0-dev2.sql.
Fortunately, our view deploy scripts are already idempotent, thanks to the use of the "OR ALTER" expression. No matter how many times a deployment script is run, the end result will be the same instance of the view, with no duplicates or errors.
As a result, there is no need to explicitly add changes. So go ahead. Modify deploy/userflips.sql to add the "twitter" column.
@@ -3,7 +3,7 @@ -- requires: flips CREATE OR ALTER VIEW userflips AS -SELECT f.id, u.nickname, u.fullname, f.body, f.created_at +SELECT f.id, u.nickname, u.fullname, u.twitter, f.body, f.created_at 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 flipr:userflips on firebird -SELECT id, nickname, fullname, body, created_at +SELECT id, nickname, twitter, fullname, body, created_at FROM userflips WHERE 1=2;
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 -q -u SYSDBA -p masterkey ID INTEGER Not Null NICKNAME VARCHAR(50) Not Null FULLNAME VARCHAR(512) Not Null TWITTER VARCHAR(512) Not Null BODY VARCHAR(512) Not Null CREATED_AT TIMESTAMP Not Null View Source: ==== ====== SELECT f.id, u.nickname, u.fullname, u.twitter, f.body, f.created_at 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 -q -u SYSDBA -p masterkey ID INTEGER Not Null NICKNAME VARCHAR(50) Not Null FULLNAME VARCHAR(512) Not Null BODY VARCHAR(512) Not Null CREATED_AT TIMESTAMP Not Null View Source: ==== ====== SELECT f.id, u.nickname, u.fullname, f.body, f.created_at 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.' [main f530359] Add the twitter column to the userflips view. 7 files changed, 32 insertions(+), 4 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
Sqitch is a work in progress. Better integration with version control systems is planned to make managing idempotent reworkings even easier. Stay tuned.
Copyright (c) 2012-2022 iovation Inc., David E. Wheeler
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.
2022-10-15 | perl v5.34.0 |