Обсуждение: Database performance problems

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

Database performance problems

От
Renato Oliveira
Дата:

Dear all,

 

I have been using Postgres but I am not an expert on the subject.

 

I would be very grateful if someone could point to the right direction with regards this problem.

 

We have a web application written in JAVA, using jaboss as a servlet.

There are 100 connections open to the database server at any given time, apparently using hibernate.

 

We are using Postgres 8.2.4 compiled

The database size is 155GB

We have 8GB of RAM

300GB Hard disk Raid1

Everything is within a single Volume

 

Today the load average was as high as 15

 

Top result:

 

Tasks: 169 total,  30 running, 139 sleeping,   0 stopped,   0 zombie

Cpu(s): 69.6% us,  5.9% sy,  0.0% ni,  0.0% id, 24.3% wa,  0.2% hi,  0.0% si

Mem:   8251404k total,  8228428k used,    22976k free,    16296k buffers

Swap:  1052248k total,    47176k used,  1005072k free,  6664308k cached

 

I am quite sure:

1 – we do not have enough memory

2 – our disk and RAID array setup is not good enough

3 – Postgres is not setup correctly and uses an older version

4 – It is using Slony and replication which does not work.

 

I would like if anyone could help with the following:

1 – Ways of proving my thoughts

2 – Gather data evidence to prove

 

I don’t have slow query check enabled, will do after Christmas, but how can I use it to show things are not good?

 

If anyone could help me it would be very much appreciated.

 

If you need more info or details, I am very happy to give more.

 

Thank you very much

 

Best regards

 

Renato Oliveira

 

 
Renato Oliveira

e-mail: renato.oliveira@grant.co.uk
 
Tel: +44 (0)1763 260811
Fax: +44 (0)1763 262410
www.grant.co.uk
 
Grant Instruments (Cambridge) Ltd
 
Company registered in England, registration number 658133
 
Registered office address:
29 Station Road,
Shepreth,
CAMBS SG8 6GB
UK
 
 
 
 

 

P Please consider the environment before printing this email

CONFIDENTIALITY: The information in this e-mail and any attachments is confidential. It is intended only for the named recipients(s). If you are not the named recipient please notify the sender immediately and do not disclose the contents to another person or take copies.
 
VIRUSES: The contents of this e-mail or attachment(s) may contain viruses which could damage your own computer system. Whilst Grant Instruments (Cambridge) Ltd has taken every reasonable precaution to minimise this risk, we cannot accept liability for any damage which you sustain as a result of software viruses. You should therefore carry out your own virus checks before opening the attachment(s).
 
OpenXML: For information about the OpenXML file format in use within Grant Instruments please visit our website

Re: Database performance problems

От
"Joshua D. Drake"
Дата:
On Wed, 2009-12-23 at 14:45 +0000, Renato Oliveira wrote:
> Dear all,
>
>
>
> I have been using Postgres but I am not an expert on the subject.
>
>
>
> I would be very grateful if someone could point to the right direction
> with regards this problem.
>
>
>
> We have a web application written in JAVA, using jaboss as a servlet.
>
> There are 100 connections open to the database server at any given
> time, apparently using hibernate.
>
>
>
> We are using Postgres 8.2.4 compiled
>
> The database size is 155GB
>
> We have 8GB of RAM
>
> 300GB Hard disk Raid1
>
> Everything is within a single Volume
>
>
>
> Today the load average was as high as 15

Linux?
Are you using elevator=deadline?
How many spindles, what type of raid?
Are you doing proper maintenance?

Joshua D. Drake



--
PostgreSQL.org Major Contributor
Command Prompt, Inc: http://www.commandprompt.com/ - 503.667.4564
Consulting, Training, Support, Custom Development, Engineering
Respect is earned, not gained through arbitrary and repetitive use or Mr. or Sir.

Re: Database performance problems

От
"Joshua D. Drake"
Дата:
On Wed, 2009-12-23 at 14:45 +0000, Renato Oliveira wrote:
> Dear all,
>
>
>
> I have been using Postgres but I am not an expert on the subject.
>
>
>
> I would be very grateful if someone could point to the right direction
> with regards this problem.
>
>
>
> We have a web application written in JAVA, using jaboss as a servlet.
>
> There are 100 connections open to the database server at any given
> time, apparently using hibernate.
>
>
>
> We are using Postgres 8.2.4 compiled
>
> The database size is 155GB
>
> We have 8GB of RAM
>
> 300GB Hard disk Raid1
>
> Everything is within a single Volume
>
>
>
> Today the load average was as high as 15

Linux?
Are you using elevator=deadline?
How many spindles, what type of raid?
Are you doing proper maintenance?

Joshua D. Drake



--
PostgreSQL.org Major Contributor
Command Prompt, Inc: http://www.commandprompt.com/ - 503.667.4564
Consulting, Training, Support, Custom Development, Engineering
Respect is earned, not gained through arbitrary and repetitive use or Mr. or Sir.


Re: Database performance problems

От
"Kevin Grittner"
Дата:
Renato Oliveira <renato.oliveira@grant.co.uk> wrote:

> We have a web application written in JAVA, using jaboss as a
> servlet.

Is the web app on the same box as the database, or separate?

> There are 100 connections open to the database server at any given
> time

How many are typically active at peak times?  You could run
something like this as a database superuser at peak times a few
times to get a feel for it:

select count(*) from pg_stat_activity
  where current_query <> '<IDLE>';

> We are using Postgres 8.2.4 compiled

You're missing two years and eight months of fixes for 8.2.

http://www.postgresql.org/support/versioning

> The database size is 155GB

Any idea how much of that is "active" -- in the sense of being
frequently referenced versus more-or-less archival?

> 300GB Hard disk Raid1

Two spindles is rather small for a database of that size.

> Today the load average was as high as 15

On how many CPUs?

> Top result:

It would be more useful to run vmstat 1 or maybe even iostat 1 at
peak times and capture a view of activity over time.  The memory
information from top isn't always that reliable.

> 1 - we do not have enough memory

More RAM would probably improve performance; hard to tell by how
much without more information.

> 2 - our disk and RAID array setup is not good enough

More spindles would probably improve performance; hard to tell by
how much without more information.

> 3 - Postgres is not setup correctly and uses an older version

Version upgrade would almost certainly help.  For configuration,
could you strip all comments and blank lines from your
postgresql.conf file and show it?

> 4 - It is using Slony and replication which does not work.

Sorry, I don't know Slony....

-Kevin

Re: Database performance problems

От
Scott Marlowe
Дата:
On Wed, Dec 23, 2009 at 7:45 AM, Renato Oliveira
<renato.oliveira@grant.co.uk> wrote:
> There are 100 connections open to the database server at any given time,
> apparently using hibernate.
>
> We are using Postgres 8.2.4 compiled

Update to 8.2.latest at your earliest chance.

> The database size is 155GB
> We have 8GB of RAM
> 300GB Hard disk Raid1
> Everything is within a single Volume
> Today the load average was as high as 15
>
> Top result:
> Tasks: 169 total,  30 running, 139 sleeping,   0 stopped,   0 zombie
> Cpu(s): 69.6% us,  5.9% sy,  0.0% ni,  0.0% id, 24.3% wa,  0.2% hi,  0.0% si
> Mem:   8251404k total,  8228428k used,    22976k free,    16296k buffers
> Swap:  1052248k total,    47176k used,  1005072k free,  6664308k cached

So, 6.6G of kernel cache, so you're not starving your machine of memory.

24.3% wait means that you've got 1 out of 4 cores waiting on IO all
the time (assuming you've got a quad core machine here)

> I am quite sure:
> 1 – we do not have enough memory

Given how much is being used for kernel cache you're probably ok.  You
could likely increase shared_buffers and work_mem and
maintenance_work_mem a bit each and use some more for the db instead
of letting the kernel have it all.  Generally 1/4 mem to
shared_buffers is reasonable on smaller memory machines.

> 2 – our disk and RAID array setup is not good enough

Hard to be sure.  What do

iostat -x 60
AND
vmstat 60

say after running for a few minutes?

> 3 – Postgres is not setup correctly and uses an older version

Not real old, but it is not up to date on security / bug fixes.

> 4 – It is using Slony and replication which does not work.

Slony is a rather complex piece of software.  If you don't need it's
extra features and such, londiste from skype may be a better choice.

> I would like if anyone could help with the following:
>
> 1 – Ways of proving my thoughts
> 2 – Gather data evidence to prove

vmstat, iostat, explain analyze <yourqueryhere>