Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Use POSIX collation in the Postgres registry #765

Closed
wants to merge 1 commit into from
Closed
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
3 changes: 3 additions & 0 deletions Changes
Original file line number Diff line number Diff line change
Expand Up @@ -49,6 +49,9 @@ Revision history for Perl extension App::Sqitch
its Unicode improvements. Thanks to Mark Tyrrell for the report and
@tiberiusferreira and Perl Monks `1nickt` and`InfiniteSilence` for the
feedback (#825).
- Set all text column collations to "POSIX" on Postgres 9.1 and higher.
and Yugabyte 2.9 and higher. Does not apply to existing registries,
only new ones. Thanks to @datafoo for the suggestion (#763)!
Comment on lines +52 to +54
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Doesn't this also apply when you upgrade the registry, at least for some columns?

Copy link
Collaborator Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

It would if we added more upgrades, that's true.


1.4.1 2024-02-04T16:35:32Z
- Removed the quoting of the role and warehouse identifiers that was
Expand Down
10 changes: 5 additions & 5 deletions lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,10 +3,10 @@ BEGIN;
SET client_min_messages = warning;

CREATE TABLE :"registry".releases (
version REAL PRIMARY KEY,
installed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
installer_name TEXT NOT NULL,
installer_email TEXT NOT NULL
version REAL PRIMARY KEY,
installed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
installer_name TEXT COLLATE "POSIX" NOT NULL,
installer_email TEXT COLLATE "POSIX" NOT NULL
):tableopts;

COMMENT ON TABLE :"registry".releases IS 'Sqitch registry releases.';
Expand All @@ -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 "POSIX" 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
13 changes: 11 additions & 2 deletions lib/App/Sqitch/Engine/pg.pm
Original file line number Diff line number Diff line change
Expand Up @@ -221,6 +221,10 @@ sub _run_registry_file {
# Fetch the client version. 8.4 == 80400
my $version = $self->_probe('-c', 'SHOW server_version_num');
my $psql_maj = $self->_psql_major_version;
my $yb_version = $self->_provider eq 'postgres' ? 9999 : do {
my ($v) = $self->_probe('-c', 'SHOW server_version') =~ /-YB-(\d+\.\d+)/;
$v;
};

# Is this XC?
my $opts = $self->_probe('-c', q{
Expand All @@ -231,19 +235,24 @@ sub _run_registry_file {
AND proname = 'pgxc_version';
}) ? ' DISTRIBUTE BY REPLICATION' : '';

if ($version < 90300 || $psql_maj < 9) {
if ($version < 90300 || $psql_maj < 9 || $yb_version < 2.9) {
# Need to transform the SQL and write it to a temp file.
my $sql = scalar $file->slurp;

# No CREATE SCHEMA IF NOT EXISTS syntax prior to 9.3.
$sql =~ s/SCHEMA IF NOT EXISTS/SCHEMA/ if $version < 90300;

# No COLLATE expression prior to 9.1 or Yugabyte 2.9.
$sql =~ s/COLLATE "POSIX"//g if $version < 90100 || $yb_version < 2.9;

if ($psql_maj < 9) {
# Also no :"registry" variable syntax prior to psql 9.0.s
# No :"registry" variable syntax prior to psql 9.0.
($schema) = $self->dbh->selectrow_array(
'SELECT quote_ident(?)', undef, $schema
);
$sql =~ s{:"registry"}{$schema}g;
}

require File::Temp;
my $fh = File::Temp->new;
print $fh $sql;
Expand Down
98 changes: 49 additions & 49 deletions lib/App/Sqitch/Engine/pg.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,10 +6,10 @@ CREATE SCHEMA IF NOT EXISTS :"registry";
COMMENT ON SCHEMA :"registry" IS 'Sqitch database deployment metadata v1.1.';

CREATE TABLE :"registry".releases (
version REAL PRIMARY KEY,
installed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
installer_name TEXT NOT NULL,
installer_email TEXT NOT NULL
version REAL PRIMARY KEY,
installed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
installer_name TEXT COLLATE "POSIX" NOT NULL,
installer_email TEXT COLLATE "POSIX" NOT NULL
);

COMMENT ON TABLE :"registry".releases IS 'Sqitch registry releases.';
Expand All @@ -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 COLLATE "POSIX" PRIMARY KEY,
uri TEXT COLLATE "POSIX" NULL UNIQUE ,
created_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
creator_name TEXT COLLATE "POSIX" NOT NULL,
creator_email TEXT COLLATE "POSIX" NOT NULL
):tableopts;

COMMENT ON TABLE :"registry".projects IS 'Sqitch projects deployed to this database.';
Expand All @@ -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 "POSIX" PRIMARY KEY,
script_hash TEXT COLLATE "POSIX" NULL,
change TEXT COLLATE "POSIX" NOT NULL,
project TEXT COLLATE "POSIX" NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
note TEXT COLLATE "POSIX" NOT NULL DEFAULT '',
committed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
committer_name TEXT COLLATE "POSIX" NOT NULL,
committer_email TEXT COLLATE "POSIX" NOT NULL,
planned_at TIMESTAMPTZ NOT NULL,
planner_name TEXT COLLATE "POSIX" NOT NULL,
planner_email TEXT COLLATE "POSIX" NOT NULL,
UNIQUE(project, script_hash)
):tableopts;

Expand All @@ -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 "POSIX" PRIMARY KEY,
tag TEXT COLLATE "POSIX" NOT NULL,
project TEXT COLLATE "POSIX" NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
change_id TEXT COLLATE "POSIX" NOT NULL REFERENCES :"registry".changes(change_id) ON UPDATE CASCADE,
note TEXT COLLATE "POSIX" NOT NULL DEFAULT '',
committed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
committer_name TEXT COLLATE "POSIX" NOT NULL,
committer_email TEXT COLLATE "POSIX" NOT NULL,
planned_at TIMESTAMPTZ NOT NULL,
planner_name TEXT COLLATE "POSIX" NOT NULL,
planner_email TEXT COLLATE "POSIX" NOT NULL,
UNIQUE(project, tag)
):tableopts;

Expand All @@ -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 "POSIX" NOT NULL REFERENCES :"registry".changes(change_id) ON UPDATE CASCADE ON DELETE CASCADE,
type TEXT COLLATE "POSIX" NOT NULL,
dependency TEXT COLLATE "POSIX" NOT NULL,
dependency_id TEXT COLLATE "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 @@ -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 "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 "POSIX" NOT NULL,
change TEXT COLLATE "POSIX" NOT NULL,
project TEXT COLLATE "POSIX" NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
note TEXT COLLATE "POSIX" NOT NULL DEFAULT '',
requires TEXT[] COLLATE "POSIX" NOT NULL DEFAULT '{}',
conflicts TEXT[] COLLATE "POSIX" NOT NULL DEFAULT '{}',
tags TEXT[] COLLATE "POSIX" NOT NULL DEFAULT '{}',
committed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
committer_name TEXT COLLATE "POSIX" NOT NULL,
committer_email TEXT COLLATE "POSIX" NOT NULL,
planned_at TIMESTAMPTZ NOT NULL,
planner_name TEXT COLLATE "POSIX" NOT NULL,
planner_email TEXT COLLATE "POSIX" NOT NULL,
PRIMARY KEY (change_id, committed_at)
):tableopts;

Expand Down
96 changes: 48 additions & 48 deletions t/lib/upgradable_registries/pg.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,10 +6,10 @@ CREATE SCHEMA IF NOT EXISTS :"registry";
COMMENT ON SCHEMA :"registry" IS 'Sqitch database deployment metadata v1.0.';

CREATE TABLE :"registry".releases (
version REAL PRIMARY KEY,
installed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
installer_name TEXT NOT NULL,
installer_email TEXT NOT NULL
version REAL PRIMARY KEY,
installed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
installer_name TEXT COLLATE "POSIX" NOT NULL,
installer_email TEXT COLLATE "POSIX" NOT NULL
):tableopts;

COMMENT ON TABLE :"registry".releases IS 'Sqitch registry releases.';
Expand All @@ -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 COLLATE "POSIX" PRIMARY KEY,
uri TEXT COLLATE "POSIX" NULL UNIQUE,
created_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
creator_name TEXT COLLATE "POSIX" NOT NULL,
creator_email TEXT COLLATE "POSIX" NOT NULL
):tableopts;

COMMENT ON TABLE :"registry".projects IS 'Sqitch projects deployed to this database.';
Expand All @@ -34,16 +34,16 @@ 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,
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 "POSIX" PRIMARY KEY,
change TEXT COLLATE "POSIX" NOT NULL,
project TEXT COLLATE "POSIX" NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
note TEXT COLLATE "POSIX" NOT NULL DEFAULT '',
committed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
committer_name TEXT COLLATE "POSIX" NOT NULL,
committer_email TEXT COLLATE "POSIX" NOT NULL,
planned_at TIMESTAMPTZ NOT NULL,
planner_name TEXT COLLATE "POSIX" NOT NULL,
planner_email TEXT COLLATE "POSIX" NOT NULL
):tableopts;

COMMENT ON TABLE :"registry".changes IS 'Tracks the changes currently deployed to the database.';
Expand All @@ -59,17 +59,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 "POSIX" PRIMARY KEY,
tag TEXT COLLATE "POSIX" NOT NULL,
project TEXT COLLATE "POSIX" NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
change_id TEXT COLLATE "POSIX" NOT NULL REFERENCES :"registry".changes(change_id) ON UPDATE CASCADE,
note TEXT COLLATE "POSIX" NOT NULL DEFAULT '',
committed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
committer_name TEXT COLLATE "POSIX" NOT NULL,
committer_email TEXT COLLATE "POSIX" NOT NULL,
planned_at TIMESTAMPTZ NOT NULL,
planner_name TEXT COLLATE "POSIX" NOT NULL,
planner_email TEXT COLLATE "POSIX" NOT NULL,
UNIQUE(project, tag)
):tableopts;

Expand All @@ -87,10 +87,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 CHECK (
change_id TEXT COLLATE "POSIX" NOT NULL REFERENCES :"registry".changes(change_id) ON UPDATE CASCADE ON DELETE CASCADE,
type TEXT COLLATE "POSIX" NOT NULL,
dependency TEXT COLLATE "POSIX" NOT NULL,
dependency_id TEXT COLLATE "POSIX" NULL REFERENCES :"registry".changes(change_id) ON UPDATE CASCADE CHECK (
(type = 'require' AND dependency_id IS NOT NULL)
OR (type = 'conflict' AND dependency_id IS NULL)
),
Expand All @@ -104,20 +104,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 TEXT NOT NULL CHECK (event IN ('deploy', 'revert', 'fail')),
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,
event TEXT COLLATE "POSIX" NOT NULL CHECK (event IN ('deploy', 'revert', 'fail')),
change_id TEXT COLLATE "POSIX" NOT NULL,
change TEXT COLLATE "POSIX" NOT NULL,
project TEXT COLLATE "POSIX" NOT NULL REFERENCES :"registry".projects(project) ON UPDATE CASCADE,
note TEXT COLLATE "POSIX" NOT NULL DEFAULT '',
requires TEXT[] COLLATE "POSIX" NOT NULL DEFAULT '{}',
conflicts TEXT[] COLLATE "POSIX" NOT NULL DEFAULT '{}',
tags TEXT[] COLLATE "POSIX" NOT NULL DEFAULT '{}',
committed_at TIMESTAMPTZ NOT NULL DEFAULT clock_timestamp(),
committer_name TEXT COLLATE "POSIX" NOT NULL,
committer_email TEXT COLLATE "POSIX" NOT NULL,
planned_at TIMESTAMPTZ NOT NULL,
planner_name TEXT COLLATE "POSIX" NOT NULL,
planner_email TEXT COLLATE "POSIX" NOT NULL,
PRIMARY KEY (change_id, committed_at)
):tableopts;

Expand Down
Loading
Loading