=encoding UTF-8 =head1 Name sqitchtutorial-mysql - A tutorial introduction to Sqitch change management on MySQL =head1 Synopsis sqitch * =head1 Description This tutorial explains how to create a sqitch-enabled MySQL 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 L as the VCS and L as the storage engine. If you'd like to manage a PostgreSQL database, see L. If you'd like to manage an SQLite database, see L. If you'd like to manage an Oracle database, see L. If you'd like to manage a Firebird database, see L. If you'd like to manage a Vertica database, see L. If you'd like to manage an Exasol database, see L. If you'd like to manage a Snowflake database, see L. =head1 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.' [main (root-commit) fdf2a40] Initialize project, add README. 1 file changed, 38 insertions(+) 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 L. 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-mysql-intro/ --engine mysql Created sqitch.conf Created sqitch.plan Created deploy/ Created revert/ Created verify/ Let's have a look at F: > cat sqitch.conf [core] engine = mysql # plan_file = sqitch.plan # top_dir = . # [engine "mysql"] # target = db:mysql: # registry = sqitch # client = mysql Good, it picked up on the fact that we're creating changes for the MySQL engine, thanks to the C<--engine mysql> option, and saved it to the file. Furthermore, it wrote a commented-out C<[engine "mysql"]> section with all the available MySQL engine-specific settings commented out and ready to be edited as appropriate. By default, Sqitch will read F in the current directory for settings. But it will also read F<~/.sqitch/sqitch.conf> for user-specific settings. Since MySQL's L client|https://dev.mysql.com/doc/refman/5.6/en/mysql.html> is not in the path on my system, let's go ahead an tell it where to find the client on our computer (don't bother if you're using the L because it uses the client inside the container, not on your host machine): > sqitch config --user engine.mysql.client /usr/local/mysql/bin/mysql 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 F<~/.sqitch/sqitch.conf> and you'll see this: > cat ~/.sqitch/sqitch.conf [engine "mysql"] client = /usr/local/mysql/bin/mysql [user] name = Marge N. O’Vera email = marge@example.com Which means that Sqitch should be able to find C 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, F: > cat sqitch.plan %syntax-version=1.0.0 %project=flipr %uri=https://github.com/sqitchers/sqitch-mysql-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 C<%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 79fe2cc] Initialize Sqitch configuration. 2 files changed, 19 insertions(+) create mode 100644 sqitch.conf create mode 100644 sqitch.plan =head1 Our First Change First, our app will need a database user, so let's create one. Run this command: > sqitch add appuser -n 'Creates a an application user.' Created deploy/appuser.sql Created revert/appuser.sql Created verify/appuser.sql Added "appuser" to sqitch.plan The L|sqitch-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 C script's job is to create the table. By default, the F file looks like this: -- Deploy flipr:appuser to mysql BEGIN; -- XXX Add DDLs here. COMMIT; What we want to do is to replace the C comment with the C statement, like so: -- Deploy flipr:users to mysql BEGIN; CREATE USER flipr; COMMIT; The C script's job is to precisely revert the change to the deploy script, so we edit this to F to look like this: -- Revert flipr:users from mysql BEGIN; DROP USER flipr; COMMIT; Now we can try deploying this change. First, we need to create a database to deploy to: > mysql -u root --execute 'CREATE DATABASE flipr_test' Now we tell Sqitch where to send the change via a L: > sqitch deploy db:mysql://root@/flipr_test Deploying changes to db:mysql://root@/flipr_test + appuser .. ok First Sqitch created the registry database and tables used to track database changes. The registry database is separate from the database to which the C change was deployed; by default, its name is C, and will be used to manage I projects on a single MySQL server. Ideally, only Sqitch data will be stored in this database, so it probably makes the most sense to create a superuser named C or something similar and use it to deploy changes. If you'd like it to use a different database as the registry database, use C to configure it (or via the L command|sqitch-target>; more L). This will be useful if you don't want to use the same registry database to manage multiple databases on the same server. Next, Sqitch deploys changes to the target database, which we specified on the command-line. We only have one change so far; the C<+> reinforces the idea that the change is being I to the database. With this change deployed, if you connect to the database, you'll be able to see the user: > mysql -u root --execute "SELECT user from mysql.user WHERE user = 'flipr';" +-------+ | User | +-------+ | flipr | +-------+ =head2 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 C 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 simplest way to see if a user exists is to check the C table. However, throwing an error in the event that the user does not exist is tricky in MySQL. To simplify things, on MySQL 5.5.0 and higher, Sqitch provides a custom function you can use in your tests, C. It works kind of like a C constraint in other databases: pass an expression as the first argument, and an error message as the second. If the expression evaluates to false, an exception will be thrown with the error message. Give it a try. Put this query into F: SELECT sqitch.checkit(COUNT(*), 'User "flipr" does not exist') FROM mysql.user WHERE user = 'flipr'; This will work well as long as we know that the registry database is named C. If you've set C to a different value, you will need to make sure you specify the correct database name in the script. Now you can run the C script with the L|sqitch-verify> command: > sqitch verify db:mysql://root@/flipr_test Verifying flipr_test * appuser .. 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 user name in the script to something that doesn't exist, something like: SELECT sqitch.checkit(COUNT(*), 'User "flipr" does not exist') FROM mysql.user WHERE user = 'nonesuch'; Then L|sqitch-verify> again: > sqitch verify db:mysql://root@/flipr_test Verifying db:mysql://root@/flipr_test * appuser .. ERROR 1644 (ERR0R) at line 5 in file: 'verify/appuser.sql': User "flipr" does not exist # Verify script "verify/appuser.sql" failed. not ok Verify Summary Report --------------------- Changes: 1 Errors: 1 Verify failed The C function is kind enough to use the error message to tell us what the problem is. Don't forget to change the table name back before continuing! =head2 Status, Revert, Log, Repeat For purely informational purposes, we can always see how a deployment was recorded via the L|sqitch-status> command, which reads the tables from the registry database: > sqitch status db:mysql://root@/flipr_test # On database db:mysql://root@/flipr_test # Project: flipr # Change: f56dd1a1ab029f398cec2cebb2ecc527fa0332c2 # Name: appuser # Deployed: 2013-12-31 13:13:17 -0800 # By: Marge N. O’Vera # Nothing to deploy (up-to-date) Let's make sure that we can revert the change: > sqitch revert db:mysql://root@/flipr_test Revert all changes from db:mysql://root@/flipr_test? [Yes] - appuser .. ok The L|sqitch-revert> command first prompts to make sure that we really do want to revert. This is to prevent unnecessary accidents. You can pass the C<-y> option to disable the prompt. Also, notice the C<-> before the change name in the output, which reinforces that the change is being I from the database. And now the schema should be gone: > mysql -u root --execute "SELECT user from mysql.user WHERE user = 'flipr';" And the status message should reflect as much: > sqitch status db:mysql://root@/flipr_test # On database db:mysql://root@/flipr_test No changes deployed Of course, since nothing is deployed, the L|sqitch-verify> command has nothing to verify: > sqitch verify db:mysql://root@/flipr_test Verifying db:mysql://root@/flipr_test No changes deployed However, we still have a record that the change happened, visible via the L|sqitch-log> command: > sqitch log db:mysql://root@/flipr_test On database db:mysql://root@/flipr_test Revert f56dd1a1ab029f398cec2cebb2ecc527fa0332c2 Name: appuser Committer: Marge N. O’Vera Date: 2013-12-31 13:26:39 -0800 Creates a an application user. Deploy f56dd1a1ab029f398cec2cebb2ecc527fa0332c2 Name: appuser Committer: Marge N. O’Vera Date: 2013-12-31 13:13:17 -0800 Creates a an application user. 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 the "flipr" user.' [main c63acb9] Add the "flipr" user. 4 files changed, 23 insertions(+) create mode 100644 deploy/appuser.sql create mode 100644 revert/appuser.sql create mode 100644 verify/appuser.sql And then deploy again. This time, let's use the C<--verify> option, so that the C script is applied when the change is deployed: > sqitch deploy --verify db:mysql://root@/flipr_test Deploying changes to db:mysql://root@/flipr_test + appuser .. ok And now the C user should be back: > mysql -u root --execute "SELECT user from mysql.user WHERE user = 'flipr';" +-------+ | user | +-------+ | flipr | +-------+ When we look at the status, the deployment will be there: > sqitch status db:mysql://root@/flipr_test # On database db:mysql://root@/flipr_test # Project: flipr # Change: f56dd1a1ab029f398cec2cebb2ecc527fa0332c2 # Name: appuser # Deployed: 2013-12-31 13:28:23 -0800 # By: Marge N. O’Vera # Nothing to deploy (up-to-date) =head1 On Target I'm getting a little tired of always having to type C, aren't you? This L 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:mysql://root@/flipr_test The L|sqitch-target> command, inspired by L|https://git-scm.com/docs/git-remote>, allows management of one or more named deployment targets. We've just added a target named C, which means we can use the string C for the target, rather than the URI. But since we're doing so much testing, we can also tell Sqitch to deploy to the C target by default: > sqitch engine add mysql 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: f56dd1a1ab029f398cec2cebb2ecc527fa0332c2 # Name: appuser # Deployed: 2013-12-31 13:28:23 -0800 # By: Marge N. O’Vera # 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 L|sqitch-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 c793050] Set default target and always verify. 1 file changed, 8 insertions(+) =head1 Deploy with Dependency Let's add another change, this time to create a table. Our app will need users, of course, so we'll create a table for them. First, add the new change: > sqitch add users --requires appuser -n 'Creates table to track our users.' Created deploy/users.sql Created revert/users.sql Created verify/users.sql Added "users [appuser]" to sqitch.plan Note that we're requiring the C change as a dependency of the new C change. Although that change has already been added to the plan and therefore should always be applied before the C change, it's a good idea to be explicit about dependencies. Now edit the scripts. When you're done, F should look like this: -- Deploy flipr:users to mysql -- requires: appuser BEGIN; CREATE TABLE users ( nickname VARCHAR(512) PRIMARY KEY, password VARCHAR(512) NOT NULL, timestamp DATETIME(6) NOT NULL ); GRANT SELECT ON TABLE users TO flipr; COMMIT; A few things to notice here. On the second line, the dependence on the C change has been listed. This doesn't do anything, but the default MySQL C template lists it here for your reference while editing the file. Useful, right? The C user has been granted C