From dd9ba0f7bc82ed1f9252442269b1e28b6b7be2f6 Mon Sep 17 00:00:00 2001 From: "David E. Wheeler" Date: Sat, 4 Jan 2025 11:35:26 -0500 Subject: [PATCH] Use POSIX collation in the Postgres registry Applies to Postgres 9.1 and higher and Yugabyte 2.9 and higher. Using the POSIX collation ensures that index ordering never changes when the database is upgraded, which is a particular problem with glibc collations, but since POSIX/C collation is strictly byte-ordered, it should be fine. Of course, any of use of `ORDER BY` on such columns will return unexpected results when users are used to other locales, but since Sqitch itself only ever orders by timestamp, it should not be an issue in its own use. Closes #763. --- Changes | 3 + lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql | 10 +-- lib/App/Sqitch/Engine/pg.pm | 13 +++- lib/App/Sqitch/Engine/pg.sql | 98 ++++++++++++------------ t/lib/upgradable_registries/pg.sql | 96 +++++++++++------------ t/pg.t | 35 ++++++++- 6 files changed, 150 insertions(+), 105 deletions(-) diff --git a/Changes b/Changes index c585c6915..f3d56219d 100644 --- a/Changes +++ b/Changes @@ -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)! 1.4.1 2024-02-04T16:35:32Z - Removed the quoting of the role and warehouse identifiers that was diff --git a/lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql b/lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql index 49f941762..8e0c2f31c 100644 --- a/lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql +++ b/lib/App/Sqitch/Engine/Upgrade/pg-1.0.sql @@ -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.'; @@ -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.'; diff --git a/lib/App/Sqitch/Engine/pg.pm b/lib/App/Sqitch/Engine/pg.pm index aa392564b..088a4bcc6 100644 --- a/lib/App/Sqitch/Engine/pg.pm +++ b/lib/App/Sqitch/Engine/pg.pm @@ -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{ @@ -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; diff --git a/lib/App/Sqitch/Engine/pg.sql b/lib/App/Sqitch/Engine/pg.sql index 87a0375ac..964f13f87 100644 --- a/lib/App/Sqitch/Engine/pg.sql +++ b/lib/App/Sqitch/Engine/pg.sql @@ -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.'; @@ -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.'; @@ -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; @@ -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; @@ -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) ), @@ -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; diff --git a/t/lib/upgradable_registries/pg.sql b/t/lib/upgradable_registries/pg.sql index a0f42da20..903d44eb7 100644 --- a/t/lib/upgradable_registries/pg.sql +++ b/t/lib/upgradable_registries/pg.sql @@ -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.'; @@ -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.'; @@ -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.'; @@ -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; @@ -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) ), @@ -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; diff --git a/t/pg.t b/t/pg.t index 9f594856a..a360cc488 100644 --- a/t/pg.t +++ b/t/pg.t @@ -371,6 +371,7 @@ RUNREG: { $mock_engine->mock(_psql_major_version => sub { $psql_maj }); my @ran; $mock_engine->mock(_run => sub { shift; push @ran, \@_ }); + $mock_engine->mock(_provider => 'postgres'); # Mock up the database handle. my $dbh = DBI->connect('dbi:Mem:', undef, undef, {}); @@ -437,7 +438,7 @@ RUNREG: { '--file' => $tmp_fh, '--set' => "tableopts= DISTRIBUTE BY REPLICATION", ]], 'Shoud have deployed the temp SQL file'; - is_deeply \@sra_args, [], 'Still hould not have have called selectrow_array'; + is_deeply \@sra_args, [], 'Still should not have have called selectrow_array'; is_deeply \@done, [['SET search_path = ?', undef, $registry]], 'The registry should have been added to the search path again'; @@ -445,6 +446,38 @@ RUNREG: { file_contents_like $tmp_fh, qr/\QCREATE SCHEMA :"registry";/, 'Should have removed IF NOT EXISTS from CREATE SCHEMA'; + # Make sure we havne't removed collation. + file_contents_like $tmp_fh, qr/\QCOLLATE "POSIX"/, + 'Should not have removed QCOLLATE "POSIX"'; + + # Reset and try Postgres 9.0 server + @probed = @ran = @done = (); + @prob_ret = (90000, 1); + $tmp_fh = undef; + $ENV{FOO} = 1; + ok $pg->_run_registry_file($ddl), 'Run the registry file again'; + delete $ENV{FOO}; + is_deeply \@probed, [ + ['-c', 'SHOW server_version_num'], + ['-c', $xc_query], + ], 'Should have again fetched the server version & checked for XC'; + isnt $tmp_fh, undef, 'Should again have a temp file handle'; + is_deeply \@ran, [[ + '--file' => $tmp_fh, + '--set' => "tableopts= DISTRIBUTE BY REPLICATION", + ]], 'Shoud have again deployed the temp SQL file'; + is_deeply \@sra_args, [], 'Again should not have have called selectrow_array'; + is_deeply \@done, [['SET search_path = ?', undef, $registry]], + 'The registry again should have been added to the search path'; + + # Make sure the file was changed to remove SCHEMA IF NOT EXISTS. + file_contents_unlike $tmp_fh, qr/\QCREATE SCHEMA IF NOT EXISTS/, + 'Should have removed IF NOT EXISTS from CREATE SCHEMA'; + + # Make sure the file was changed to remove COLLATE "POSIX". + file_contents_unlike $tmp_fh, qr/\QCOLLATE "POSIX"/, + 'Should have removed COLLATE "POSIX"'; + # Reset and try with Server 11 and psql 8.x. @probed = @ran = @done = (); $psql_maj = 8;