Skip to content

Commit

Permalink
Add the script_hash column to the changes table.
Browse files Browse the repository at this point in the history
The SHA-1 hash of the deploy script will be stored here. However, since this
value is not available for all projects during an upgrade, upgraded registries
will instead get a copy of the change ID. A forthcoming commit will add code
to update this value on deploy. And in the future, this value will be used to
help reconcile and merge differences between the plans and registries.

In order to facilitate testing upgrades, an older version of the schema for
each engine registry may now be found in `t/lib/upgradable_registries/`. Even
future engines will need to include this file, with the `script_hash` column
removed, as well as an upgrade script to add it in a
`lib/App/Sqitch/Engine/Upgrade/` script.
  • Loading branch information
theory committed Jan 5, 2015
1 parent 10f5c3d commit a04be11
Show file tree
Hide file tree
Showing 23 changed files with 1,078 additions and 7 deletions.
3 changes: 3 additions & 0 deletions Changes
Original file line number Diff line number Diff line change
Expand Up @@ -10,6 +10,9 @@ Revision history for Perl extension App::Sqitch
scripts run.
- Added the `upgrade` command, which upgrades the schema for the Sqitch
registry for a target database.
- Added the `script_hash` column to the `changes` registry table. This
column contains a SHA-1 hash of the deploy script for the change at the
time it was deployed.

0.997 2014-11-04T22:52:23Z
[New Features]
Expand Down
14 changes: 14 additions & 0 deletions lib/App/Sqitch/Engine/Upgrade/firebird-1.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -24,3 +24,17 @@ UPDATE RDB$RELATION_FIELDS
UPDATE RDB$RELATION_FIELDS
SET RDB$DESCRIPTION = 'Email address of the user who installed the registry release.'
WHERE RDB$RELATION_NAME = 'VERSIONS' AND RDB$FIELD_NAME = 'INSTALLER_EMAIL';

-- Add the script_hash column to the changes table. Copy change_id for now.
ALTER TABLE changes ADD script_hash VARCHAR(40);
UPDATE changes SET script_hash = change_id;

-- Make the column NOT NULL UNIQUE.
UPDATE RDB$RELATION_FIELDS SET RDB$NULL_FLAG = 1
WHERE RDB$RELATION_NAME = 'CHANGES' AND RDB$FIELD_NAME = 'SCRIPT_HASH';
ALTER TABLE changes ADD CONSTRAINT UNIQUE (script_hash);

-- Add a comment on the new column.
UPDATE RDB$RELATION_FIELDS
SET RDB$DESCRIPTION = 'Deploy script SHA-1 hash.'
WHERE RDB$RELATION_NAME = 'CHANGES' AND RDB$FIELD_NAME = 'SCRIPT_HASH';
5 changes: 5 additions & 0 deletions lib/App/Sqitch/Engine/Upgrade/mysql-1.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,3 +11,8 @@ CREATE TABLE releases (
CHARACTER SET 'utf8',
COMMENT 'Sqitch registry releases.'
;

-- Add the script_hash column to the changes table. Copy change_id for now.
ALTER TABLE changes ADD COLUMN script_hash VARCHAR(40);
UPDATE changes SET script_hash = change_id;
ALTER TABLE changes MODIFY script_hash VARCHAR(40) NOT NULL UNIQUE;
6 changes: 6 additions & 0 deletions lib/App/Sqitch/Engine/Upgrade/oracle-1.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -10,3 +10,9 @@ COMMENT ON COLUMN &registry..releases.version IS 'Version of the Sqitch
COMMENT ON COLUMN &registry..releases.installed_at IS 'Date the registry release was installed.';
COMMENT ON COLUMN &registry..releases.installer_name IS 'Name of the user who installed the registry release.';
COMMENT ON COLUMN &registry..releases.installer_email IS 'Email address of the user who installed the registry release.';

-- Add the script_hash column to the changes table. Copy change_id for now.
ALTER TABLE &registry..changes ADD script_hash CHAR(40);
UPDATE &registry..changes SET script_hash = change_id;
ALTER TABLE &registry..changes MODIFY (script_hash NOT NULL UNIQUE);
COMMENT ON COLUMN &registry..changes.script_hash IS 'Deploy script SHA-1 hash.';
7 changes: 7 additions & 0 deletions lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -15,4 +15,11 @@ COMMENT ON COLUMN :"registry".releases.installed_at IS 'Date the registry rel
COMMENT ON COLUMN :"registry".releases.installer_name IS 'Name of the user who installed the registry release.';
COMMENT ON COLUMN :"registry".releases.installer_email IS 'Email address of the user who installed the registry release.';

-- Add the script_hash column to the changes table. Copy change_id for now.
ALTER TABLE :"registry".changes ADD COLUMN script_hash TEXT;
UPDATE :"registry".changes SET script_hash = change_id;
ALTER TABLE :"registry".changes ALTER COLUMN script_hash SET NOT NULL;
ALTER TABLE :"registry".changes ADD CONSTRAINT changes_script_hash_key UNIQUE (script_hash);
COMMENT ON COLUMN :"registry".changes.script_hash IS 'Deploy script SHA-1 hash.';

COMMIT;
26 changes: 26 additions & 0 deletions lib/App/Sqitch/Engine/Upgrade/sqlite-1.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,4 +7,30 @@ CREATE TABLE releases (
installer_email TEXT NOT NULL
);

-- Create a new changes table with script_hash.
CREATE TABLE new_changes (
change_id TEXT PRIMARY KEY,
script_hash TEXT NOT NULL UNIQUE,
change TEXT NOT NULL,
project TEXT NOT NULL REFERENCES projects(project) ON UPDATE CASCADE,
note TEXT NOT NULL DEFAULT '',
committed_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
committer_name TEXT NOT NULL,
committer_email TEXT NOT NULL,
planned_at DATETIME NOT NULL,
planner_name TEXT NOT NULL,
planner_email TEXT NOT NULL
);

-- Copy all the data to the new table and move it into place.
INSERT INTO new_changes
SELECT change_id, change_id, change, project, note,
committed_at, committer_name, committer_email,
planned_at, planner_name, planner_email
FROM changes;
PRAGMA foreign_keys = OFF;
DROP TABLE changes;
ALTER TABLE new_changes RENAME TO changes;
PRAGMA foreign_keys = ON;

COMMIT;
6 changes: 6 additions & 0 deletions lib/App/Sqitch/Engine/Upgrade/vertica-1.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,3 +6,9 @@ CREATE TABLE :"registry".releases (
);

COMMENT ON TABLE :"registry".releases IS 'Sqitch registry releases.';

-- Add the script_hash column to the changes table. Copy change_id for now.
ALTER TABLE :"registry".changes ADD COLUMN script_hash CHAR(40);
UPDATE :"registry".changes SET script_hash = change_id;
ALTER TABLE :"registry".changes ALTER COLUMN script_hash SET NOT NULL;
ALTER TABLE :"registry".changes ADD CONSTRAINT changes_script_hash_key UNIQUE (script_hash);
5 changes: 5 additions & 0 deletions lib/App/Sqitch/Engine/firebird.sql
Original file line number Diff line number Diff line change
Expand Up @@ -76,6 +76,7 @@ UPDATE RDB$RELATION_FIELDS

CREATE TABLE changes (
change_id VARCHAR(40) NOT NULL PRIMARY KEY,
script_hash VARCHAR(40) NOT NULL UNIQUE,
change VARCHAR(255) NOT NULL,
project VARCHAR(255) NOT NULL REFERENCES projects(project)
ON UPDATE CASCADE,
Expand All @@ -98,6 +99,10 @@ UPDATE RDB$RELATION_FIELDS
SET RDB$DESCRIPTION = 'Change primary key.'
WHERE RDB$RELATION_NAME = 'CHANGES' AND RDB$FIELD_NAME = 'CHANGE_ID';

UPDATE RDB$RELATION_FIELDS
SET RDB$DESCRIPTION = 'Deploy script SHA-1 hash.'
WHERE RDB$RELATION_NAME = 'CHANGES' AND RDB$FIELD_NAME = 'SCRIPT_HASH';

UPDATE RDB$RELATION_FIELDS
SET RDB$DESCRIPTION = 'Name of a deployed change.'
WHERE RDB$RELATION_NAME = 'CHANGES' AND RDB$FIELD_NAME = 'CHANGE';
Expand Down
2 changes: 2 additions & 0 deletions lib/App/Sqitch/Engine/mysql.sql
Original file line number Diff line number Diff line change
Expand Up @@ -35,6 +35,8 @@ CREATE TABLE projects (
CREATE TABLE changes (
change_id VARCHAR(40) PRIMARY KEY
COMMENT 'Change primary key.',
script_hash VARCHAR(40) NOT NULL UNIQUE
COMMENT 'Deploy script SHA-1 hash.',
"change" VARCHAR(255) NOT NULL
COMMENT 'Name of a deployed change.',
project VARCHAR(255) NOT NULL
Expand Down
2 changes: 2 additions & 0 deletions lib/App/Sqitch/Engine/oracle.sql
Original file line number Diff line number Diff line change
Expand Up @@ -28,6 +28,7 @@ COMMENT ON COLUMN &registry..projects.creator_email IS 'Email address of the us

CREATE TABLE &registry..changes (
change_id CHAR(40) PRIMARY KEY,
script_hash CHAR(40) NOT NULL UNIQUE,
change VARCHAR2(512 CHAR) NOT NULL,
project VARCHAR2(512 CHAR) NOT NULL REFERENCES &registry..projects(project),
note VARCHAR2(4000 CHAR) DEFAULT '',
Expand All @@ -41,6 +42,7 @@ CREATE TABLE &registry..changes (

COMMENT ON TABLE &registry..changes IS 'Tracks the changes currently deployed to the database.';
COMMENT ON COLUMN &registry..changes.change_id IS 'Change primary key.';
COMMENT ON COLUMN &registry..changes.script_hash IS 'Deploy script SHA-1 hash.';
COMMENT ON COLUMN &registry..changes.change IS 'Name of a deployed change.';
COMMENT ON COLUMN &registry..changes.project IS 'Name of the Sqitch project to which the change belongs.';
COMMENT ON COLUMN &registry..changes.note IS 'Description of the change.';
Expand Down
2 changes: 2 additions & 0 deletions lib/App/Sqitch/Engine/pg.sql
Original file line number Diff line number Diff line change
Expand Up @@ -35,6 +35,7 @@ COMMENT ON COLUMN :"registry".projects.creator_email IS 'Email address of the u

CREATE TABLE :"registry".changes (
change_id TEXT PRIMARY KEY,
script_hash TEXT NOT NULL UNIQUE,
change TEXT NOT NULL,
project TEXT NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
note TEXT NOT NULL DEFAULT '',
Expand All @@ -48,6 +49,7 @@ CREATE TABLE :"registry".changes (

COMMENT ON TABLE :"registry".changes IS 'Tracks the changes currently deployed to the database.';
COMMENT ON COLUMN :"registry".changes.change_id IS 'Change primary key.';
COMMENT ON COLUMN :"registry".changes.script_hash IS 'Deploy script SHA-1 hash.';
COMMENT ON COLUMN :"registry".changes.change IS 'Name of a deployed change.';
COMMENT ON COLUMN :"registry".changes.project IS 'Name of the Sqitch project to which the change belongs.';
COMMENT ON COLUMN :"registry".changes.note IS 'Description of the change.';
Expand Down
1 change: 1 addition & 0 deletions lib/App/Sqitch/Engine/sqlite.sql
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,7 @@ CREATE TABLE projects (

CREATE TABLE changes (
change_id TEXT PRIMARY KEY,
script_hash TEXT NOT NULL UNIQUE,
change TEXT NOT NULL,
project TEXT NOT NULL REFERENCES projects(project) ON UPDATE CASCADE,
note TEXT NOT NULL DEFAULT '',
Expand Down
1 change: 1 addition & 0 deletions lib/App/Sqitch/Engine/vertica.sql
Original file line number Diff line number Diff line change
Expand Up @@ -23,6 +23,7 @@ COMMENT ON TABLE :"registry".projects IS 'Sqitch projects deploy

CREATE TABLE :"registry".changes (
change_id CHAR(40) PRIMARY KEY ENCODING AUTO,
script_hash CHAR(40) NOT NULL UNIQUE,
change VARCHAR(1024) NOT NULL,
project VARCHAR(1024) NOT NULL REFERENCES :"registry".projects(project),
note VARCHAR(65000) NOT NULL DEFAULT '',
Expand Down
15 changes: 15 additions & 0 deletions lib/App/Sqitch/Plan/Change.pm
Original file line number Diff line number Diff line change
Expand Up @@ -200,6 +200,15 @@ sub deploy_file {
$self->target->deploy_dir->file( $self->path_segments );
}

sub script_hash {
my $path = shift->deploy_file;
return '0000000000000000000000000000000000000000' unless -e $path;
require Digest::SHA;
my $sha = Digest::SHA->new(1);
$sha->add( $path->slurp(iomode => '<:raw') );
return $sha->hexdigest;
}

sub revert_file {
my $self = shift;
$self->target->revert_dir->file( $self->path_segments );
Expand Down Expand Up @@ -427,6 +436,12 @@ Returns the path to the verify script file for the change.
Returns the path to a script, for the change.
=head3 C<script_hash>
my $hash = $change->script_hash;
Returns the hex digest of the SHA-1 hash for the deploy script.
=head3 C<rework_tags>
my @tags = $change->rework_tags;
Expand Down
4 changes: 3 additions & 1 deletion lib/App/Sqitch/Role/DBIEngine.pm
Original file line number Diff line number Diff line change
Expand Up @@ -437,6 +437,7 @@ sub log_deploy_change {
my $ts = $self->_ts_default;
my $cols = join "\n , ", $self->_quote_idents(qw(
change_id
script_hash
change
project
note
Expand All @@ -451,9 +452,10 @@ sub log_deploy_change {
INSERT INTO changes (
$cols
)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, $ts)
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, $ts)
}, undef,
$id,
$change->script_hash,
$name,
$proj,
$change->note,
Expand Down
11 changes: 10 additions & 1 deletion t/change.t
Original file line number Diff line number Diff line change
Expand Up @@ -4,7 +4,7 @@ use strict;
use warnings;
use 5.010;
use utf8;
use Test::More tests => 85;
use Test::More tests => 87;
#use Test::More 'no_plan';
use Test::NoWarnings;
use App::Sqitch;
Expand Down Expand Up @@ -49,6 +49,7 @@ can_ok $CLASS, qw(
add_tag
plan
deploy_file
script_hash
revert_file
verify_file
requires
Expand Down Expand Up @@ -107,6 +108,14 @@ ok !$change->is_reworked, 'The change should not be reworked';
is_deeply [ $change->path_segments ], ['foo.sql'],
'path_segments should not include suffix';

# Test script_hash.
is $change->script_hash, '0000000000000000000000000000000000000000',
'Nonexistent deploy script hash should be null hash';
make_path $change->deploy_file->dir->stringify;
$change->deploy_file->spew(iomode => '>:utf8', "Foo\nBar\nBøz\n亜唖娃阿" );
is $change->script_hash, 'd48866b846300912570f643c99b2ceec4ba29f5c',
'Deploy script hash should be correct';

# Identify it as reworked.
ok $change->add_rework_tags($tag), 'Add a rework tag';
is_deeply [$change->rework_tags], [$tag], 'Reworked tag should be stored';
Expand Down
26 changes: 21 additions & 5 deletions t/lib/DBIEngineTest.pm
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,8 @@ use Try::Tiny;
use Test::More;
use Test::Exception;
use Time::HiRes qw(sleep);
use Path::Class qw(file dir);
use Digest::SHA qw(sha1_hex);
use Locale::TextDomain qw(App-Sqitch);

# Just die on warnings.
Expand All @@ -21,6 +23,14 @@ sub run {
my $user1_email = 'marge@example.com';
my $mock_sqitch = Test::MockModule->new('App::Sqitch');

# Mock script hashes using lines from the README.
my $mock_change = Test::MockModule->new('App::Sqitch::Plan::Change');
my @lines = grep { $_ } file('README.md')->slurp(
chomp => 1,
iomode => '<:encoding(UTF-8)'
);
$mock_change->mock(script_hash => sub { sha1_hex shift @lines });

can_ok $class, qw(
initialized
initialize
Expand Down Expand Up @@ -67,20 +77,25 @@ sub run {
};
}

ok $engine, 'Engine initialized';
ok $engine, 'Engine instantiated';

ok !$engine->initialized, 'Database should not yet be initialized';
ok $engine->initialize, 'Initialize the database';
OLDREG: {
my $mock_file = Test::MockModule->new('Path::Class::File');
my $dir = file(__FILE__)->dir->subdir('upgradable_registries');
$mock_file->mock( dir => sub { $dir } );
ok $engine->initialize, 'Initialize the database';
};
ok $engine->initialized, 'Database should now be initialized';
ok !$engine->needs_upgrade, 'Engine should not need upgrading';
ok !$engine->needs_upgrade, 'Registry should not need upgrading';
is_deeply $engine->dbh->selectall_arrayref(
'SELECT version, installer_name, installer_email FROM releases'
), [[$engine->registry_release + 0, $sqitch->user_name, $sqitch->user_email]],
'The release should be registered';

# Let's make sure upgrades work.
$engine->dbh->do('DROP TABLE releases');
ok $engine->needs_upgrade, 'Engine should need upgrading';
ok $engine->needs_upgrade, 'Registry should need upgrading';
MOCKINFO: {
my $sqitch_mocker = Test::MockModule->new(ref $sqitch);
my @args;
Expand All @@ -92,7 +107,7 @@ sub run {
new => '1.0',
)], 'Should have info output for upgrade';
}
ok !$engine->needs_upgrade, 'Engine should no longer need upgrading';
ok !$engine->needs_upgrade, 'Registry should no longer need upgrading';
is_deeply $engine->dbh->selectall_arrayref(
'SELECT version, installer_name, installer_email FROM releases'
), [[$engine->registry_release + 0, $sqitch->user_name, $sqitch->user_email]],
Expand All @@ -115,6 +130,7 @@ sub run {
ok !$engine->initialized, 'Database should no longer seem initialized';
ok $engine->initialize, 'Initialize the database again';
ok $engine->initialized, 'Database should be initialized again';
ok !$engine->needs_upgrade, 'Registry should not need upgrading';

is $engine->earliest_change_id, undef, 'Still no earlist change';
is $engine->latest_change_id, undef, 'Still no latest changes';
Expand Down
Loading

0 comments on commit a04be11

Please sign in to comment.