Thread: pg_dump and schema names

pg_dump and schema names

From
Bruce Momjian
Date:
pg_dump goes to great lengths not to hard-code the schema name into
commands like CREATE TABLE, instead setting the search_path before
creating the table;  these commands:
CREATE SCHEMA xx;CREATE TABLE xx.test(x int);

generates this output:
SET search_path = xx, pg_catalog;CREATE TABLE test (    x integer);

If you dump a schema and want to reload it into another schema, you
should only need to update that one search_path line.  However, later in
the dump file, we hardcode the schema name for setting the object owner:
ALTER TABLE xx.test OWNER TO postgres;

Could we use search_path here to avoid the schema designation?  I am not
sure this possible because while CREATE defaults to the first existing
schema in the search_path, I am not sure ALTER has the same behavior
because you are not _creating_ something with ALTER.

--  Bruce Momjian  <bruce@momjian.us>        http://momjian.us EnterpriseDB
http://enterprisedb.com
 + It's impossible for everything to be true. +



Re: pg_dump and schema names

From
James Sewell
Date:
I was under the impression that every command that references a relation makes use of the search path, regardless of what it is *doing*. Maybe this is different in older versions though?

I actually ran into this recently and had to remove all the xx. schema components using vi before I could run the dump to move to a different schema.

Just to be sure:

postgres=# create schema test;
CREATE SCHEMA
postgres=# set search_path to test;
SET
postgres=# create table test1(id serial);
NOTICE:  CREATE TABLE will create implicit sequence "test1_id_seq" for serial column "test1.id"
CREATE TABLE
postgres=# alter table test1 owner to postgres;
ALTER TABLE


Cheers,

James Sewell
Solutions Architect

_____________________________________


http://www.lisasoft.com/sites/lisasoft/files/u1/2013hieghtslogan_0.png

Level 2, 50 Queen St,
Melbourne, VIC, 3000

P: 03 8370 8000   F: 03 8370 8099  W: www.lisasoft.com



On Fri, Aug 9, 2013 at 2:04 PM, Bruce Momjian <bruce@momjian.us> wrote:
pg_dump goes to great lengths not to hard-code the schema name into
commands like CREATE TABLE, instead setting the search_path before
creating the table;  these commands:

        CREATE SCHEMA xx;
        CREATE TABLE xx.test(x int);

generates this output:

        SET search_path = xx, pg_catalog;
        CREATE TABLE test (
            x integer
        );

If you dump a schema and want to reload it into another schema, you
should only need to update that one search_path line.  However, later in
the dump file, we hardcode the schema name for setting the object owner:

        ALTER TABLE xx.test OWNER TO postgres;

Could we use search_path here to avoid the schema designation?  I am not
sure this possible because while CREATE defaults to the first existing
schema in the search_path, I am not sure ALTER has the same behavior
because you are not _creating_ something with ALTER.

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

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


--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers



The contents of this email are confidential and may be subject to legal or professional privilege and copyright. No representation is made that this email is free of viruses or other defects. If you have received this communication in error, you may not copy or distribute any part of it or otherwise disclose its contents to anyone. Please advise the sender of your incorrect receipt of this correspondence.
Attachment

Re: pg_dump and schema names

From
Tom Lane
Date:
Bruce Momjian <bruce@momjian.us> writes:
> pg_dump goes to great lengths not to hard-code the schema name into
> commands like CREATE TABLE, instead setting the search_path before
> creating the table;  these commands:

>     CREATE SCHEMA xx;
>     CREATE TABLE xx.test(x int);

> generates this output:

>     SET search_path = xx, pg_catalog;
>     CREATE TABLE test (
>         x integer
>     );

> If you dump a schema and want to reload it into another schema, you
> should only need to update that one search_path line.  However, later in
> the dump file, we hardcode the schema name for setting the object owner:

>     ALTER TABLE xx.test OWNER TO postgres;

> Could we use search_path here to avoid the schema designation?

Perhaps, but that's not likely to reduce the number of places you have to
edit, unless your dump is only one schema anyway.

The practical difficulties involved can be seen by reading the comments
and code for_getObjectDescription().
        regards, tom lane



Re: pg_dump and schema names

From
Bruce Momjian
Date:
On Fri, Aug  9, 2013 at 01:48:43AM -0400, Tom Lane wrote:
> Bruce Momjian <bruce@momjian.us> writes:
> > pg_dump goes to great lengths not to hard-code the schema name into
> > commands like CREATE TABLE, instead setting the search_path before
> > creating the table;  these commands:
>
> >     CREATE SCHEMA xx;
> >     CREATE TABLE xx.test(x int);
>
> > generates this output:
>
> >     SET search_path = xx, pg_catalog;
> >     CREATE TABLE test (
> >         x integer
> >     );
>
> > If you dump a schema and want to reload it into another schema, you
> > should only need to update that one search_path line.  However, later in
> > the dump file, we hardcode the schema name for setting the object owner:
>
> >     ALTER TABLE xx.test OWNER TO postgres;
>
> > Could we use search_path here to avoid the schema designation?
>
> Perhaps, but that's not likely to reduce the number of places you have to
> edit, unless your dump is only one schema anyway.
>
> The practical difficulties involved can be seen by reading the comments
> and code for _getObjectDescription().

Yes, I looked at that.    Seems _getObjectDescription() is only called
from _printTocEntry(), and that function has a call to
_selectOutputSchema() at the top, so we already know we have search_path
set to the proper schema.

The attached patch removes the unnecessary schema qualification for
ALTER OWNER, and the attached dump file show a two-schema dump that
restores just fine.

Basically, if we are going to use search_path to avoid schema
specification, we should do it in ALTER OWNER too.

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

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

Attachment

Re: pg_dump and schema names

From
Tom Lane
Date:
Bruce Momjian <bruce@momjian.us> writes:
> On Fri, Aug  9, 2013 at 01:48:43AM -0400, Tom Lane wrote:
>> The practical difficulties involved can be seen by reading the comments
>> and code for _getObjectDescription().

> Yes, I looked at that.    Seems _getObjectDescription() is only called
> from _printTocEntry(), and that function has a call to
> _selectOutputSchema() at the top, so we already know we have search_path
> set to the proper schema.

> The attached patch removes the unnecessary schema qualification for
> ALTER OWNER, and the attached dump file show a two-schema dump that
> restores just fine.

This really requires more than no attention to the comments, especially
since you just removed the only apparent reason for _getObjectDescription
to make a distinction between objects whose name includes a schema and
those that don't.
        regards, tom lane



Re: pg_dump and schema names

From
Bruce Momjian
Date:
On Fri, Aug  9, 2013 at 12:53:20PM -0400, Tom Lane wrote:
> Bruce Momjian <bruce@momjian.us> writes:
> > On Fri, Aug  9, 2013 at 01:48:43AM -0400, Tom Lane wrote:
> >> The practical difficulties involved can be seen by reading the comments
> >> and code for _getObjectDescription().
> 
> > Yes, I looked at that.    Seems _getObjectDescription() is only called
> > from _printTocEntry(), and that function has a call to
> > _selectOutputSchema() at the top, so we already know we have search_path
> > set to the proper schema.
> 
> > The attached patch removes the unnecessary schema qualification for
> > ALTER OWNER, and the attached dump file show a two-schema dump that
> > restores just fine.
> 
> This really requires more than no attention to the comments, especially
> since you just removed the only apparent reason for _getObjectDescription
> to make a distinction between objects whose name includes a schema and
> those that don't.

I am confused.  Are you saying I didn't read the comments, or that I can
now merge the schema-qualified and non-schema-qualified object sections? 

Also, this seems like dead code as there is no test for "INDEX" in the
if() block it exists in:
       /*        * Pre-7.3 pg_dump would sometimes (not always) put a fmtId'd name        * into te->tag for an index.
Thischeck is heuristic, so make its        * scope as narrow as possible.        */       if (AH->version < K_VERS_1_7
&&          te->tag[0] == '"' &&           te->tag[strlen(te->tag) - 1] == '"' &&           strcmp(type, "INDEX") == 0)
         appendPQExpBuffer(buf, "%s", te->tag);       else
 

Please advise.

--  Bruce Momjian  <bruce@momjian.us>        http://momjian.us EnterpriseDB
http://enterprisedb.com
 + It's impossible for everything to be true. +



Re: pg_dump and schema names

From
Tom Lane
Date:
Bruce Momjian <bruce@momjian.us> writes:
> On Fri, Aug  9, 2013 at 12:53:20PM -0400, Tom Lane wrote:
>> This really requires more than no attention to the comments, especially
>> since you just removed the only apparent reason for _getObjectDescription
>> to make a distinction between objects whose name includes a schema and
>> those that don't.

> I am confused.  Are you saying I didn't read the comments, or that I can
> now merge the schema-qualified and non-schema-qualified object sections? 

Well, it's certainly not immediately obvious why we shouldn't merge them.
But I would have expected the function's header comment to now explain
that the output is intentionally not schema-qualified and assumes that the
search path is set for the object's schema if any.

> Also, this seems like dead code as there is no test for "INDEX" in the
> if() block it exists in:

>         /*
>          * Pre-7.3 pg_dump would sometimes (not always) put a fmtId'd name
>          * into te->tag for an index. This check is heuristic, so make its
>          * scope as narrow as possible.
>          */
>         if (AH->version < K_VERS_1_7 &&
>             te->tag[0] == '"' &&
>             te->tag[strlen(te->tag) - 1] == '"' &&
>             strcmp(type, "INDEX") == 0)
>             appendPQExpBuffer(buf, "%s", te->tag);
>         else

Huh, yeah it is dead code, since _printTocEntry doesn't call this function
for "INDEX" objects.  And anyway I doubt anybody still cares about reading
7.2-era archive files.  No objection to removing that.
        regards, tom lane



Re: pg_dump and schema names

From
Bruce Momjian
Date:
On Fri, Aug  9, 2013 at 01:39:35PM -0400, Tom Lane wrote:
> Bruce Momjian <bruce@momjian.us> writes:
> > On Fri, Aug  9, 2013 at 12:53:20PM -0400, Tom Lane wrote:
> >> This really requires more than no attention to the comments, especially
> >> since you just removed the only apparent reason for _getObjectDescription
> >> to make a distinction between objects whose name includes a schema and
> >> those that don't.
>
> > I am confused.  Are you saying I didn't read the comments, or that I can
> > now merge the schema-qualified and non-schema-qualified object sections?
>
> Well, it's certainly not immediately obvious why we shouldn't merge them.
> But I would have expected the function's header comment to now explain
> that the output is intentionally not schema-qualified and assumes that the
> search path is set for the object's schema if any.

OK, done with the attached patch.  The dump output is unchanged.

> > Also, this seems like dead code as there is no test for "INDEX" in the
> > if() block it exists in:
>
> >         /*
> >          * Pre-7.3 pg_dump would sometimes (not always) put a fmtId'd name
> >          * into te->tag for an index. This check is heuristic, so make its
> >          * scope as narrow as possible.
> >          */
> >         if (AH->version < K_VERS_1_7 &&
> >             te->tag[0] == '"' &&
> >             te->tag[strlen(te->tag) - 1] == '"' &&
> >             strcmp(type, "INDEX") == 0)
> >             appendPQExpBuffer(buf, "%s", te->tag);
> >         else
>
> Huh, yeah it is dead code, since _printTocEntry doesn't call this function
> for "INDEX" objects.  And anyway I doubt anybody still cares about reading
> 7.2-era archive files.  No objection to removing that.

Removed.

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

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

Attachment

Re: pg_dump and schema names

From
Bruce Momjian
Date:
On Fri, Aug  9, 2013 at 02:15:31PM -0400, Bruce Momjian wrote:
> On Fri, Aug  9, 2013 at 01:39:35PM -0400, Tom Lane wrote:
> > Bruce Momjian <bruce@momjian.us> writes:
> > > On Fri, Aug  9, 2013 at 12:53:20PM -0400, Tom Lane wrote:
> > >> This really requires more than no attention to the comments, especially
> > >> since you just removed the only apparent reason for _getObjectDescription
> > >> to make a distinction between objects whose name includes a schema and
> > >> those that don't.
> > 
> > > I am confused.  Are you saying I didn't read the comments, or that I can
> > > now merge the schema-qualified and non-schema-qualified object sections? 
> > 
> > Well, it's certainly not immediately obvious why we shouldn't merge them.
> > But I would have expected the function's header comment to now explain
> > that the output is intentionally not schema-qualified and assumes that the
> > search path is set for the object's schema if any.
> 
> OK, done with the attached patch.  The dump output is unchanged.

To be honest, I never got to modifying the comments because I expected
someone to say the patch was wrong.  I also didn't expect to find dead
code in there too.

--  Bruce Momjian  <bruce@momjian.us>        http://momjian.us EnterpriseDB
http://enterprisedb.com
 + It's impossible for everything to be true. +



Re: pg_dump and schema names

From
Peter Eisentraut
Date:
On 8/9/13 12:04 AM, Bruce Momjian wrote:
> generates this output:
> 
>     SET search_path = xx, pg_catalog;
>     CREATE TABLE test (
>         x integer
>     );
> 
> If you dump a schema and want to reload it into another schema, you
> should only need to update that one search_path line.

Is anyone actually using that feature?  It doesn't seem very reliable.
You can't just change the schema name in one or two places.  You'd have
to manually inspect function source code, for example.




Re: pg_dump and schema names

From
Bruce Momjian
Date:
On Mon, Aug 12, 2013 at 12:28:26PM -0400, Peter Eisentraut wrote:
> On 8/9/13 12:04 AM, Bruce Momjian wrote:
> > generates this output:
> > 
> >     SET search_path = xx, pg_catalog;
> >     CREATE TABLE test (
> >         x integer
> >     );
> > 
> > If you dump a schema and want to reload it into another schema, you
> > should only need to update that one search_path line.
> 
> Is anyone actually using that feature?  It doesn't seem very reliable.
> You can't just change the schema name in one or two places.  You'd have
> to manually inspect function source code, for example.

True.  I think the larger issue is that we use search_path to avoid
specifying the schema name in lots of places, and SET OWNER should do
the same.  I think the schema reload case is just a side-effect.

--  Bruce Momjian  <bruce@momjian.us>        http://momjian.us EnterpriseDB
http://enterprisedb.com
 + It's impossible for everything to be true. +



Re: pg_dump and schema names

From
Bruce Momjian
Date:
On Fri, Aug  9, 2013 at 02:15:31PM -0400, Bruce Momjian wrote:
> > Well, it's certainly not immediately obvious why we shouldn't merge them.
> > But I would have expected the function's header comment to now explain
> > that the output is intentionally not schema-qualified and assumes that the
> > search path is set for the object's schema if any.
> 
> OK, done with the attached patch.  The dump output is unchanged.
> 
> > > Also, this seems like dead code as there is no test for "INDEX" in the
> > > if() block it exists in:
> > 
> > >         /*
> > >          * Pre-7.3 pg_dump would sometimes (not always) put a fmtId'd name
> > >          * into te->tag for an index. This check is heuristic, so make its
> > >          * scope as narrow as possible.
> > >          */
> > >         if (AH->version < K_VERS_1_7 &&
> > >             te->tag[0] == '"' &&
> > >             te->tag[strlen(te->tag) - 1] == '"' &&
> > >             strcmp(type, "INDEX") == 0)
> > >             appendPQExpBuffer(buf, "%s", te->tag);
> > >         else
> > 
> > Huh, yeah it is dead code, since _printTocEntry doesn't call this function
> > for "INDEX" objects.  And anyway I doubt anybody still cares about reading
> > 7.2-era archive files.  No objection to removing that.
> 
> Removed.

Patch applied.

--  Bruce Momjian  <bruce@momjian.us>        http://momjian.us EnterpriseDB
http://enterprisedb.com
 + It's impossible for everything to be true. +