From a5fe67115d87a8c6bae243f4029a664212dcd88e Mon Sep 17 00:00:00 2001 From: "David E. Wheeler" Date: Sun, 5 Jan 2025 16:11:42 -0500 Subject: [PATCH] Refine ASCII column definitions 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. --- inc/Module/Build/Sqitch.pm | 2 +- .../Sqitch/Engine/Upgrade/firebird-1.0.sql | 2 +- lib/App/Sqitch/Engine/Upgrade/mysql-1.0.sql | 2 +- lib/App/Sqitch/Engine/Upgrade/oracle-1.0.sql | 4 +- lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql | 2 +- lib/App/Sqitch/Engine/cockroach.sql | 94 ++++++++++--------- lib/App/Sqitch/Engine/exasol.sql | 82 ++++++++-------- lib/App/Sqitch/Engine/firebird.sql | 22 ++--- lib/App/Sqitch/Engine/mysql.sql | 20 ++-- lib/App/Sqitch/Engine/oracle.sql | 31 +++--- lib/App/Sqitch/Engine/pg.sql | 92 +++++++++--------- lib/App/Sqitch/Engine/snowflake.sql | 92 +++++++++--------- 12 files changed, 226 insertions(+), 219 deletions(-) diff --git a/inc/Module/Build/Sqitch.pm b/inc/Module/Build/Sqitch.pm index 27d93aa63..a711338ea 100644 --- a/inc/Module/Build/Sqitch.pm +++ b/inc/Module/Build/Sqitch.pm @@ -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); diff --git a/lib/App/Sqitch/Engine/Upgrade/firebird-1.0.sql b/lib/App/Sqitch/Engine/Upgrade/firebird-1.0.sql index d666c4162..ad38c89b1 100644 --- a/lib/App/Sqitch/Engine/Upgrade/firebird-1.0.sql +++ b/lib/App/Sqitch/Engine/Upgrade/firebird-1.0.sql @@ -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.'; diff --git a/lib/App/Sqitch/Engine/Upgrade/mysql-1.0.sql b/lib/App/Sqitch/Engine/Upgrade/mysql-1.0.sql index ac88c549e..4549bcda2 100644 --- a/lib/App/Sqitch/Engine/Upgrade/mysql-1.0.sql +++ b/lib/App/Sqitch/Engine/Upgrade/mysql-1.0.sql @@ -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. diff --git a/lib/App/Sqitch/Engine/Upgrade/oracle-1.0.sql b/lib/App/Sqitch/Engine/Upgrade/oracle-1.0.sql index d019d9041..76ef22846 100644 --- a/lib/App/Sqitch/Engine/Upgrade/oracle-1.0.sql +++ b/lib/App/Sqitch/Engine/Upgrade/oracle-1.0.sql @@ -12,7 +12,9 @@ COMMENT ON COLUMN ®istry..releases.installer_name IS 'Name of the user who i COMMENT ON COLUMN ®istry..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 ®istry..changes ADD script_hash CHAR(40) NULL UNIQUE; +-- https://docs.oracle.com/en/error-help/db/ora-43929/?r=23ai +SET MAX_STRING_SIZE=EXTENDED; +ALTER TABLE ®istry..changes ADD script_hash CHAR(40) COLLATE ASCII7 NULL UNIQUE; UPDATE ®istry..changes SET script_hash = change_id; COMMENT ON COLUMN ®istry..changes.script_hash IS 'Deploy script SHA-1 hash.'; diff --git a/lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql b/lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql index 49f941762..e3c1c385a 100644 --- a/lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql +++ b/lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql @@ -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.'; diff --git a/lib/App/Sqitch/Engine/cockroach.sql b/lib/App/Sqitch/Engine/cockroach.sql index 717bdd26a..8f590f831 100644 --- a/lib/App/Sqitch/Engine/cockroach.sql +++ b/lib/App/Sqitch/Engine/cockroach.sql @@ -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.'; -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 +-- "C" collation bug: https://github.com/cockroachdb/cockroach/issues/108657 + +CREATE TABLE projects ( + 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.'; @@ -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) ); @@ -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) ); @@ -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) ), @@ -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) ); diff --git a/lib/App/Sqitch/Engine/exasol.sql b/lib/App/Sqitch/Engine/exasol.sql index d7731ad56..0fa1351a3 100644 --- a/lib/App/Sqitch/Engine/exasol.sql +++ b/lib/App/Sqitch/Engine/exasol.sql @@ -16,11 +16,11 @@ COMMENT ON COLUMN ®istry..releases.installer_name IS 'Name of the user who i COMMENT ON COLUMN ®istry..releases.installer_email IS 'Email address of the user who installed the registry release.'; CREATE TABLE ®istry..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 ®istry..projects IS 'Sqitch projects deployed to this database.'; @@ -31,17 +31,17 @@ COMMENT ON COLUMN ®istry..projects.creator_name IS 'Name of the user who ad COMMENT ON COLUMN ®istry..projects.creator_email IS 'Email address of the user who added the project.'; CREATE TABLE ®istry..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 ®istry..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 ®istry..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 ); @@ -59,17 +59,17 @@ COMMENT ON COLUMN ®istry..changes.planner_name IS 'Name of the user who pl COMMENT ON COLUMN ®istry..changes.planner_email IS 'Email address of the user who planned the change.'; CREATE TABLE ®istry..tags ( - tag_id CHAR(40) PRIMARY KEY, - tag VARCHAR2(512 CHAR) NOT NULL, - project VARCHAR2(512 CHAR) NOT NULL REFERENCES ®istry..projects(project), - change_id CHAR(40) NOT NULL REFERENCES ®istry..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 ®istry..projects(project), + change_id CHAR(40) CHARACTER SET ASCII NOT NULL REFERENCES ®istry..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) ); @@ -87,10 +87,10 @@ COMMENT ON COLUMN ®istry..tags.planner_name IS 'Name of the user who plane COMMENT ON COLUMN ®istry..tags.planner_email IS 'Email address of the user who planned the tag.'; CREATE TABLE ®istry..dependencies ( - change_id CHAR(40) NOT NULL REFERENCES ®istry..changes(change_id), -- ON DELETE CASCADE, - type VARCHAR2(8) NOT NULL, - dependency VARCHAR2(1024 CHAR) NOT NULL, - dependency_id CHAR(40) NULL REFERENCES ®istry..changes(change_id), + change_id CHAR(40) CHARACTER SET ASCII NOT NULL REFERENCES ®istry..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 ®istry..changes(change_id), -- CONSTRAINT dependencies_check CHECK ( -- (type = 'require' AND dependency_id IS NOT NULL) -- OR (type = 'conflict' AND dependency_id IS NULL) @@ -105,20 +105,20 @@ COMMENT ON COLUMN ®istry..dependencies.dependency IS 'Dependency name.'; COMMENT ON COLUMN ®istry..dependencies.dependency_id IS 'Change ID the dependency resolves to.'; CREATE TABLE ®istry..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 ®istry..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 ®istry..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 ®istry..events_pkey ON ®istry..events(change_id, committed_at); diff --git a/lib/App/Sqitch/Engine/firebird.sql b/lib/App/Sqitch/Engine/firebird.sql index 5757c1725..3cf75f7fd 100644 --- a/lib/App/Sqitch/Engine/firebird.sql +++ b/lib/App/Sqitch/Engine/firebird.sql @@ -26,7 +26,7 @@ COMMENT ON COLUMN releases.installer_email IS 'Email address of the user who ins CREATE TABLE projects ( project VARCHAR(255) NOT NULL PRIMARY KEY, - uri VARCHAR(255) UNIQUE, + uri VARCHAR(255) CHARACTER SET ASCII UNIQUE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP NOT NULL, creator_name VARCHAR(255) NOT NULL, creator_email VARCHAR(255) NOT NULL @@ -42,8 +42,8 @@ COMMENT ON COLUMN projects.creator_email IS 'Email address of the user who adde -- Table: changes CREATE TABLE changes ( - change_id VARCHAR(40) NOT NULL PRIMARY KEY, - script_hash VARCHAR(40), + change_id VARCHAR(40) CHARACTER SET ASCII NOT NULL PRIMARY KEY, + script_hash VARCHAR(40) CHARACTER SET ASCII, change VARCHAR(255) NOT NULL, project VARCHAR(255) NOT NULL REFERENCES projects(project) ON UPDATE CASCADE, @@ -73,11 +73,11 @@ COMMENT ON COLUMN changes.planner_email IS 'Email address of the user who plan -- Table: tags CREATE TABLE tags ( - tag_id CHAR(40) NOT NULL PRIMARY KEY, + tag_id CHAR(40) CHARACTER SET ASCII NOT NULL PRIMARY KEY, tag VARCHAR(250) NOT NULL, project VARCHAR(255) NOT NULL REFERENCES projects(project) ON UPDATE CASCADE, - change_id CHAR(40) NOT NULL REFERENCES changes(change_id) + change_id CHAR(40) CHARACTER SET ASCII NOT NULL REFERENCES changes(change_id) ON UPDATE CASCADE, note BLOB SUB_TYPE TEXT DEFAULT '' NOT NULL, committed_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP NOT NULL, @@ -105,11 +105,11 @@ COMMENT ON COLUMN tags.planner_email IS 'Email address of the user who planned -- Table: dependencies CREATE TABLE dependencies ( - change_id CHAR(40) NOT NULL REFERENCES changes(change_id) + change_id CHAR(40) CHARACTER SET ASCII NOT NULL REFERENCES changes(change_id) ON UPDATE CASCADE ON DELETE CASCADE, - type VARCHAR(8) NOT NULL, - dependency VARCHAR(512) NOT NULL, - dependency_id CHAR(40) REFERENCES changes(change_id) + type VARCHAR(8) CHARACTER SET ASCII NOT NULL, + dependency VARCHAR(512) NOT NULL, + dependency_id CHAR(40) CHARACTER SET ASCII REFERENCES 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) @@ -126,11 +126,11 @@ COMMENT ON COLUMN dependencies.dependency_id IS 'Change ID the dependency resolv -- Table: events CREATE TABLE events ( - event VARCHAR(6) NOT NULL + event VARCHAR(6) CHARACTER SET ASCII NOT NULL CONSTRAINT events_event_check CHECK ( event IN ('deploy', 'revert', 'fail', 'merge') ), - change_id CHAR(40) NOT NULL, + change_id CHAR(40) CHARACTER SET ASCII NOT NULL, change VARCHAR(512) NOT NULL, project VARCHAR(255) NOT NULL REFERENCES projects(project) ON UPDATE CASCADE, diff --git a/lib/App/Sqitch/Engine/mysql.sql b/lib/App/Sqitch/Engine/mysql.sql index fea4a2759..e93ae0f21 100644 --- a/lib/App/Sqitch/Engine/mysql.sql +++ b/lib/App/Sqitch/Engine/mysql.sql @@ -19,7 +19,7 @@ CREATE TABLE releases ( CREATE TABLE projects ( project VARCHAR(255) PRIMARY KEY COMMENT 'Unique Name of a project.', - uri VARCHAR(255) NULL UNIQUE + uri VARCHAR(255) CHARACTER SET ascii NULL UNIQUE COMMENT 'Optional project URI', created_at DATETIME(6) NOT NULL COMMENT 'Date the project was added to the database.', @@ -33,9 +33,9 @@ CREATE TABLE projects ( ; CREATE TABLE changes ( - change_id VARCHAR(40) PRIMARY KEY + change_id VARCHAR(40) CHARACTER SET ascii PRIMARY KEY COMMENT 'Change primary key.', - script_hash VARCHAR(40) NULL + script_hash VARCHAR(40) CHARACTER SET ascii NULL COMMENT 'Deploy script SHA-1 hash.', "change" VARCHAR(255) NOT NULL COMMENT 'Name of a deployed change.', @@ -63,14 +63,14 @@ CREATE TABLE changes ( ; CREATE TABLE tags ( - tag_id VARCHAR(40) PRIMARY KEY + tag_id VARCHAR(40) CHARACTER SET ascii PRIMARY KEY COMMENT 'Tag primary key.', tag VARCHAR(255) NOT NULL COMMENT 'Project-unique tag name.', project VARCHAR(255) NOT NULL COMMENT 'Name of the Sqitch project to which the tag belongs.' REFERENCES projects(project) ON UPDATE CASCADE, - change_id VARCHAR(40) NOT NULL + change_id VARCHAR(40) CHARACTER SET ascii NOT NULL COMMENT 'ID of last change deployed before the tag was applied.' REFERENCES changes(change_id) ON UPDATE CASCADE, note VARCHAR(255) NOT NULL @@ -94,14 +94,14 @@ CREATE TABLE tags ( ; CREATE TABLE dependencies ( - change_id VARCHAR(40) NOT NULL + change_id VARCHAR(40) CHARACTER SET ascii NOT NULL COMMENT 'ID of the depending change.' REFERENCES changes(change_id) ON UPDATE CASCADE ON DELETE CASCADE, - type VARCHAR(8) NOT NULL + type VARCHAR(8) CHARACTER SET ascii NOT NULL COMMENT 'Type of dependency.', dependency VARCHAR(255) NOT NULL COMMENT 'Dependency name.', - dependency_id VARCHAR(40) NULL + dependency_id VARCHAR(40) CHARACTER SET ascii NULL COMMENT 'Change ID the dependency resolves to.' REFERENCES changes(change_id) ON UPDATE CASCADE, PRIMARY KEY (change_id, dependency) @@ -111,9 +111,9 @@ CREATE TABLE dependencies ( ; CREATE TABLE events ( - event ENUM ('deploy', 'fail', 'merge', 'revert') NOT NULL + event ENUM ('deploy', 'fail', 'merge', 'revert') CHARACTER SET ascii NOT NULL COMMENT 'Type of event.', - change_id VARCHAR(40) NOT NULL + change_id VARCHAR(40) CHARACTER SET ascii NOT NULL COMMENT 'Change ID.', "change" VARCHAR(255) NOT NULL COMMENT 'Change name.', diff --git a/lib/App/Sqitch/Engine/oracle.sql b/lib/App/Sqitch/Engine/oracle.sql index 2c3d2cf67..c567ba5d7 100644 --- a/lib/App/Sqitch/Engine/oracle.sql +++ b/lib/App/Sqitch/Engine/oracle.sql @@ -1,3 +1,6 @@ +-- https://docs.oracle.com/en/error-help/db/ora-43929/?r=23ai +SET MAX_STRING_SIZE=EXTENDED; + CREATE TABLE ®istry..releases ( version FLOAT PRIMARY KEY, installed_at TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL, @@ -12,11 +15,11 @@ COMMENT ON COLUMN ®istry..releases.installer_name IS 'Name of the user who i COMMENT ON COLUMN ®istry..releases.installer_email IS 'Email address of the user who installed the registry release.'; CREATE TABLE ®istry..projects ( - project VARCHAR2(512 CHAR) PRIMARY KEY, - uri VARCHAR2(512 CHAR) NULL UNIQUE, + project VARCHAR2(512 CHAR) PRIMARY KEY, + uri VARCHAR2(512 CHAR) COLLATE ASCII7 NULL UNIQUE, created_at TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL, - creator_name VARCHAR2(512 CHAR) NOT NULL, - creator_email VARCHAR2(512 CHAR) NOT NULL + creator_name VARCHAR2(512 CHAR) NOT NULL, + creator_email VARCHAR2(512 CHAR) NOT NULL ); COMMENT ON TABLE ®istry..projects IS 'Sqitch projects deployed to this database.'; @@ -27,8 +30,8 @@ COMMENT ON COLUMN ®istry..projects.creator_name IS 'Name of the user who ad COMMENT ON COLUMN ®istry..projects.creator_email IS 'Email address of the user who added the project.'; CREATE TABLE ®istry..changes ( - change_id CHAR(40) PRIMARY KEY, - script_hash CHAR(40) NULL, + change_id CHAR(40) COLLATE ASCII7 PRIMARY KEY, + script_hash CHAR(40) COLLATE ASCII7 NULL, change VARCHAR2(512 CHAR) NOT NULL, project VARCHAR2(512 CHAR) NOT NULL REFERENCES ®istry..projects(project), note VARCHAR2(4000 CHAR) DEFAULT '', @@ -55,10 +58,10 @@ COMMENT ON COLUMN ®istry..changes.planner_name IS 'Name of the user who pl COMMENT ON COLUMN ®istry..changes.planner_email IS 'Email address of the user who planned the change.'; CREATE TABLE ®istry..tags ( - tag_id CHAR(40) PRIMARY KEY, + tag_id CHAR(40) COLLATE ASCII7 PRIMARY KEY, tag VARCHAR2(512 CHAR) NOT NULL, project VARCHAR2(512 CHAR) NOT NULL REFERENCES ®istry..projects(project), - change_id CHAR(40) NOT NULL REFERENCES ®istry..changes(change_id), + change_id CHAR(40) COLLATE ASCII7 NOT NULL REFERENCES ®istry..changes(change_id), note VARCHAR2(4000 CHAR) DEFAULT '', committed_at TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL, committer_name VARCHAR2(512 CHAR) NOT NULL, @@ -83,10 +86,10 @@ COMMENT ON COLUMN ®istry..tags.planner_name IS 'Name of the user who plane COMMENT ON COLUMN ®istry..tags.planner_email IS 'Email address of the user who planned the tag.'; CREATE TABLE ®istry..dependencies ( - change_id CHAR(40) NOT NULL REFERENCES ®istry..changes(change_id) ON DELETE CASCADE, - type VARCHAR2(8) NOT NULL, - dependency VARCHAR2(1024 CHAR) NOT NULL, - dependency_id CHAR(40) NULL REFERENCES ®istry..changes(change_id), + change_id CHAR(40) COLLATE ASCII7 NOT NULL REFERENCES ®istry..changes(change_id) ON DELETE CASCADE, + type VARCHAR2(8) COLLATE ASCII7 NOT NULL, + dependency VARCHAR2(1024 CHAR) NOT NULL, + dependency_id CHAR(40) COLLATE ASCII7 NULL REFERENCES ®istry..changes(change_id), CONSTRAINT dependencies_check CHECK ( (type = 'require' AND dependency_id IS NOT NULL) OR (type = 'conflict' AND dependency_id IS NULL) @@ -104,11 +107,11 @@ CREATE TYPE ®istry..sqitch_array AS varray(1024) OF VARCHAR2(512); / CREATE TABLE ®istry..events ( - event VARCHAR2(6) NOT NULL + event VARCHAR2(6) COLLATE ASCII7 NOT NULL CONSTRAINT events_event_check CHECK ( event IN ('deploy', 'revert', 'fail', 'merge') ), - change_id CHAR(40) NOT NULL, + change_id CHAR(40) COLLATE ASCII7 NOT NULL, change VARCHAR2(512 CHAR) NOT NULL, project VARCHAR2(512 CHAR) NOT NULL REFERENCES ®istry..projects(project), note VARCHAR2(4000 CHAR) DEFAULT '', diff --git a/lib/App/Sqitch/Engine/pg.sql b/lib/App/Sqitch/Engine/pg.sql index 87a0375ac..7dd12ba1d 100644 --- a/lib/App/Sqitch/Engine/pg.sql +++ b/lib/App/Sqitch/Engine/pg.sql @@ -10,7 +10,7 @@ CREATE TABLE :"registry".releases ( installed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(), installer_name TEXT NOT NULL, installer_email TEXT NOT NULL -); +):tableopts; COMMENT ON TABLE :"registry".releases IS 'Sqitch registry releases.'; COMMENT ON COLUMN :"registry".releases.version IS 'Version of the Sqitch registry.'; @@ -19,11 +19,11 @@ 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.'; 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 "C" NULL UNIQUE, + created_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(), + creator_name TEXT NOT NULL, + creator_email TEXT NOT NULL ):tableopts; COMMENT ON TABLE :"registry".projects IS 'Sqitch projects deployed to this database.'; @@ -34,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 "C" PRIMARY KEY, + script_hash TEXT COLLATE "C" 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) ):tableopts; @@ -62,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 "C" PRIMARY KEY, + tag TEXT NOT NULL, + project TEXT NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE, + change_id TEXT COLLATE "C" 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) ):tableopts; @@ -90,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 "C" NOT NULL REFERENCES :"registry".changes(change_id) ON UPDATE CASCADE ON DELETE CASCADE, + type TEXT COLLATE "C" NOT NULL, + dependency TEXT NOT NULL, + dependency_id TEXT COLLATE "C" 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) ), @@ -107,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 "C" 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 "C" 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) ):tableopts; diff --git a/lib/App/Sqitch/Engine/snowflake.sql b/lib/App/Sqitch/Engine/snowflake.sql index 93b244e27..acd2b32ce 100644 --- a/lib/App/Sqitch/Engine/snowflake.sql +++ b/lib/App/Sqitch/Engine/snowflake.sql @@ -15,12 +15,12 @@ COMMENT ON COLUMN ®istry.releases.installed_at IS 'Date the registry relea COMMENT ON COLUMN ®istry.releases.installer_name IS 'Name of the user who installed the registry release.'; COMMENT ON COLUMN ®istry.releases.installer_email IS 'Email address of the user who installed the registry release.'; -CREATE TABLE ®istry.projects ( - project TEXT PRIMARY KEY, - uri TEXT NULL UNIQUE, - created_at TIMESTAMP_TZ NOT NULL DEFAULT current_timestamp, - creator_name TEXT NOT NULL, - creator_email TEXT NOT NULL +CREATE TABLE projects ( + project TEXT PRIMARY KEY, + uri TEXT COLLATE 'en_us_posix' NULL UNIQUE, + created_at TIMESTAMP_TZ NOT NULL DEFAULT current_timestamp, + creator_name TEXT NOT NULL, + creator_email TEXT NOT NULL ); COMMENT ON TABLE ®istry.projects IS 'Sqitch projects deployed to this database.'; @@ -31,17 +31,17 @@ COMMENT ON COLUMN ®istry.projects.creator_name IS 'Name of the user who add COMMENT ON COLUMN ®istry.projects.creator_email IS 'Email address of the user who added the project.'; CREATE TABLE ®istry.changes ( - change_id TEXT PRIMARY KEY, - script_hash TEXT NULL, - change TEXT NOT NULL, - project TEXT NOT NULL REFERENCES ®istry.projects(project) ON UPDATE CASCADE, - note TEXT NOT NULL DEFAULT '', - committed_at TIMESTAMP_TZ NOT NULL DEFAULT current_timestamp, - committer_name TEXT NOT NULL, - committer_email TEXT NOT NULL, - planned_at TIMESTAMP_TZ NOT NULL, - planner_name TEXT NOT NULL, - planner_email TEXT NOT NULL, + change_id TEXT COLLATE 'en_us_posix' PRIMARY KEY, + script_hash TEXT COLLATE 'en_us_posix' NULL, + change TEXT NOT NULL, + project TEXT NOT NULL REFERENCES ®istry.projects(project) ON UPDATE CASCADE, + note TEXT NOT NULL DEFAULT '', + committed_at TIMESTAMP_TZ NOT NULL DEFAULT current_timestamp, + committer_name TEXT NOT NULL, + committer_email TEXT NOT NULL, + planned_at TIMESTAMP_TZ NOT NULL, + planner_name TEXT NOT NULL, + planner_email TEXT NOT NULL, UNIQUE(project, script_hash) ); @@ -59,17 +59,17 @@ COMMENT ON COLUMN ®istry.changes.planner_name IS 'Name of the user who pla COMMENT ON COLUMN ®istry.changes.planner_email IS 'Email address of the user who planned the change.'; CREATE TABLE ®istry.tags ( - tag_id TEXT PRIMARY KEY, - tag TEXT NOT NULL, - project TEXT NOT NULL REFERENCES ®istry.projects(project) ON UPDATE CASCADE, - change_id TEXT NOT NULL REFERENCES ®istry.changes(change_id) ON UPDATE CASCADE, - note TEXT NOT NULL DEFAULT '', - committed_at TIMESTAMPTZ NOT NULL DEFAULT current_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_posix' PRIMARY KEY, + tag TEXT NOT NULL, + project TEXT NOT NULL REFERENCES ®istry.projects(project) ON UPDATE CASCADE, + change_id TEXT COLLATE 'en_us_posix' NOT NULL REFERENCES ®istry.changes(change_id) ON UPDATE CASCADE, + note TEXT NOT NULL DEFAULT '', + committed_at TIMESTAMPTZ NOT NULL DEFAULT current_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) ); @@ -87,10 +87,10 @@ COMMENT ON COLUMN ®istry.tags.planner_name IS 'Name of the user who planed COMMENT ON COLUMN ®istry.tags.planner_email IS 'Email address of the user who planned the tag.'; CREATE TABLE ®istry.dependencies ( - change_id TEXT NOT NULL REFERENCES ®istry.changes(change_id) ON UPDATE CASCADE ON DELETE CASCADE, - type TEXT NOT NULL, - dependency TEXT NOT NULL, - dependency_id TEXT NULL REFERENCES ®istry.changes(change_id) ON UPDATE CASCADE, + change_id TEXT COLLATE 'en_us_posix' NOT NULL REFERENCES ®istry.changes(change_id) ON UPDATE CASCADE ON DELETE CASCADE, + type TEXT COLLATE 'en_us_posix' NOT NULL, + dependency TEXT NOT NULL, + dependency_id TEXT COLLATE 'en_us_posix' NULL REFERENCES ®istry.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) @@ -105,23 +105,23 @@ COMMENT ON COLUMN ®istry.dependencies.dependency IS 'Dependency name.'; COMMENT ON COLUMN ®istry.dependencies.dependency_id IS 'Change ID the dependency resolves to.'; CREATE TABLE ®istry.events ( - event TEXT NOT NULL, + event TEXT COLLATE 'en_us_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 ®istry.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 current_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_posix' NOT NULL, + change TEXT NOT NULL, + project TEXT NOT NULL REFERENCES ®istry.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 current_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) );