Thread: Set maintenance work mem for pg_restore

Set maintenance work mem for pg_restore

From
Deron
Date:
I see a lot of suggestions to increase maintenance work mem if running pg_restore.  This is to help with the index creation and initial sort from what I understand.  A few tests I ran does show this helps.
Does anyone know if there is a way to only "temporarily" set this setting?  I have some DBs that are bloated and I have a script to run off hours (I don't like working late).  This uses pg_dump and pg_restore to recover the disk space.  I found that this is usually faster than 'vacuum full', and is useful in some cases.
 
I know I can set this for my current session dynamically "set maintenance_work_mem = xxxxx", but it seems that the only way I can do this for pg_restore is to update the configuration, reload and then change it back when the script completes and reload again.
 
Thanks
 
Deron
 

Re: Set maintenance work mem for pg_restore

From
Alvaro Herrera
Date:
Deron escribió:
> I see a lot of suggestions to increase maintenance work mem if running
> pg_restore.  This is to help with the index creation and initial sort from
> what I understand.  A few tests I ran does show this helps.
> Does anyone know if there is a way to only "temporarily" set this setting?
> I have some DBs that are bloated and I have a script to run off hours (I
> don't like working late).  This uses pg_dump and pg_restore to recover the
> disk space.  I found that this is usually faster than 'vacuum full', and is
> useful in some cases.

You can specify it via PGOPTIONS:

$ PGOPTIONS='-c maintenance_work_mem=1GB' psql
Welcome to psql 8.2.5, the PostgreSQL interactive terminal.

Type:  \copyright for distribution terms
       \h for help with SQL commands
       \? for help with psql commands
       \g or terminate with semicolon to execute query
       \q to quit

alvherre=# show maintenance_work_mem ;
 maintenance_work_mem
----------------------
 1GB
(1 row)

alvherre=# \q

$ psql
Welcome to psql 8.2.5, the PostgreSQL interactive terminal.

Type:  \copyright for distribution terms
       \h for help with SQL commands
       \? for help with psql commands
       \g or terminate with semicolon to execute query
       \q to quit

alvherre=# show maintenance_work_mem ;
 maintenance_work_mem
----------------------
 16MB
(1 row)



--
Alvaro Herrera                                http://www.CommandPrompt.com/
PostgreSQL Replication, Consulting, Custom Development, 24x7 support

Re: Set maintenance work mem for pg_restore

From
"Scott Marlowe"
Date:
On Dec 18, 2007 2:30 PM, Deron <fecastle@gmail.com> wrote:
> I see a lot of suggestions to increase maintenance work mem if running
> pg_restore.  This is to help with the index creation and initial sort from
> what I understand.  A few tests I ran does show this helps.
> Does anyone know if there is a way to only "temporarily" set this setting?
> I have some DBs that are bloated and I have a script to run off hours (I
> don't like working late).  This uses pg_dump and pg_restore to recover the
> disk space.  I found that this is usually faster than 'vacuum full', and is
> useful in some cases.
>
> I know I can set this for my current session dynamically "set
> maintenance_work_mem = xxxxx", but it seems that the only way I can do this
> for pg_restore is to update the configuration, reload and then change it
> back when the script completes and reload again.

If you use psql to restore, you can just add the set
maintenance_work_mem = xxx at the top of the file.

Also you can do it by creating a "special" superuser and altering that
user to inherit this new setting:

create user bubba superuser;
alter user bubba set maintenance_work_mem TO 512000;

then just connect as that user to run your restores or what not.  You
can also set it for a non-super user, or a database as well.

Re: Set maintenance work mem for pg_restore

From
Tom Lane
Date:
Deron <fecastle@gmail.com> writes:
> Does anyone know if there is a way to only "temporarily" set this setting?

Aside from the specific answers already given, the general answer is to
read
http://www.postgresql.org/docs/8.2/static/config-setting.html
which enumerates all (most?) of the many ways you can set configuration
parameters.

            regards, tom lane

Re: Set maintenance work mem for pg_restore

From
Deron
Date:
Thanks for this and the other suggestions.  This is exactly what I was looking for.
 
Deron


 
On 12/18/07, Alvaro Herrera <alvherre@commandprompt.com> wrote:
Deron escribió:
> I see a lot of suggestions to increase maintenance work mem if running
> pg_restore.  This is to help with the index creation and initial sort from
> what I understand.  A few tests I ran does show this helps.
> Does anyone know if there is a way to only "temporarily" set this setting?
> I have some DBs that are bloated and I have a script to run off hours (I
> don't like working late).  This uses pg_dump and pg_restore to recover the
> disk space.  I found that this is usually faster than 'vacuum full', and is
> useful in some cases.

You can specify it via PGOPTIONS:

$ PGOPTIONS='-c maintenance_work_mem=1GB' psql
Welcome to psql 8.2.5, the PostgreSQL interactive terminal.

Type:  \copyright for distribution terms
      \h for help with SQL commands
      \? for help with psql commands
      \g or terminate with semicolon to execute query
      \q to quit

alvherre=# show maintenance_work_mem ;
maintenance_work_mem
----------------------
1GB
(1 row)

alvherre=# \q

$ psql
Welcome to psql 8.2.5, the PostgreSQL interactive terminal.

Type:  \copyright for distribution terms
      \h for help with SQL commands
      \? for help with psql commands
      \g or terminate with semicolon to execute query
      \q to quit

alvherre=# show maintenance_work_mem ;
maintenance_work_mem
----------------------
16MB
(1 row)



--
Alvaro Herrera                                 http://www.CommandPrompt.com/
PostgreSQL Replication, Consulting, Custom Development, 24x7 support