Обсуждение: Slow adding Large Indexes

Поиск
Список
Период
Сортировка

Slow adding Large Indexes

От
"Thorne, Francis"
Дата:

Hi All,

I have recently moved postgres from one server to another (a newer server) and have encounter a problem I cant figure out.  I have a table (roughly 7.5GB) that gets re-created every night with fresh data,  to insert the data I run the following procedure.

Drop all indexes
Truncate Table
Insert Data
Create Indexes

The problem I have is that it takes around 15 mins to insert the data into the table which is a massive improvement from the old server but it then takes 40 mins to create two indexes one 1GB index and another that is a 2GB index this is considerably slower than on the older server.

I have had a play around with some of the settings but with no real success, in particular the maintenance_work_mem setting.  Any help on this would be greatly appreciated.  The new server is a Virtual Server running RedHat Linux,  Postgres 8.3 , 8GB of RAM with 4 x 2.66ghz.  The current settings in postgresql.conf I have are

shared_buffers = 768MB                                                                     
temp_buffers = 100MB                   
#max_prepared_transactions = 5         
work_mem = 64MB                        
maintenance_work_mem = 800MB           
#max_stack_depth = 2MB                 

# - Free Space Map -

max_fsm_pages =  2097152              
#max_fsm_relations = 1000              

# - Kernel Resource Usage -

#max_files_per_process = 1000          
#shared_preload_libraries = ''         

# - Cost-Based Vacuum Delay -

#vacuum_cost_delay = 0                 
#vacuum_cost_page_hit = 1              
#vacuum_cost_page_miss = 10            
#vacuum_cost_page_dirty = 20           
#vacuum_cost_limit = 200               

# - Background Writer -

#bgwriter_delay = 200ms               
#bgwriter_lru_maxpages = 100           
#bgwriter_lru_multiplier = 2.0         

/etc/sysctl.conf

kernel.shmmax = 4294967295
kernel.shmall = 268435456

Any help would be greatly appreciated, thanks in advance

Fran




___________________________________________________

This email is intended for the named recipient. The information contained
in it is confidential. You should not copy it for any purposes, nor
disclose its contents to any other party. If you received this email
in error, please notify the sender immediately via email, and delete
it from your computer.

Any views or opinions presented are solely those of the author and do not
necessarily represent those of the company.

Cromwell Tools Limited, PO Box 14, 65 Chartwell Drive
Wigston, Leicester LE18 1AT. Tel 0116 2888000
Registered in England and Wales, Reg No 00986161
VAT GB 115 5713 87 900
__________________________________________________

Re: Slow adding Large Indexes

От
Tom Lane
Дата:
"Thorne, Francis" <thornef@cromwell.co.uk> writes:
> The problem I have is that it takes around 15 mins to insert the data
> into the table which is a massive improvement from the old server but it
> then takes 40 mins to create two indexes one 1GB index and another that
> is a 2GB index this is considerably slower than on the older server.

If these are indexes on textual data, maybe you accidentally changed
from C locale to some other locale.  All the other ones are slower to
compare text strings, sometimes massively so.

            regards, tom lane

Re: Slow adding Large Indexes

От
"Thorne, Francis"
Дата:
 Hi Tom

Thanks for the quick response and useful information, having looked at
the current postgresql.conf file the locale settings are as follow

# These settings are initialized by initdb, but they can be changed.
lc_messages = 'en_US.UTF-8'                     # locale for system
error message
                                                # strings
lc_monetary = 'en_US.UTF-8'                     # locale for monetary
formatting
lc_numeric = 'en_US.UTF-8'                      # locale for number
formatting
lc_time = 'en_US.UTF-8'                         # locale for time
formatting

How can I go about changing these to the C locale, would a simple change
in postgresql.conf be o.k I have read that an initdb might be required ?
The postgres install is currently in use any hints on the best way to go
about doing this making sure all my other settings are maintained ?

Thanks again for your help in this matter
Fran

-----Original Message-----
From: Tom Lane [mailto:tgl@sss.pgh.pa.us]
Sent: 27 July 2009 15:00
To: Thorne, Francis
Cc: pgsql-admin@postgresql.org
Subject: Re: [ADMIN] Slow adding Large Indexes

"Thorne, Francis" <thornef@cromwell.co.uk> writes:
> The problem I have is that it takes around 15 mins to insert the data
> into the table which is a massive improvement from the old server but
it
> then takes 40 mins to create two indexes one 1GB index and another
that
> is a 2GB index this is considerably slower than on the older server.

If these are indexes on textual data, maybe you accidentally changed
from C locale to some other locale.  All the other ones are slower to
compare text strings, sometimes massively so.

            regards, tom lane

___________________________________________________

This email is intended for the named recipient. The information contained
in it is confidential.  You should not copy it for any purposes, nor
disclose its contents to any other party.  If you received this email
in error, please notify the sender immediately via email, and delete it from
your computer.

Any views or opinions presented are solely those of the author and do not
necessarily represent those of the company.

Cromwell Tools Limited, PO Box 14, 65 Chartwell Drive
Wigston, Leicester LE18 1AT. Tel 0116 2888000
Registered in England and Wales, Reg No 00986161
VAT GB 115 5713 87 900
__________________________________________________


Re: Slow adding Large Indexes

От
Tom Lane
Дата:
"Thorne, Francis" <thornef@cromwell.co.uk> writes:
> How can I go about changing these to the C locale,

dump, initdb --no-locale, reload :-(.  Note that the settings you
actually mentioned are not performance critical; it's lo_collate and
lc_ctype that count ... and those can only be set by initdb.

            regards, tom lane