Thread: Restore db

Restore db

From
Alexander Burbello
Date:
Hi folks,

My server has a daily routine to import a dump file, however its taking long time to finish it.
The original db has around 200 MB and takes 3~4 minutes to export (there are many blob fields), however it takes 4 hours to import using pg_restore.

What can I do to tune this database to speed up this restore??

My current db parameters are:
shared_buffers = 256MB
maintenance_work_mem = 32MB

Any suggestion is very welcome.
Thank you.
Alex

Re: Restore db

From
Ondrej Ivanič
Date:
Hi,

On 14 November 2011 11:09, Alexander Burbello <burbello@yahoo.com.br> wrote:
> What can I do to tune this database to speed up this restore??
> My current db parameters are:
> shared_buffers = 256MB
> maintenance_work_mem = 32MB

You should increase maintenance_work_mem as much as you can.
full_page_writes, archive_mode and auto_vacuum should be disable
during restore. Increase checkpoint_segments (for example to 64) and
set wal_buffers to 16MB. 8.4 introduced parallel restore (pg_restore
option -j <num jobs>).

Maybe you can't do anything mentioned above because it is not possible
to restart server (you can change maintenance_work_mem via PGOPTIONS)
or there is a single table to import (-j is not aplicable) -- try to
drop indexes and recreate them after import.

--
Ondrej Ivanic
(ondrej.ivanic@gmail.com)

Re: Restore db

From
Andy Colson
Date:
On 11/13/2011 06:09 PM, Alexander Burbello wrote:
> Hi folks,
>
> My server has a daily routine to import a dump file, however its taking long time to finish it.
> The original db has around 200 MB and takes 3~4 minutes to export (there are many blob fields), however it takes 4
hoursto import using pg_restore. 
>
> What can I do to tune this database to speed up this restore??
>
> My current db parameters are:
> shared_buffers = 256MB
> maintenance_work_mem = 32MB
>
> Any suggestion is very welcome.
> Thank you.
> Alex

Are you doing this over a network?

If you watch it restore with vmstat (or top) are you IO bound?  If so, temporarily turn off fsync, restore the db, then
turnit back on. 

something like:
autovacuum = off
fsync = off
synchronous_commit = off
full_page_writes = off
bgwriter_lru_maxpages = 0


On the other hand, if you are cpu bound, use the multi-core-restore-option -j.

Or use both.

> My current db parameters are:
> shared_buffers = 256MB
> maintenance_work_mem = 32MB

This is useless information without knowing anything about your computer.  If you have 512 Meg of ram its a lot
differentthan if you have 32 Gig. 


-Andy