=encoding UTF-8 =head1 Name sqitchtutorial-exasol - A tutorial introduction to Sqitch change management on Exasol =head1 Synopsis sqitch * =head1 Description This tutorial explains how to create a sqitch-enabled Exasol 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 a new project from scratch, a fictional antisocial networking site called Flipr. All examples use L as the VCS and L as the storage engine, but for the most part you can substitute other VCSes and database engines in the examples as appropriate. 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 MySQL 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 a Snowflake database, see L. =head2 Connection Configuration Sqitch requires ODBC to connect to the Exasol database. As such, you'll need to make sure that the Exasol ODBC driver is properly configured. At its simplest, on Unix-like systems, name the driver "Exasol" by adding this entry to C (usually found in C, C, or C): [Exasol] Description = ODBC for Exasol Driver = /opt/EXASOL_ODBC-6.0.4/lib/linux/x86_64/libexaodbc-uo2214lv2.so Note that you'll need to adjust the path depending on the version of the ODBC driver, and where you installed it. You might also consider naming your database connection by putting an entry in C<~/.odbc.ini>, like so (assuming that Exasol is running on your local host): [flipr_test] Driver = Exasol EXAHOST = 127.0.0.1:8563 EXAUID = sys EXAPWD = exasol Putting user and password information here is optional, but probably safer than other available options as long as the file is protected (mode 0600) so that only you can read it. Normally, of course, you'd have a separate user per project (and a separate ODBC connection defined); the above example is taken from the simplified tutorial setup we're using. See the L for ODBC drivers, documentation, etc. =head2 Database Setup While installing and configuring an Exasol instance is beyond the scope of this tutorial, if you just want to follow along, you can start a Docker instance: > docker run --detach --privileged --stop-timeout 120 -p 127.0.0.1:8563:8888 exasol/docker-db:latest This will make Exasol available at 127.0.0.1 (localhost) on port 8563, as if you were running it directly on your machine. You may have to wait for a minute until the database finished initializing; you can try connecting with `exaplus` to check status. See the corresponding L for more information about how to run Exasol using Docker, for example if you want your data to persist beyond the lifetime of the container, etc. =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.' 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-exasol-intro/ --engine exasol Created sqitch.conf Created sqitch.plan Created deploy/ Created revert/ Created verify/ Let's have a look at F: > cat sqitch.conf [core] engine = exasol # plan_file = sqitch.plan # top_dir = . # [engine "exasol"] # target = db:exasol: # registry = sqitch # client = exaplus Good, it picked up on the fact that we're creating changes for the Exasol engine, thanks to the C<--engine exasol> option, and saved it to the file. Furthermore, it wrote a commented-out C<[engine "exasol"]> section with all the available Exasol 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 Exasol's C client 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.exasol.client /opt/EXAplus/exaplus 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 "exasol"] client = /opt/EXAplus/exaplus [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-exasol-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 a42564d] Initialize Sqitch configuration. 2 files changed, 16 insertions(+), 0 deletions(-) create mode 100644 sqitch.conf create mode 100644 sqitch.plan =head1 Our First Change First, our project will need a schema. This creates a nice namespace for all of the objects that will be part of the flipr app. Run this command: > sqitch add appschema -n 'Add schema for all flipr objects.' Created deploy/appschema.sql Created revert/appschema.sql Created verify/appschema.sql Added "appschema" 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 schema. So we add this to F: CREATE SCHEMA flipr; The C script's job is to precisely revert the change to the deploy script, so we add this to F: DROP SCHEMA flipr; Now we can try deploying this change. We tell Sqitch where to send the change via a L, assuming the default C user and an ODBC driver named C (see L for details): > sqitch deploy 'db:exasol://sys:exasol@localhost:8563/?Driver=Exasol' Adding registry tables to db:exasol://sys:@localhost:8563/?Driver=Exasol Deploying changes to db:exasol://sys:@localhost:8563/?Driver=Exasol + appschema .. ok (If you see an error resolving the TLS certificate, you can disable certificate verification by adding C<&SSLCERTIFICATE=SSL_VERIFY_NONE> to the end of the URL. Only do this for testing!) First Sqitch created registry tables used to track database changes. The structure and name of the registry varies between databases (Exasol uses a schema to namespace its registry, while SQLite and MySQL use separate databases). Next, Sqitch deploys changes. We only have one so far; the C<+> reinforces the idea that the change is being C to the database. With this change deployed, if you connect to the database, you'll be able to see the schema: > exaplus -q -u sys -p exasol -c localhost:8563 -sql "select schema_name from exa_schemas;" SCHEMA_NAME -------------------------------------------------------------------------------------------------------------------------------- SQITCH 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. In Exasol, the simplest way to do so for schema is probably to simply create an object in the schema. Put this SQL into F: CREATE TABLE flipr.verify__ (id int); DROP TABLE flipr.verify__; In truth, you can use I query that generates an SQL error if the schema doesn't exist. Another handy way to do that is to divide by zero if an object doesn't exist. For example, to throw an error when the C schema does not exist, you could do something like this: SELECT 1/COUNT(*) FROM exa_schemas WHERE schema_name = 'FLIPR'; Either way, run the C script with the L|sqitch-verify> command: > sqitch verify 'db:exasol://sys:exasol@localhost:8563/?Driver=Exasol' Verifying db:exasol://sys:@localhost:8563/?Driver=Exasol * 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: CREATE TABLE nonesuch.verify__ (id int); Then L|sqitch-verify> again: > sqitch verify 'db:exasol://sys:exasol@localhost:8563/?Driver=Exasol' Verifying db:exasol://sys:@localhost:8563/?Driver=Exasol * appschema .. Error: [42000] schema NONESUCH not found [line 1, column 40] (Session: 1582884049218108749) # 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 exa_schemas WHERE schema_name = 'nonesuch'; Then the verify will look something like: > sqitch verify 'db:exasol://sys:exasol@localhost:8563/?Driver=Exasol' Verifying db:exasol://sys:@localhost:8563/?Driver=Exasol * appschema .. Error: [22012] data exception - division by zero (Session: 1582884446489810101) # 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! =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 registry tables from the database: > sqitch status 'db:exasol://sys:exasol@localhost:8563/?Driver=Exasol' # On database db:exasol://sys:@localhost:8563/?Driver=Exasol # Project: flipr # Change: f9759f0ed77964b6a3b6c7aa3b6058b4bb7db764 # Name: appschema # Deployed: 2014-09-04 15:26:28 -0700 # By: Marge N. O’Vera # Nothing to deploy (up-to-date) Let's make sure that we can revert the change: > sqitch revert 'db:exasol://sys:exasol@localhost:8563/?Driver=Exasol' Revert all changes from db:exasol://sys:@localhost:8563/?Driver=Exasol? [Yes] - appschema .. 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: > exaplus -q -u sys -p exasol -c localhost:8563 -sql "select schema_name from exa_schemas;" SCHEMA_NAME -------------------------------------------------------------------------------------------------------------------------------- SQITCH And the status message should reflect as much: > sqitch status 'db:exasol://sys:exasol@localhost:8563/?Driver=Exasol' # On database db:exasol://sys:@localhost:8563/?Driver=Exasol No changes deployed Of course, since nothing is deployed, the L|sqitch-verify> command has nothing to verify: > sqitch verify 'db:exasol://sys:exasol@localhost:8563/?Driver=Exasol' Verifying db:exasol://sys:@localhost:8563/?Driver=Exasol No changes deployed However, we still have a record that the change happened, visible via the L|sqitch-log> command: > sqitch log 'db:exasol://sys:exasol@localhost:8563/?Driver=Exasol' On database db:exasol://sys:@localhost:8563/?Driver=Exasol Revert f9759f0ed77964b6a3b6c7aa3b6058b4bb7db764 Name: appschema Committer: Marge N. O’Vera Date: 2014-09-04 16:33:02 -0700 Add schema for all flipr objects. Deploy f9759f0ed77964b6a3b6c7aa3b6058b4bb7db764 Name: appschema Committer: Marge N. O’Vera Date: 2014-09-04 15:26:28 -0700 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 flipr schema.' [main 9bee4bd] Add flipr schema. 5 files changed, 197 insertions(+), 0 deletions(-) create mode 100644 deploy/appschema.sql create mode 100644 revert/appschema.sql create mode 100644 sqitch.sql create mode 100644 verify/appschema.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:exasol://sys:exasol@localhost:8563/?Driver=Exasol' Deploying changes to db:exasol://sys:@localhost:8563/?Driver=Exasol + appschema .. ok And now the schema should be back: > exaplus -q -u sys -p exasol -c localhost:8563 -sql "select schema_name from exa_schemas;" SCHEMA_NAME -------------------------------------------------------------------------------------------------------------------------------- SQITCH FLIPR When we look at the status, the deployment will be there: > sqitch status 'db:exasol://sys:exasol@localhost:8563/?Driver=Exasol' # On database db:exasol://sys:@localhost:8563/?Driver=Exasol # Project: flipr # Change: fef4c2911ae68aee8f6ea164293a32923dc13b67 # Name: appschema # Deployed: 2014-09-04 16:37:38 -0700 # 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:exasol://sys:exasol@localhost:8563/?Driver=Exasol' 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 exasol 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: f9759f0ed77964b6a3b6c7aa3b6058b4bb7db764 # Name: appschema # Deployed: 2014-09-04 16:37:38 -0700 # 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 deployment target and always verify.' [main 469779a] Set default deployment target and always verify. 1 files changed, 8 insertions(+), 0 deletions(-) =head1 Deploy with Dependency Let's add another change, this time to create a table. Our app will need users, of course, so we'll create a table for them. First, add the new change: > sqitch add users --requires appschema -n 'Creates table to track our users.' Created deploy/users.sql Created revert/users.sql Created verify/users.sql Added "users [appschema]" 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 exasol -- requires: appschema CREATE TABLE flipr.users ( nickname VARCHAR(64) PRIMARY KEY, password VARCHAR(256) NOT NULL, fullname VARCHAR(256) NOT NULL, twitter VARCHAR(256) NOT NULL, ts TIMESTAMP WITH LOCAL TIME ZONE DEFAULT NOW() NOT NULL ); 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 C Exasol template lists it here for your reference while editing the file. Useful, right? The table itself will be created in the C schema. This is why we need to require the C change. Now for the verify script. The simplest way to check that the table was created and has the expected columns without touching the data? Just select from the table with a false C clause. Add this to F: SELECT nickname, password, fullname, twitter, ts FROM flipr.users WHERE FALSE; Now for the revert script: all we have to do is drop the table. Add this to F: DROP TABLE flipr.users; Couldn't be much simpler, right? Let's deploy this bad boy: > sqitch deploy Deploying changes to flipr_test + users .. 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: > exaplus -q -u sys -p exasol -c localhost:8563 -sql "describe flipr.users;" COLUMN_NAME SQL_TYPE NULLABLE DISTRIBUTION_KEY -------------------------------------------------------------------------------------------------------------------------------- ---------------------------------------- -------- ---------------- NICKNAME VARCHAR(64) UTF8 FALSE FALSE PASSWORD VARCHAR(256) UTF8 FALSE FALSE FULLNAME VARCHAR(256) UTF8 FALSE FALSE TWITTER VARCHAR(256) UTF8 FALSE FALSE TS TIMESTAMP WITH LOCAL TIME ZONE FALSE FALSE We can also verify all currently deployed changes with the L|sqitch-verify> command: > sqitch verify Verifying flipr_test * appschema .. ok * users ...... ok Verify successful Now have a look at the status: > sqitch status # On database flipr_test # Project: flipr # Change: 794a6c78816543909d592e2e9f5c0fade5b47406 # Name: users # Deployed: 2017-11-02 11:02:40 +0100 # By: Marge N. O’Vera # 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 appschema from flipr_test - users .. ok Note that we've used the C<--to> option to specify the change to revert to. And what do we revert to? The symbolic tag C<@HEAD>, when passed to L|sqitch-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 (C<^>) tells Sqitch to select the change I to the last deployed change. So we revert to C, the penultimate change. The other potentially useful symbolic tag is C<@ROOT>, which refers to the first change deployed to the database (or in the plan, depending on the command). Back to the database. The C table should be gone but the C schema should still be around: > exaplus -q -u sys -p exasol -c localhost:8563 -sql "describe flipr.users;" Error: [42000] table or view FLIPR.USERS not found [line 1, column 10] (Session: 1582958508294847446) The L|sqitch-status> command politely informs us that we have undeployed changes: > sqitch status # On database flipr_test # Project: flipr # Change: f9759f0ed77964b6a3b6c7aa3b6058b4bb7db764 # Name: appschema # Deployed: 2014-09-04 16:37:38 -0700 # By: Marge N. O’Vera # Undeployed change: * users As does the L|sqitch-verify> command: > sqitch verify Verifying flipr_test * appschema .. ok Undeployed change: * users Verify successful Note that the verify is successful, because all currently-deployed changes are verified. The list of undeployed changes (just "users" here) reminds us about the current state. Okay, let's commit and deploy again: > git add . > git commit -am 'Add users table.' [main c7c24c5] Add users table. 4 files changed, 18 insertions(+), 0 deletions(-) create mode 100644 deploy/users.sql create mode 100644 revert/users.sql create mode 100644 verify/users.sql > sqitch deploy Deploying changes to flipr_test + users .. ok Looks good. Check the status: > sqitch status # On database flipr_test # Project: flipr # Change: d647ac8c130a7e0b12c9049789e46afb4a4f6e53 # Name: users # Deployed: 2014-09-04 17:42:53 -0700 # By: Marge N. O’Vera # Nothing to deploy (up-to-date) Excellent. Let's do some more! =head1 Add Two at Once Let's add a couple more changes. Our app will need to store status messages from users. Let's call them -- and the table to store them -- "flips". And we'll also need a view that lists user names with their flips. Let's add changes for them both: > sqitch add flips -r appschema -r users -n 'Adds table for storing flips.' Created deploy/flips.sql Created revert/flips.sql Created verify/flips.sql Added "flips [appschema users]" to sqitch.plan > sqitch add userflips -r appschema -r users -r flips \ -n 'Creates the userflips view.' Created deploy/userflips.sql Created revert/userflips.sql Created verify/userflips.sql Added "userflips [appschema users flips]" to sqitch.plan Now might be a good time to have a look at the deployment plan: > cat sqitch.plan %syntax-version=1.0.0 %project=flipr %uri=https://github.com/sqitchers/sqitch-exasol-intro/ appschema 2014-09-04T18:40:34Z Marge N. O’Vera # Add schema for all flipr objects. users [appschema] 2014-09-04T23:40:15Z Marge N. O’Vera # Creates table to track our users. flips [appschema users] 2014-09-05T00:16:58Z Marge N. O’Vera # Adds table for storing flips. userflips [appschema users flips] 2014-09-05T00:18:43Z Marge N. O’Vera # Creates the userflips view. Each change appears on a single line with the name of the change, a bracketed list of dependencies, a timestamp, the name and email address of the user who planned the change, and a note. Let's write the code for the new changes. Here's what F should look like: -- Deploy flipr:flips to exasol -- requires: appschema -- requires: users CREATE TABLE flipr.flips ( id INTEGER IDENTITY PRIMARY KEY, nickname VARCHAR(64) NOT NULL REFERENCES flipr.users(nickname), body VARCHAR(180) DEFAULT '' NOT NULL, ts TIMESTAMP WITH LOCAL TIME ZONE DEFAULT NOW() NOT NULL ); COMMIT; Here's what F might look like: -- Verify flipr:flips on exasol SELECT id, nickname, body, ts FROM flipr.flips WHERE FALSE; ROLLBACK; And F should look something like this: -- Revert flipr:flips from exasol DROP TABLE flipr.flips; COMMIT; Now for C; F might look like this: -- Deploy flipr:userflips to exasol -- requires: appschema -- requires: users -- requires: flips CREATE OR REPLACE VIEW flipr.userflips AS SELECT f.id, u.nickname, u.fullname, f.body, f.ts FROM flipr.users u JOIN flipr.flips f ON u.nickname = f.nickname; COMMIT; Use a C