Skip to content

Commit

Permalink
Refine ASCII column definitions
Browse files Browse the repository at this point in the history
Columns that store SHA hash hex strings or URIs can be ASCII or use "C"
collation. Update each engine to use the appropriate encoding or
collation for such columns.
  • Loading branch information
theory committed Jan 5, 2025
1 parent ea6062b commit 952122a
Show file tree
Hide file tree
Showing 16 changed files with 278 additions and 226 deletions.
2 changes: 1 addition & 1 deletion inc/Module/Build/Sqitch.pm
Original file line number Diff line number Diff line change
Expand Up @@ -17,7 +17,7 @@ __PACKAGE__->add_property($_) for qw(etcdir installed_etcdir);
__PACKAGE__->add_property(with => []);

# Set dual_life to true to force dual-life modules such as Pod::Simple to be
# incliuded in the bundle directory.
# included in the bundle directory.
# --dual_life 1
__PACKAGE__->add_property(dual_life => 0);

Expand Down
2 changes: 1 addition & 1 deletion lib/App/Sqitch/Engine/Upgrade/firebird-1.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -14,7 +14,7 @@ COMMENT ON COLUMN releases.installer_name IS 'Name of the user who installed th
COMMENT ON COLUMN releases.installer_email IS 'Email address of the user who installed the registry release.';

-- Add the script_hash column to the changes table.
ALTER TABLE changes ADD script_hash VARCHAR(40) UNIQUE;
ALTER TABLE changes ADD script_hash VARCHAR(40) CHARACTER SET ASCII UNIQUE;
COMMIT;
UPDATE changes SET script_hash = change_id;
COMMENT ON COLUMN changes.script_hash IS 'Deploy script SHA-1 hash.';
Expand Down
2 changes: 1 addition & 1 deletion lib/App/Sqitch/Engine/Upgrade/mysql-1.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,7 +13,7 @@ CREATE TABLE releases (
;

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

-- Allow "merge" events.
Expand Down
2 changes: 1 addition & 1 deletion lib/App/Sqitch/Engine/Upgrade/oracle-1.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,7 +12,7 @@ COMMENT ON COLUMN &registry..releases.installer_name IS 'Name of the user who i
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) NULL UNIQUE;
ALTER TABLE &registry..changes ADD script_hash CHAR(40) COLLATE ASCII7 NULL UNIQUE;
UPDATE &registry..changes SET script_hash = change_id;
COMMENT ON COLUMN &registry..changes.script_hash IS 'Deploy script SHA-1 hash.';

Expand Down
2 changes: 1 addition & 1 deletion lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,7 +16,7 @@ COMMENT ON COLUMN :"registry".releases.installer_name IS 'Name of the user who
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 NULL UNIQUE;
ALTER TABLE :"registry".changes ADD COLUMN script_hash TEXT COLLATE "C" NULL UNIQUE;
UPDATE :"registry".changes SET script_hash = change_id;
COMMENT ON COLUMN :"registry".changes.script_hash IS 'Deploy script SHA-1 hash.';

Expand Down
92 changes: 47 additions & 45 deletions lib/App/Sqitch/Engine/cockroach.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,12 +16,14 @@ 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.';

-- "C" collation bug: https://github.com/cockroachdb/cockroach/issues/108657

CREATE TABLE :"registry".projects (
project TEXT PRIMARY KEY,
uri TEXT NULL UNIQUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
creator_name TEXT NOT NULL,
creator_email TEXT NOT NULL
project TEXT PRIMARY KEY,
uri TEXT COLLATE "en-US-u-va-posix" NULL UNIQUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
creator_name TEXT NOT NULL,
creator_email TEXT NOT NULL
);

COMMENT ON TABLE :"registry".projects IS 'Sqitch projects deployed to this database.';
Expand All @@ -32,17 +34,17 @@ COMMENT ON COLUMN :"registry".projects.creator_name IS 'Name of the user who a
COMMENT ON COLUMN :"registry".projects.creator_email IS 'Email address of the user who added the project.';

CREATE TABLE :"registry".changes (
change_id TEXT PRIMARY KEY,
script_hash TEXT NULL,
change TEXT NOT NULL,
project TEXT NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
note TEXT NOT NULL DEFAULT '',
committed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
committer_name TEXT NOT NULL,
committer_email TEXT NOT NULL,
planned_at TIMESTAMPTZ NOT NULL,
planner_name TEXT NOT NULL,
planner_email TEXT NOT NULL,
change_id TEXT COLLATE "en-US-u-va-posix" PRIMARY KEY,
script_hash TEXT COLLATE "en-US-u-va-posix" NULL,
change TEXT NOT NULL,
project TEXT NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
note TEXT NOT NULL DEFAULT '',
committed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
committer_name TEXT NOT NULL,
committer_email TEXT NOT NULL,
planned_at TIMESTAMPTZ NOT NULL,
planner_name TEXT NOT NULL,
planner_email TEXT NOT NULL,
UNIQUE(project, script_hash)
);

Expand All @@ -60,17 +62,17 @@ COMMENT ON COLUMN :"registry".changes.planner_name IS 'Name of the user who p
COMMENT ON COLUMN :"registry".changes.planner_email IS 'Email address of the user who planned the change.';

CREATE TABLE :"registry".tags (
tag_id TEXT PRIMARY KEY,
tag TEXT NOT NULL,
project TEXT NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
change_id TEXT NOT NULL REFERENCES :"registry".changes(change_id) ON UPDATE CASCADE,
note TEXT NOT NULL DEFAULT '',
committed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
committer_name TEXT NOT NULL,
committer_email TEXT NOT NULL,
planned_at TIMESTAMPTZ NOT NULL,
planner_name TEXT NOT NULL,
planner_email TEXT NOT NULL,
tag_id TEXT COLLATE "en-US-u-va-posix" PRIMARY KEY,
tag TEXT NOT NULL,
project TEXT NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
change_id TEXT COLLATE "en-US-u-va-posix" NOT NULL REFERENCES :"registry".changes(change_id) ON UPDATE CASCADE,
note TEXT NOT NULL DEFAULT '',
committed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
committer_name TEXT NOT NULL,
committer_email TEXT NOT NULL,
planned_at TIMESTAMPTZ NOT NULL,
planner_name TEXT NOT NULL,
planner_email TEXT NOT NULL,
UNIQUE(project, tag)
);

Expand All @@ -88,10 +90,10 @@ COMMENT ON COLUMN :"registry".tags.planner_name IS 'Name of the user who plan
COMMENT ON COLUMN :"registry".tags.planner_email IS 'Email address of the user who planned the tag.';

CREATE TABLE :"registry".dependencies (
change_id TEXT NOT NULL REFERENCES :"registry".changes(change_id) ON UPDATE CASCADE ON DELETE CASCADE,
type TEXT NOT NULL,
dependency TEXT NOT NULL,
dependency_id TEXT NULL REFERENCES :"registry".changes(change_id) ON UPDATE CASCADE CONSTRAINT dependencies_check CHECK (
change_id TEXT COLLATE "en-US-u-va-posix" NOT NULL REFERENCES :"registry".changes(change_id) ON UPDATE CASCADE ON DELETE CASCADE,
type TEXT COLLATE "en-US-u-va-posix" NOT NULL,
dependency TEXT NOT NULL,
dependency_id TEXT COLLATE "en-US-u-va-posix" NULL REFERENCES :"registry".changes(change_id) ON UPDATE CASCADE CONSTRAINT dependencies_check CHECK (
(type = 'require' AND dependency_id IS NOT NULL)
OR (type = 'conflict' AND dependency_id IS NULL)
),
Expand All @@ -105,22 +107,22 @@ COMMENT ON COLUMN :"registry".dependencies.dependency IS 'Dependency name.';
COMMENT ON COLUMN :"registry".dependencies.dependency_id IS 'Change ID the dependency resolves to.';

CREATE TABLE :"registry".events (
event TEXT NOT NULL CONSTRAINT events_event_check CHECK (
event TEXT COLLATE "en-US-u-va-posix" NOT NULL CONSTRAINT events_event_check CHECK (
event IN ('deploy', 'revert', 'fail', 'merge')
),
change_id TEXT NOT NULL,
change TEXT NOT NULL,
project TEXT NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
note TEXT NOT NULL DEFAULT '',
requires TEXT[] NOT NULL DEFAULT '{}',
conflicts TEXT[] NOT NULL DEFAULT '{}',
tags TEXT[] NOT NULL DEFAULT '{}',
committed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
committer_name TEXT NOT NULL,
committer_email TEXT NOT NULL,
planned_at TIMESTAMPTZ NOT NULL,
planner_name TEXT NOT NULL,
planner_email TEXT NOT NULL,
change_id TEXT COLLATE "en-US-u-va-posix" NOT NULL,
change TEXT NOT NULL,
project TEXT NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
note TEXT NOT NULL DEFAULT '',
requires TEXT[] NOT NULL DEFAULT '{}',
conflicts TEXT[] NOT NULL DEFAULT '{}',
tags TEXT[] NOT NULL DEFAULT '{}',
committed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
committer_name TEXT NOT NULL,
committer_email TEXT NOT NULL,
planned_at TIMESTAMPTZ NOT NULL,
planner_name TEXT NOT NULL,
planner_email TEXT NOT NULL,
PRIMARY KEY (change_id, committed_at)
);

Expand Down
82 changes: 41 additions & 41 deletions lib/App/Sqitch/Engine/exasol.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,11 +16,11 @@ COMMENT ON COLUMN &registry..releases.installer_name IS 'Name of the user who i
COMMENT ON COLUMN &registry..releases.installer_email IS 'Email address of the user who installed the registry release.';

CREATE TABLE &registry..projects (
project VARCHAR2(512 CHAR) PRIMARY KEY,
uri VARCHAR2(512 CHAR) NULL, -- UNIQUE should also be used here, but not supported in EXASOL
created_at TIMESTAMP WITH LOCAL TIME ZONE DEFAULT current_timestamp NOT NULL,
creator_name VARCHAR2(512 CHAR) NOT NULL,
creator_email VARCHAR2(512 CHAR) NOT NULL
project VARCHAR2(512 CHAR) PRIMARY KEY,
uri VARCHAR2(512 CHAR) CHARACTER SET ASCII NULL, -- UNIQUE should also be used here, but not supported in EXASOL
created_at TIMESTAMP WITH LOCAL TIME ZONE DEFAULT current_timestamp NOT NULL,
creator_name VARCHAR2(512 CHAR) NOT NULL,
creator_email VARCHAR2(512 CHAR) NOT NULL
);

COMMENT ON TABLE &registry..projects IS 'Sqitch projects deployed to this database.';
Expand All @@ -31,17 +31,17 @@ COMMENT ON COLUMN &registry..projects.creator_name IS 'Name of the user who ad
COMMENT ON COLUMN &registry..projects.creator_email IS 'Email address of the user who added the project.';

CREATE TABLE &registry..changes (
change_id CHAR(40) PRIMARY KEY,
script_hash CHAR(40) NULL,
change VARCHAR2(512 CHAR) NOT NULL,
project VARCHAR2(512 CHAR) NOT NULL REFERENCES &registry..projects(project),
note VARCHAR2(4000 CHAR) DEFAULT '',
change_id CHAR(40) CHARACTER SET ASCII PRIMARY KEY,
script_hash CHAR(40) CHARACTER SET ASCII NULL,
change VARCHAR2(512 CHAR) NOT NULL,
project VARCHAR2(512 CHAR) NOT NULL REFERENCES &registry..projects(project),
note VARCHAR2(4000 CHAR) DEFAULT '',
committed_at TIMESTAMP WITH LOCAL TIME ZONE DEFAULT current_timestamp NOT NULL,
committer_name VARCHAR2(512 CHAR) NOT NULL,
committer_email VARCHAR2(512 CHAR) NOT NULL,
committer_name VARCHAR2(512 CHAR) NOT NULL,
committer_email VARCHAR2(512 CHAR) NOT NULL,
planned_at TIMESTAMP WITH LOCAL TIME ZONE NOT NULL,
planner_name VARCHAR2(512 CHAR) NOT NULL,
planner_email VARCHAR2(512 CHAR) NOT NULL
planner_name VARCHAR2(512 CHAR) NOT NULL,
planner_email VARCHAR2(512 CHAR) NOT NULL
-- UNIQUE(project, script_hash) -- not supported in EXASOL
);

Expand All @@ -59,17 +59,17 @@ COMMENT ON COLUMN &registry..changes.planner_name IS 'Name of the user who pl
COMMENT ON COLUMN &registry..changes.planner_email IS 'Email address of the user who planned the change.';

CREATE TABLE &registry..tags (
tag_id CHAR(40) PRIMARY KEY,
tag VARCHAR2(512 CHAR) NOT NULL,
project VARCHAR2(512 CHAR) NOT NULL REFERENCES &registry..projects(project),
change_id CHAR(40) NOT NULL REFERENCES &registry..changes(change_id),
note VARCHAR2(4000 CHAR) DEFAULT '',
tag_id CHAR(40) CHARACTER SET ASCII PRIMARY KEY,
tag VARCHAR2(512 CHAR) NOT NULL,
project VARCHAR2(512 CHAR) NOT NULL REFERENCES &registry..projects(project),
change_id CHAR(40) CHARACTER SET ASCII NOT NULL REFERENCES &registry..changes(change_id),
note VARCHAR2(4000 CHAR) DEFAULT '',
committed_at TIMESTAMP WITH LOCAL TIME ZONE DEFAULT current_timestamp NOT NULL,
committer_name VARCHAR2(512 CHAR) NOT NULL,
committer_email VARCHAR2(512 CHAR) NOT NULL,
committer_name VARCHAR2(512 CHAR) NOT NULL,
committer_email VARCHAR2(512 CHAR) NOT NULL,
planned_at TIMESTAMP WITH LOCAL TIME ZONE NOT NULL,
planner_name VARCHAR2(512 CHAR) NOT NULL,
planner_email VARCHAR2(512 CHAR) NOT NULL
planner_name VARCHAR2(512 CHAR) NOT NULL,
planner_email VARCHAR2(512 CHAR) NOT NULL
-- UNIQUE(project, tag)
);

Expand All @@ -87,10 +87,10 @@ COMMENT ON COLUMN &registry..tags.planner_name IS 'Name of the user who plane
COMMENT ON COLUMN &registry..tags.planner_email IS 'Email address of the user who planned the tag.';

CREATE TABLE &registry..dependencies (
change_id CHAR(40) NOT NULL REFERENCES &registry..changes(change_id), -- ON DELETE CASCADE,
type VARCHAR2(8) NOT NULL,
dependency VARCHAR2(1024 CHAR) NOT NULL,
dependency_id CHAR(40) NULL REFERENCES &registry..changes(change_id),
change_id CHAR(40) CHARACTER SET ASCII NOT NULL REFERENCES &registry..changes(change_id), -- ON DELETE CASCADE,
type VARCHAR2(8) CHARACTER SET ASCII NOT NULL,
dependency VARCHAR2(1024 CHAR) NOT NULL,
dependency_id CHAR(40) CHARACTER SET ASCII NULL REFERENCES &registry..changes(change_id),
-- CONSTRAINT dependencies_check CHECK (
-- (type = 'require' AND dependency_id IS NOT NULL)
-- OR (type = 'conflict' AND dependency_id IS NULL)
Expand All @@ -105,20 +105,20 @@ COMMENT ON COLUMN &registry..dependencies.dependency IS 'Dependency name.';
COMMENT ON COLUMN &registry..dependencies.dependency_id IS 'Change ID the dependency resolves to.';

CREATE TABLE &registry..events (
event VARCHAR2(6) NOT NULL,
change_id CHAR(40) NOT NULL,
change VARCHAR2(512 CHAR) NOT NULL,
project VARCHAR2(512 CHAR) NOT NULL REFERENCES &registry..projects(project),
note VARCHAR2(4000 CHAR) DEFAULT '',
requires VARCHAR2(4000 CHAR) DEFAULT '' NOT NULL,
conflicts VARCHAR2(4000 CHAR) DEFAULT '' NOT NULL,
tags VARCHAR2(4000 CHAR) DEFAULT '' NOT NULL,
committed_at TIMESTAMP WITH LOCAL TIME ZONE DEFAULT current_timestamp NOT NULL,
committer_name VARCHAR2(512 CHAR) NOT NULL,
committer_email VARCHAR2(512 CHAR) NOT NULL,
planned_at TIMESTAMP WITH LOCAL TIME ZONE NOT NULL,
planner_name VARCHAR2(512 CHAR) NOT NULL,
planner_email VARCHAR2(512 CHAR) NOT NULL
event VARCHAR2(6) CHARACTER SET ASCII NOT NULL,
change_id CHAR(40) CHARACTER SET ASCII NOT NULL,
change VARCHAR2(512 CHAR) NOT NULL,
project VARCHAR2(512 CHAR) NOT NULL REFERENCES &registry..projects(project),
note VARCHAR2(4000 CHAR) DEFAULT '',
requires VARCHAR2(4000 CHAR) DEFAULT '' NOT NULL,
conflicts VARCHAR2(4000 CHAR) DEFAULT '' NOT NULL,
tags VARCHAR2(4000 CHAR) DEFAULT '' NOT NULL,
committed_at TIMESTAMP WITH LOCAL TIME ZONE DEFAULT current_timestamp NOT NULL,
committer_name VARCHAR2(512 CHAR) NOT NULL,
committer_email VARCHAR2(512 CHAR) NOT NULL,
planned_at TIMESTAMP WITH LOCAL TIME ZONE NOT NULL,
planner_name VARCHAR2(512 CHAR) NOT NULL,
planner_email VARCHAR2(512 CHAR) NOT NULL
);

-- CREATE INDEX &registry..events_pkey ON &registry..events(change_id, committed_at);
Expand Down
Loading

0 comments on commit 952122a

Please sign in to comment.