pg_upgrade from 9.0.7 to 9.1.3: duplicate key pg_authid_oid_index

Started by Bryan Murphyover 13 years ago9 messages
#1Bryan Murphy
bmurphy1976@gmail.com

I'm having a problem upgrading a cluster from 9.0.7 to 9.1.3. Here's the
error:

psql:/srv/pg_upgrade_dump_globals.sql:54: ERROR: duplicate key value
violates unique constraint "pg_authid_oid_index"
DETAIL: Key (oid)=(10) already exists.

Any ideas what I'm doing wrong?

Here's the verbose output from pg_upgrade:

$ /opt/postgresql-9.1/bin/pg_upgrade --link --verbose
--old-datadir=/srv/postgresql/pg_data --new-datadir=/srv/postgres-9.1
--old-bindir=/opt/postgresql-9.0/bin --new-bindir=/opt/postgresql-9.1/bin
Running in verbose mode
Performing Consistency Checks
-----------------------------
Checking current, bin, and data directories ok
Checking cluster versions ok
"/opt/postgresql-9.0/bin/pg_ctl" -w -l "/dev/null" -D
"/srv/postgresql/pg_data" -o "-p 5432 -c autovacuum=off -c
autovacuum_freeze_max_age=2000000000" start >> "/dev/null" 2>&1
Checking database user is a superuser ok
Checking for prepared transactions ok
Checking for reg* system oid user data types ok
Checking for contrib/isn with bigint-passing mismatch ok
Creating catalog dump
"/opt/postgresql-9.1/bin/pg_dumpall" --port 5432 --username "postgres"
--schema-only --binary-upgrade > "/srv/pg_upgrade_dump_all.sql"
ok
"/opt/postgresql-9.0/bin/pg_ctl" -w -l "/dev/null" -D
"/srv/postgresql/pg_data" stop >> "/dev/null" 2>&1
"/opt/postgresql-9.1/bin/pg_ctl" -w -l "/dev/null" -D "/srv/postgres-9.1"
-o "-p 5432 -b" start >> "/dev/null" 2>&1
Checking for prepared transactions ok
Checking for presence of required libraries ok

| If pg_upgrade fails after this point, you must
| re-initdb the new cluster before continuing.
| You will also need to remove the ".old" suffix
| from /srv/postgresql/pg_data/global/pg_control.old.

Performing Upgrade
------------------
Adding ".old" suffix to old global/pg_control ok
Analyzing all rows in the new cluster
"/opt/postgresql-9.1/bin/vacuumdb" --port 5432 --username "postgres" --all
--analyze >> "/dev/null" 2>&1
ok
Freezing all rows on the new cluster
"/opt/postgresql-9.1/bin/vacuumdb" --port 5432 --username "postgres" --all
--freeze >> "/dev/null" 2>&1
ok
"/opt/postgresql-9.1/bin/pg_ctl" -w -l "/dev/null" -D "/srv/postgres-9.1"
stop >> "/dev/null" 2>&1
Deleting new commit clogs ok
Copying old commit clogs to new server cp -Rf
"/srv/postgresql/pg_data/pg_clog" "/srv/postgres-9.1/pg_clog"
ok
Setting next transaction id for new cluster
"/opt/postgresql-9.1/bin/pg_resetxlog" -f -x 743542427 "/srv/postgres-9.1"

/dev/null

ok
Resetting WAL archives
"/opt/postgresql-9.1/bin/pg_resetxlog" -l 1,829,15 "/srv/postgres-9.1" >>
"/dev/null" 2>&1
ok
"/opt/postgresql-9.1/bin/pg_ctl" -w -l "/dev/null" -D "/srv/postgres-9.1"
-o "-p 5432 -b" start >> "/dev/null" 2>&1
Setting frozenxid counters in new cluster ok
Creating databases in the new cluster
"/opt/postgresql-9.1/bin/psql" --set ON_ERROR_STOP=on --no-psqlrc --port
5432 --username "postgres" -f "/srv/pg_upgrade_dump_globals.sql" --dbname
template1 >> "/dev/null"
psql:/srv/pg_upgrade_dump_globals.sql:54: ERROR: duplicate key value
violates unique constraint "pg_authid_oid_index"
DETAIL: Key (oid)=(10) already exists.

There were problems executing "/opt/postgresql-9.1/bin/psql" --set
ON_ERROR_STOP=on --no-psqlrc --port 5432 --username "postgres" -f
"/srv/pg_upgrade_dump_globals.sql" --dbname template1 >> "/dev/null"
Failure, exiting
"/opt/postgresql-9.1/bin/pg_ctl" -w -l "/dev/null" -D "/srv/postgres-9.1"
-m fast stop >> "/dev/null" 2>&1

Thanks,
Bryan

#2Jeff Davis
pgsql@j-davis.com
In reply to: Bryan Murphy (#1)
Re: pg_upgrade from 9.0.7 to 9.1.3: duplicate key pg_authid_oid_index

On Thu, 2012-05-31 at 15:55 -0500, Bryan Murphy wrote:

I'm having a problem upgrading a cluster from 9.0.7 to 9.1.3. Here's
the error:

Please send /srv/pg_upgrade_dump_globals.sql

Also, can you restart the old system (by removing the ".old" suffix, as
the message suggests), and then do a "SELECT oid,* FROM pg_authid" and
send the output along?

Regards,
Jeff Davis

#3Bryan Murphy
bmurphy1976@gmail.com
In reply to: Jeff Davis (#2)
Re: pg_upgrade from 9.0.7 to 9.1.3: duplicate key pg_authid_oid_index

On Thu, May 31, 2012 at 4:28 PM, Jeff Davis <pgsql@j-davis.com> wrote:

On Thu, 2012-05-31 at 15:55 -0500, Bryan Murphy wrote:

I'm having a problem upgrading a cluster from 9.0.7 to 9.1.3. Here's
the error:

Please send /srv/pg_upgrade_dump_globals.sql

Also, can you restart the old system (by removing the ".old" suffix, as
the message suggests), and then do a "SELECT oid,* FROM pg_authid" and
send the output along?

Here's the requested data: https://gist.github.com/2852014

I had to censor some of it because it contained sensitive information,
hopefully the censoring is obvious and I don't believe I touched any of the
functional information.

Thanks,
Bryan

#4Bryan Murphy
bmurphy1976@gmail.com
In reply to: Bryan Murphy (#3)
Re: pg_upgrade from 9.0.7 to 9.1.3: duplicate key pg_authid_oid_index

On Fri, Jun 1, 2012 at 8:07 AM, Bryan Murphy <bmurphy1976@gmail.com> wrote:

On Thu, May 31, 2012 at 4:28 PM, Jeff Davis <pgsql@j-davis.com> wrote:

On Thu, 2012-05-31 at 15:55 -0500, Bryan Murphy wrote:

I'm having a problem upgrading a cluster from 9.0.7 to 9.1.3. Here's
the error:

Please send /srv/pg_upgrade_dump_globals.sql

Also, can you restart the old system (by removing the ".old" suffix, as
the message suggests), and then do a "SELECT oid,* FROM pg_authid" and
send the output along?

Here's the requested data: https://gist.github.com/2852014

I had to censor some of it because it contained sensitive information,
hopefully the censoring is obvious and I don't believe I touched any of the
functional information.

OK, I seem to have figured it out. Your questions pointed me in the right
direction.

The old 9.0 cluster was created by ubuntu. In this cluster there was an
ubuntu user with an oid of 10 and a postgres user with an oid of 16386.

The new 9.1 cluster was created with a custom build of postgres 9.1. This
did not have an ubuntu user, and it had a postgres user with an oid of 10.

I renamed the postgres user in the old 9.0 cluster to pg, renamed the
ubuntu user to postgres, and then re-ran pg_upgrade and it appears to have
worked correctly this time.

Bryan

#5Tom Lane
tgl@sss.pgh.pa.us
In reply to: Bryan Murphy (#4)
Re: pg_upgrade from 9.0.7 to 9.1.3: duplicate key pg_authid_oid_index

Bryan Murphy <bmurphy1976@gmail.com> writes:

The old 9.0 cluster was created by ubuntu. In this cluster there was an
ubuntu user with an oid of 10 and a postgres user with an oid of 16386.

The new 9.1 cluster was created with a custom build of postgres 9.1. This
did not have an ubuntu user, and it had a postgres user with an oid of 10.

OID 10 is the bootstrap superuser, which is created with the name of the
operating system user that ran initdb. So the above does not sound like
anything to do with custom vs stock builds, but with who did initdb.

It seems that pg_upgrade needs a check to make sure that the bootstrap
superuser is named the same in old and new clusters.

regards, tom lane

#6Bruce Momjian
bruce@momjian.us
In reply to: Tom Lane (#5)
1 attachment(s)
Re: [GENERAL] pg_upgrade from 9.0.7 to 9.1.3: duplicate key pg_authid_oid_index

On Fri, Jun 01, 2012 at 09:52:59AM -0400, Tom Lane wrote:

Bryan Murphy <bmurphy1976@gmail.com> writes:

The old 9.0 cluster was created by ubuntu. In this cluster there was an
ubuntu user with an oid of 10 and a postgres user with an oid of 16386.

The new 9.1 cluster was created with a custom build of postgres 9.1. This
did not have an ubuntu user, and it had a postgres user with an oid of 10.

OID 10 is the bootstrap superuser, which is created with the name of the
operating system user that ran initdb. So the above does not sound like
anything to do with custom vs stock builds, but with who did initdb.

It seems that pg_upgrade needs a check to make sure that the bootstrap
superuser is named the same in old and new clusters.

[ Thread moved to hackers.]

OK, I have studied this. First we preserve pg_authid.oid because oids
are stored in pg_largeobject_metadata. Second, we dumpall all users,
even the install user because (from pg_dumpall.c):

* We dump CREATE ROLE followed by ALTER ROLE to ensure that the role
* will acquire the right properties even if it already exists (ie, it
* won't hurt for the CREATE to fail). This is particularly important
* for the role we are connected as, since even with --clean we will
* have failed to drop it.

So, pg_upgrade has to strip out restoring the install user because that
would cause an error on restore. That is done in
dump.c::split_old_dump().

The problem is if the old and new install users have different oids, as
the reporter verified.

The attached patch adds checks to verify the the old/new servers have
the same install-user oid.

--
Bruce Momjian <bruce@momjian.us> http://momjian.us
EnterpriseDB http://enterprisedb.com

+ It's impossible for everything to be true. +

Attachments:

pg_upgrade.difftext/x-diff; charset=us-asciiDownload
diff --git a/contrib/pg_upgrade/pg_upgrade.c b/contrib/pg_upgrade/pg_upgrade.c
new file mode 100644
index 465ecdd..ba81823
*** a/contrib/pg_upgrade/pg_upgrade.c
--- b/contrib/pg_upgrade/pg_upgrade.c
***************
*** 29,35 ****
   *	We control all assignments of pg_enum.oid because these oids are stored
   *	in user tables as enum values.
   *
!  *	We control all assignments of pg_auth.oid because these oids are stored
   *	in pg_largeobject_metadata.
   */
  
--- 29,35 ----
   *	We control all assignments of pg_enum.oid because these oids are stored
   *	in user tables as enum values.
   *
!  *	We control all assignments of pg_authid.oid because these oids are stored
   *	in pg_largeobject_metadata.
   */
  
diff --git a/contrib/pg_upgrade/check.c b/contrib/pg_upgrade/check.c
new file mode 100644
index 2669c09..df77f53
*** a/contrib/pg_upgrade/check.c
--- b/contrib/pg_upgrade/check.c
*************** static void set_locale_and_encoding(Clus
*** 16,22 ****
  static void check_new_cluster_is_empty(void);
  static void check_locale_and_encoding(ControlData *oldctrl,
  						  ControlData *newctrl);
! static void check_is_super_user(ClusterInfo *cluster);
  static void check_for_prepared_transactions(ClusterInfo *cluster);
  static void check_for_isn_and_int8_passing_mismatch(ClusterInfo *cluster);
  static void check_for_reg_data_type_usage(ClusterInfo *cluster);
--- 16,22 ----
  static void check_new_cluster_is_empty(void);
  static void check_locale_and_encoding(ControlData *oldctrl,
  						  ControlData *newctrl);
! static void check_is_super_user_get_oid(ClusterInfo *cluster);
  static void check_for_prepared_transactions(ClusterInfo *cluster);
  static void check_for_isn_and_int8_passing_mismatch(ClusterInfo *cluster);
  static void check_for_reg_data_type_usage(ClusterInfo *cluster);
*************** check_old_cluster(bool live_check, char
*** 69,75 ****
  	/*
  	 * Check for various failure cases
  	 */
! 	check_is_super_user(&old_cluster);
  	check_for_prepared_transactions(&old_cluster);
  	check_for_reg_data_type_usage(&old_cluster);
  	check_for_isn_and_int8_passing_mismatch(&old_cluster);
--- 69,75 ----
  	/*
  	 * Check for various failure cases
  	 */
! 	check_is_super_user_get_oid(&old_cluster);
  	check_for_prepared_transactions(&old_cluster);
  	check_for_reg_data_type_usage(&old_cluster);
  	check_for_isn_and_int8_passing_mismatch(&old_cluster);
*************** check_new_cluster(void)
*** 121,137 ****
  {
  	set_locale_and_encoding(&new_cluster);
  
  	get_db_and_rel_infos(&new_cluster);
  
  	check_new_cluster_is_empty();
- 	check_for_prepared_transactions(&new_cluster);
  
  	check_loadable_libraries();
  
- 	check_locale_and_encoding(&old_cluster.controldata, &new_cluster.controldata);
- 
  	if (user_opts.transfer_mode == TRANSFER_MODE_LINK)
  		check_hard_link();
  }
  
  
--- 121,144 ----
  {
  	set_locale_and_encoding(&new_cluster);
  
+ 	check_locale_and_encoding(&old_cluster.controldata, &new_cluster.controldata);
+ 
  	get_db_and_rel_infos(&new_cluster);
  
  	check_new_cluster_is_empty();
  
  	check_loadable_libraries();
  
  	if (user_opts.transfer_mode == TRANSFER_MODE_LINK)
  		check_hard_link();
+ 
+     check_is_super_user_get_oid(&new_cluster);
+     /* We don't restore our own user, so both clusters better have equal user oids */
+     if (old_cluster.user_oid != new_cluster.user_oid)
+ 		pg_log(PG_FATAL,
+ 		"Old and new cluster superusers have different values for pg_authid.oid");
+     
+ 	check_for_prepared_transactions(&new_cluster);
  }
  
  
*************** create_script_for_old_cluster_deletion(c
*** 577,588 ****
  
  
  /*
!  *	check_is_super_user()
   *
   *	Make sure we are the super-user.
   */
  static void
! check_is_super_user(ClusterInfo *cluster)
  {
  	PGresult   *res;
  	PGconn	   *conn = connectToServer(cluster, "template1");
--- 584,595 ----
  
  
  /*
!  *	check_is_super_user_get_oid()
   *
   *	Make sure we are the super-user.
   */
  static void
! check_is_super_user_get_oid(ClusterInfo *cluster)
  {
  	PGresult   *res;
  	PGconn	   *conn = connectToServer(cluster, "template1");
*************** check_is_super_user(ClusterInfo *cluster
*** 591,597 ****
  
  	/* Can't use pg_authid because only superusers can view it. */
  	res = executeQueryOrDie(conn,
! 							"SELECT rolsuper "
  							"FROM pg_catalog.pg_roles "
  							"WHERE rolname = current_user");
  
--- 598,604 ----
  
  	/* Can't use pg_authid because only superusers can view it. */
  	res = executeQueryOrDie(conn,
! 							"SELECT rolsuper, oid "
  							"FROM pg_catalog.pg_roles "
  							"WHERE rolname = current_user");
  
*************** check_is_super_user(ClusterInfo *cluster
*** 599,604 ****
--- 606,613 ----
  		pg_log(PG_FATAL, "database user \"%s\" is not a superuser\n",
  			   os_info.user);
  
+ 	cluster->user_oid = atooid(PQgetvalue(res, 0, 1));
+ 
  	PQclear(res);
  
  	PQfinish(conn);
diff --git a/contrib/pg_upgrade/pg_upgrade.h b/contrib/pg_upgrade/pg_upgrade.h
new file mode 100644
index 26aa7bb..ef59c2b
*** a/contrib/pg_upgrade/pg_upgrade.h
--- b/contrib/pg_upgrade/pg_upgrade.h
*************** typedef struct
*** 230,235 ****
--- 230,236 ----
  	char		major_version_str[64];	/* string PG_VERSION of cluster */
  	uint32		bin_version;	/* version returned from pg_ctl */
  	Oid			pg_database_oid;	/* OID of pg_database relation */
+ 	Oid			user_oid;		/* OID of connected user */
  	char	   *tablespace_suffix;		/* directory specification */
  } ClusterInfo;
  
#7Tom Lane
tgl@sss.pgh.pa.us
In reply to: Bruce Momjian (#6)
Re: Re: [GENERAL] pg_upgrade from 9.0.7 to 9.1.3: duplicate key pg_authid_oid_index

Bruce Momjian <bruce@momjian.us> writes:

On Fri, Jun 01, 2012 at 09:52:59AM -0400, Tom Lane wrote:

It seems that pg_upgrade needs a check to make sure that the bootstrap
superuser is named the same in old and new clusters.

The attached patch adds checks to verify the the old/new servers have
the same install-user oid.

That may or may not be a useful check to make, but it's got
approximately nothing to do with what I was complaining about.

In particular, supposing that the user has given you a username that
isn't the bootstrap superuser in the new cluster, this patch is not
going to stop the update script from failing. Because the script is
then going to try to replace the bootstrap superuser, and that is
certainly going to give an error.

I see the point of worrying about the install user as well as the
bootstrap superuser, but wouldn't it be best to insist they be the same?
Particularly in the new cluster, where if they aren't the same it means
the user has manually created at least one role in the new cluster,
which is likely to lead to OID conflicts or worse.

Furthermore, if the bootstrap superusers aren't named the same, your
patch fails to handle the original complaint. In the case the
OP mentioned, the old cluster had
OID 10: "ubuntu"
some user-defined OID: "postgres"
and the new cluster had
OID 10: "postgres"
If the user tells pg_upgrade to use username postgres, your check will
not fail AFAICS, but nonetheless things are going to be messed up after
the upgrade, because some objects and privileges that used to belong to
the bootstrap superuser will now belong to a non-default superuser,
whereas what used to belong to the non-default superuser will now belong
to the bootstrap superuser. That cannot be thought desirable. For one
reason, in the old installation the postgres role could have been
dropped (possibly after dropping a few non-builtin objects) whereas the
"ubuntu" role was pinned. In the new installation, "postgres" is pinned
and "ubuntu" won't be.

I think the checks that are actually needed here are (1) bootstrap
superusers are named the same, and (2) there are no roles other than the
bootstrap superuser in the new cluster.

regards, tom lane

#8Bruce Momjian
bruce@momjian.us
In reply to: Tom Lane (#7)
1 attachment(s)
Re: Re: [GENERAL] pg_upgrade from 9.0.7 to 9.1.3: duplicate key pg_authid_oid_index

On Sat, Jun 02, 2012 at 05:10:03PM -0400, Tom Lane wrote:

Bruce Momjian <bruce@momjian.us> writes:

On Fri, Jun 01, 2012 at 09:52:59AM -0400, Tom Lane wrote:

It seems that pg_upgrade needs a check to make sure that the bootstrap
superuser is named the same in old and new clusters.

The attached patch adds checks to verify the the old/new servers have
the same install-user oid.

That may or may not be a useful check to make, but it's got
approximately nothing to do with what I was complaining about.

In particular, supposing that the user has given you a username that
isn't the bootstrap superuser in the new cluster, this patch is not
going to stop the update script from failing. Because the script is
then going to try to replace the bootstrap superuser, and that is
certainly going to give an error.

I see the point of worrying about the install user as well as the
bootstrap superuser, but wouldn't it be best to insist they be the same?
Particularly in the new cluster, where if they aren't the same it means
the user has manually created at least one role in the new cluster,
which is likely to lead to OID conflicts or worse.

Furthermore, if the bootstrap superusers aren't named the same, your
patch fails to handle the original complaint. In the case the
OP mentioned, the old cluster had
OID 10: "ubuntu"
some user-defined OID: "postgres"
and the new cluster had
OID 10: "postgres"
If the user tells pg_upgrade to use username postgres, your check will
not fail AFAICS, but nonetheless things are going to be messed up after
the upgrade, because some objects and privileges that used to belong to
the bootstrap superuser will now belong to a non-default superuser,
whereas what used to belong to the non-default superuser will now belong
to the bootstrap superuser. That cannot be thought desirable. For one
reason, in the old installation the postgres role could have been
dropped (possibly after dropping a few non-builtin objects) whereas the
"ubuntu" role was pinned. In the new installation, "postgres" is pinned
and "ubuntu" won't be.

I think the checks that are actually needed here are (1) bootstrap
superusers are named the same, and (2) there are no roles other than the
bootstrap superuser in the new cluster.

You are right that it is more complex than I stated, but given the
limited feedback I got on the pg_upgrade/plplython, I figured people
didn't want to hear the details. Here they are:

There are three failure modes for pg_upgrade:

1. check failure
2. schema restore failure
3. silent failure/corruption

Of course, the later items are worse than the earlier ones. The
reporter got a "schema restore failure" while still following the
pg_upgrade instructions. My initial patch changed that #2 error to a #1
error. Tom is right that creating users in the new cluster (against
instructions), can still generate a #2 error if a new/old pg_authid.oid
match, and they are not the install user, but seeing that is something
that is against the instructions, I was going to leave that as a #2.

However, since Tom feels we should check that and make it a #1 failure,
I have added that test to the attached patch.

--
Bruce Momjian <bruce@momjian.us> http://momjian.us
EnterpriseDB http://enterprisedb.com

+ It's impossible for everything to be true. +

Attachments:

pg_upgrade.difftext/x-diff; charset=us-asciiDownload
diff --git a/contrib/pg_upgrade/check.c b/contrib/pg_upgrade/check.c
new file mode 100644
index d226f00..9f3dcda
*** a/contrib/pg_upgrade/check.c
--- b/contrib/pg_upgrade/check.c
*************** check_new_cluster(void)
*** 138,144 ****
  	 *	We don't restore our own user, so both clusters must match have
  	 *	matching install-user oids.
  	 */
! 	if (old_cluster.install_user_oid != new_cluster.install_user_oid)
  		pg_log(PG_FATAL,
  		"Old and new cluster install users have different values for pg_authid.oid.\n");
  
--- 138,144 ----
  	 *	We don't restore our own user, so both clusters must match have
  	 *	matching install-user oids.
  	 */
! 	if (old_cluster.install_role_oid != new_cluster.install_role_oid)
  		pg_log(PG_FATAL,
  		"Old and new cluster install users have different values for pg_authid.oid.\n");
  
*************** check_new_cluster(void)
*** 147,153 ****
  	 *	defined users might match users defined in the old cluster and
  	 *	generate an error during pg_dump restore.
  	 */
! 	if (new_cluster.user_count != 1)
  		pg_log(PG_FATAL, "Only the install user can be defined in the new cluster.\n");
      
  	check_for_prepared_transactions(&new_cluster);
--- 147,153 ----
  	 *	defined users might match users defined in the old cluster and
  	 *	generate an error during pg_dump restore.
  	 */
! 	if (new_cluster.role_count != 1)
  		pg_log(PG_FATAL, "Only the install user can be defined in the new cluster.\n");
      
  	check_for_prepared_transactions(&new_cluster);
*************** check_is_super_user(ClusterInfo *cluster
*** 618,624 ****
  		pg_log(PG_FATAL, "database user \"%s\" is not a superuser\n",
  			   os_info.user);
  
! 	cluster->install_user_oid = atooid(PQgetvalue(res, 0, 1));
  
  	PQclear(res);
  
--- 618,624 ----
  		pg_log(PG_FATAL, "database user \"%s\" is not a superuser\n",
  			   os_info.user);
  
! 	cluster->install_role_oid = atooid(PQgetvalue(res, 0, 1));
  
  	PQclear(res);
  
*************** check_is_super_user(ClusterInfo *cluster
*** 629,635 ****
  	if (PQntuples(res) != 1)
  		pg_log(PG_FATAL, "could not determine the number of users\n");
  
! 	cluster->user_count = atoi(PQgetvalue(res, 0, 0));
  
  	PQclear(res);
  
--- 629,635 ----
  	if (PQntuples(res) != 1)
  		pg_log(PG_FATAL, "could not determine the number of users\n");
  
! 	cluster->role_count = atoi(PQgetvalue(res, 0, 0));
  
  	PQclear(res);
  
diff --git a/contrib/pg_upgrade/pg_upgrade.h b/contrib/pg_upgrade/pg_upgrade.h
new file mode 100644
index 528eea7..1d7f56c
*** a/contrib/pg_upgrade/pg_upgrade.h
--- b/contrib/pg_upgrade/pg_upgrade.h
*************** typedef struct
*** 230,237 ****
  	char		major_version_str[64];	/* string PG_VERSION of cluster */
  	uint32		bin_version;	/* version returned from pg_ctl */
  	Oid			pg_database_oid;	/* OID of pg_database relation */
! 	Oid			install_user_oid;	/* OID of connected user */
! 	Oid			user_count;		/* number of users defined in the cluster */
  	char	   *tablespace_suffix;		/* directory specification */
  } ClusterInfo;
  
--- 230,237 ----
  	char		major_version_str[64];	/* string PG_VERSION of cluster */
  	uint32		bin_version;	/* version returned from pg_ctl */
  	Oid			pg_database_oid;	/* OID of pg_database relation */
! 	Oid			install_role_oid;	/* OID of connected role */
! 	Oid			role_count;			/* number of roles defined in the cluster */
  	char	   *tablespace_suffix;		/* directory specification */
  } ClusterInfo;
  
diff --git a/contrib/pg_upgrade/check.c b/contrib/pg_upgrade/check.c
new file mode 100644
index 2669c09..d226f00
*** a/contrib/pg_upgrade/check.c
--- b/contrib/pg_upgrade/check.c
*************** check_new_cluster(void)
*** 121,137 ****
  {
  	set_locale_and_encoding(&new_cluster);
  
  	get_db_and_rel_infos(&new_cluster);
  
  	check_new_cluster_is_empty();
- 	check_for_prepared_transactions(&new_cluster);
  
  	check_loadable_libraries();
  
- 	check_locale_and_encoding(&old_cluster.controldata, &new_cluster.controldata);
- 
  	if (user_opts.transfer_mode == TRANSFER_MODE_LINK)
  		check_hard_link();
  }
  
  
--- 121,156 ----
  {
  	set_locale_and_encoding(&new_cluster);
  
+ 	check_locale_and_encoding(&old_cluster.controldata, &new_cluster.controldata);
+ 
  	get_db_and_rel_infos(&new_cluster);
  
  	check_new_cluster_is_empty();
  
  	check_loadable_libraries();
  
  	if (user_opts.transfer_mode == TRANSFER_MODE_LINK)
  		check_hard_link();
+ 
+ 	check_is_super_user(&new_cluster);
+ 
+ 	/*
+ 	 *	We don't restore our own user, so both clusters must match have
+ 	 *	matching install-user oids.
+ 	 */
+ 	if (old_cluster.install_user_oid != new_cluster.install_user_oid)
+ 		pg_log(PG_FATAL,
+ 		"Old and new cluster install users have different values for pg_authid.oid.\n");
+ 
+ 	/*
+ 	 *	We only allow the install user in the new cluster because other
+ 	 *	defined users might match users defined in the old cluster and
+ 	 *	generate an error during pg_dump restore.
+ 	 */
+ 	if (new_cluster.user_count != 1)
+ 		pg_log(PG_FATAL, "Only the install user can be defined in the new cluster.\n");
+     
+ 	check_for_prepared_transactions(&new_cluster);
  }
  
  
*************** create_script_for_old_cluster_deletion(c
*** 579,585 ****
  /*
   *	check_is_super_user()
   *
!  *	Make sure we are the super-user.
   */
  static void
  check_is_super_user(ClusterInfo *cluster)
--- 598,604 ----
  /*
   *	check_is_super_user()
   *
!  *	Check we are superuser, and out user id and user count
   */
  static void
  check_is_super_user(ClusterInfo *cluster)
*************** check_is_super_user(ClusterInfo *cluster
*** 591,597 ****
  
  	/* Can't use pg_authid because only superusers can view it. */
  	res = executeQueryOrDie(conn,
! 							"SELECT rolsuper "
  							"FROM pg_catalog.pg_roles "
  							"WHERE rolname = current_user");
  
--- 610,616 ----
  
  	/* Can't use pg_authid because only superusers can view it. */
  	res = executeQueryOrDie(conn,
! 							"SELECT rolsuper, oid "
  							"FROM pg_catalog.pg_roles "
  							"WHERE rolname = current_user");
  
*************** check_is_super_user(ClusterInfo *cluster
*** 599,604 ****
--- 618,636 ----
  		pg_log(PG_FATAL, "database user \"%s\" is not a superuser\n",
  			   os_info.user);
  
+ 	cluster->install_user_oid = atooid(PQgetvalue(res, 0, 1));
+ 
+ 	PQclear(res);
+ 
+ 	res = executeQueryOrDie(conn,
+ 							"SELECT COUNT(*) "
+ 							"FROM pg_catalog.pg_roles ");
+ 
+ 	if (PQntuples(res) != 1)
+ 		pg_log(PG_FATAL, "could not determine the number of users\n");
+ 
+ 	cluster->user_count = atoi(PQgetvalue(res, 0, 0));
+ 
  	PQclear(res);
  
  	PQfinish(conn);
diff --git a/contrib/pg_upgrade/pg_upgrade.c b/contrib/pg_upgrade/pg_upgrade.c
new file mode 100644
index 465ecdd..ba81823
*** a/contrib/pg_upgrade/pg_upgrade.c
--- b/contrib/pg_upgrade/pg_upgrade.c
***************
*** 29,35 ****
   *	We control all assignments of pg_enum.oid because these oids are stored
   *	in user tables as enum values.
   *
!  *	We control all assignments of pg_auth.oid because these oids are stored
   *	in pg_largeobject_metadata.
   */
  
--- 29,35 ----
   *	We control all assignments of pg_enum.oid because these oids are stored
   *	in user tables as enum values.
   *
!  *	We control all assignments of pg_authid.oid because these oids are stored
   *	in pg_largeobject_metadata.
   */
  
diff --git a/contrib/pg_upgrade/pg_upgrade.h b/contrib/pg_upgrade/pg_upgrade.h
new file mode 100644
index 26aa7bb..528eea7
*** a/contrib/pg_upgrade/pg_upgrade.h
--- b/contrib/pg_upgrade/pg_upgrade.h
*************** typedef struct
*** 230,235 ****
--- 230,237 ----
  	char		major_version_str[64];	/* string PG_VERSION of cluster */
  	uint32		bin_version;	/* version returned from pg_ctl */
  	Oid			pg_database_oid;	/* OID of pg_database relation */
+ 	Oid			install_user_oid;	/* OID of connected user */
+ 	Oid			user_count;		/* number of users defined in the cluster */
  	char	   *tablespace_suffix;		/* directory specification */
  } ClusterInfo;
  
#9Bruce Momjian
bruce@momjian.us
In reply to: Bruce Momjian (#8)
Re: Re: [GENERAL] pg_upgrade from 9.0.7 to 9.1.3: duplicate key pg_authid_oid_index

On Mon, Jun 04, 2012 at 10:16:45AM -0400, Bruce Momjian wrote:

I think the checks that are actually needed here are (1) bootstrap
superusers are named the same, and (2) there are no roles other than the
bootstrap superuser in the new cluster.

You are right that it is more complex than I stated, but given the
limited feedback I got on the pg_upgrade/plplython, I figured people
didn't want to hear the details. Here they are:

There are three failure modes for pg_upgrade:

1. check failure
2. schema restore failure
3. silent failure/corruption

Of course, the later items are worse than the earlier ones. The
reporter got a "schema restore failure" while still following the
pg_upgrade instructions. My initial patch changed that #2 error to a #1
error. Tom is right that creating users in the new cluster (against
instructions), can still generate a #2 error if a new/old pg_authid.oid
match, and they are not the install user, but seeing that is something
that is against the instructions, I was going to leave that as a #2.

Applied and back-patched to Postgres 9.1.

--
Bruce Momjian <bruce@momjian.us> http://momjian.us
EnterpriseDB http://enterprisedb.com

+ It's impossible for everything to be true. +