Thread: Parameters for PostgreSQL

Parameters for PostgreSQL

From
Jayadevan M
Date:
Hello all,
We are planning to test one of our products, which works with Oracle, on PostgreSQL.  The database size is about 100 GB. It is a product with a not-so-high load ( about 10 tps - mostly read). My doubts are about PostgreSQL settings. For Oracle, we give about 4 GB SGA (shared buffer) and 1.5 GB PGA (sum of session-specific memory). The machine configuration is
Opteron 2CPU * 4cores @ 2.3GHz  
16GB  RAM
OS Solaris10 x64

So far I have changed the following settings in postgresql.conf

shared_buffers = 2GB                    
temp_buffers = 8MB                      
work_mem = 16MB                        
maintenance_work_mem = 32MB            
wal_level = archive                    
checkpoint_segments = 10                
checkpoint_completion_target = 0.7      
archive_mode = on              
effective_cache_size = 6GB              
log_destination = 'csvlog'              
logging_collector = on                  
log_directory = '/backup/datapump/pgdata/log'              
log_filename = 'postgresql-%Y-%m-%d_%H%M%S.log'
log_rotation_age = 1d                  
client_min_messages = notice            
log_min_messages = warning              
log_min_duration_statement = 3000    

Could you please let me know the parameters I should pay attention to? Do the settings mentioned above look OK?
We are suing weblogic. Should we let weblogic manage the connection pool or try something else?

Regards,
Jayadevan






DISCLAIMER:


"The information in this e-mail and any attachment is intended only for the person to whom it is addressed and may contain confidential and/or privileged material. If you have received this e-mail in error, kindly contact the sender and destroy all copies of the original communication. IBS makes no warranty, express or implied, nor guarantees the accuracy, adequacy or completeness of the information contained in this email or any attachment and is not liable for any errors, defects, omissions, viruses or for resultant loss or damage, if any, direct or indirect."





Re: Parameters for PostgreSQL

From
Merlin Moncure
Date:
On Mon, Aug 1, 2011 at 7:09 AM, Jayadevan M
<Jayadevan.Maymala@ibsplc.com> wrote:
> Hello all,
> We are planning to test one of our products, which works with Oracle, on
> PostgreSQL.  The database size is about 100 GB. It is a product with a
> not-so-high load ( about 10 tps - mostly read). My doubts are about
> PostgreSQL settings. For Oracle, we give about 4 GB SGA (shared buffer) and
> 1.5 GB PGA (sum of session-specific memory). The machine configuration is
> Opteron 2CPU * 4cores @ 2.3GHz
> 16GB  RAM
> OS Solaris10 x64
>
> So far I have changed the following settings in postgresql.conf
>
> shared_buffers = 2GB
> temp_buffers = 8MB
> work_mem = 16MB
> maintenance_work_mem = 32MB
> wal_level = archive
> checkpoint_segments = 10
> checkpoint_completion_target = 0.7
> archive_mode = on
> effective_cache_size = 6GB
> log_destination = 'csvlog'
> logging_collector = on
> log_directory = '/backup/datapump/pgdata/log'
> log_filename = 'postgresql-%Y-%m-%d_%H%M%S.log'
> log_rotation_age = 1d
> client_min_messages = notice
> log_min_messages = warning
> log_min_duration_statement = 3000
>
> Could you please let me know the parameters I should pay attention to? Do
> the settings mentioned above look OK?

The settings above look ok.  I would consider raising
maintenance_work_mem much higher, say to 1gb. I personally don't like
the timestamp encoded into the log filename and do something much
simpler, like:
log_filename = 'postgresql-%d.log'

and set the logs to truncate on rotation.

> We are suing weblogic. Should we let weblogic manage the connection pool or
> try something else?

Don't have a experience with weblogic, but at 10 tps, it doesn't
matter a whole lot. I'd consider sticking with what you've got unless
you have a good reason to change it.

merlin

Re: Parameters for PostgreSQL

From
Craig Ringer
Date:
On 1/08/2011 8:09 PM, Jayadevan M wrote:

> The machine  configuration is
> Opteron 2CPU * 4cores @ 2.3GHz
> 16GB RAM
> OS Solaris10 x64

The most important spec has been omitted. What's the storage subsystem?
For most database workloads that's *WAY* more important than the CPUs.

It certainly will be for yours, since your 100GB database won't fit into
16GB of RAM, so you'll be doing a lot of disk I/O.

> Could you please let me know the parameters I should pay attention to?
> Do the settings mentioned above look OK?

There's nothing obviously dangerous like a giant work_mem setting.

Like Oracle, it's very much a matter of tuning to your machine and
workload. Parameters right for one workload will be less than ideal for
another. If at all possible, do some load testing with a dev instance
and tweak based on that.

The most recent book on Pg performance is Greg Smith's "PostgreSQL High
Performance" and it's had very positive comments on this list. It might
be worth a look.

> We are suing weblogic.
          ^^^^^
Best. Typo. Ever.

I hear most people who use it want to, you're just brave enough to do it :-P

> Should we let weblogic manage the connection pool
> or try something else?

In Glassfish 3.1 and JBoss 7 I let the app server manage the connection
pool. Assuming Weblogic works as well - which I'd hope - you should be
fine doing the same.

PostgreSQL doesn't have any built-in pooling or admission control - each
"connection" is also an executor backend and isn't especially cheap to
have around, so you don't want hundreds and hundreds of them.
If your app hangs on to connections from the pool for a long time, you
might land up wanting to use an external thin pooler like pgpool-II. I
wouldn't worry about anything like this unless you start getting
max_connections exceeded exceptions via your pooler, though, as it
shouldn't be an issue for most EE apps with a container-powered
connection pool.

--
Craig Ringer

POST Newspapers
276 Onslow Rd, Shenton Park
Ph: 08 9381 3088     Fax: 08 9388 2258
ABN: 50 008 917 717
http://www.postnewspapers.com.au/

Re: Parameters for PostgreSQL

From
Jayadevan M
Date:
Hello,

>The most important spec has been omitted. What's the storage subsystem?

We have storage on SAN, RAID 5.
 
> > We are suing weblogic.
>           ^^^^^
> Best. Typo. Ever.
>
> I hear most people who use it want to, you're just brave enough to do it :-P
I wish I could make a few millions that way.



Thank you for all the replies. The first step is, of course, to migrate the data. I am working with ora2pg for that. I assume creating files with 'COPY' to work as input for PostgreSQL is the right approach? We don't have many stored procedures or packages. So that part should be OK.





DISCLAIMER:


"The information in this e-mail and any attachment is intended only for the person to whom it is addressed and may contain confidential and/or privileged material. If you have received this e-mail in error, kindly contact the sender and destroy all copies of the original communication. IBS makes no warranty, express or implied, nor guarantees the accuracy, adequacy or completeness of the information contained in this email or any attachment and is not liable for any errors, defects, omissions, viruses or for resultant loss or damage, if any, direct or indirect."





Re: Parameters for PostgreSQL

From
Craig Ringer
Date:
On 04/08/11 11:42, Jayadevan M wrote:
Hello,

>The most important spec has been omitted. What's the storage subsystem?

We have storage on SAN, RAID 5.

RAID 5? That's *really* not ideal for database workloads, either Pg or Oracle, unless your RAID 5 storage backend has enough battery-backed write cache to keep huge amounts of writes in RAM and reorder them really effectively.

I hope each RAID 5 LUN is only across a few disks and is layered with RAID 1, though. RAID 5 becomes less reliable than using a single disk when used with too many HDDs, because the probability of a double-disk failure becomes greater than that of a single standalone disk failing. After being bitten by that a few times, these days I'm using RAID 6 in most cases where RAID 10 isn't practical.

In any case, "SAN" can be anything from a Linux box running an iSCSI target on top of a RAID 5 `md' software RAID volume on four 5400RPM HDDs, right up to a giant hundreds-of-fast-disks monster filer full of dedicated ASICs and great gobs of battery backed write cache DRAM. Are you able to be any more specific about what you're dealing with?

 
> > We are suing weblogic.
>           ^^^^^
> Best. Typo. Ever.
>
> I hear most people who use it want to, you're just brave enough to do it :-P
I wish I could make a few millions that way.



Thank you for all the replies. The first step is, of course, to migrate the data. I am working with ora2pg for that. I assume creating files with 'COPY' to work as input for PostgreSQL is the right approach? We don't have many stored procedures or packages. So that part should be OK.


Re: Parameters for PostgreSQL

From
Adarsh Sharma
Date:
I think RAID 10 is best among all the RAID Levels.


Thanks


Craig Ringer wrote:
On 04/08/11 11:42, Jayadevan M wrote:
Hello,

>The most important spec has been omitted. What's the storage subsystem?

We have storage on SAN, RAID 5.

RAID 5? That's *really* not ideal for database workloads, either Pg or Oracle, unless your RAID 5 storage backend has enough battery-backed write cache to keep huge amounts of writes in RAM and reorder them really effectively.

I hope each RAID 5 LUN is only across a few disks and is layered with RAID 1, though. RAID 5 becomes less reliable than using a single disk when used with too many HDDs, because the probability of a double-disk failure becomes greater than that of a single standalone disk failing. After being bitten by that a few times, these days I'm using RAID 6 in most cases where RAID 10 isn't practical.

In any case, "SAN" can be anything from a Linux box running an iSCSI target on top of a RAID 5 `md' software RAID volume on four 5400RPM HDDs, right up to a giant hundreds-of-fast-disks monster filer full of dedicated ASICs and great gobs of battery backed write cache DRAM. Are you able to be any more specific about what you're dealing with?

 
> > We are suing weblogic.
>           ^^^^^
> Best. Typo. Ever.
>
> I hear most people who use it want to, you're just brave enough to do it :-P
I wish I could make a few millions that way.



Thank you for all the replies. The first step is, of course, to migrate the data. I am working with ora2pg for that. I assume creating files with 'COPY' to work as input for PostgreSQL is the right approach? We don't have many stored procedures or packages. So that part should be OK.



Re: Parameters for PostgreSQL

From
Andy Colson
Date:

On 8/3/2011 11:03 PM, Craig Ringer wrote:
> great gobs of battery backed write cache DRAM.

Now I know what I'm asking Santa for Christmas this year!

-Andy

Re: Parameters for PostgreSQL

From
Craig Ringer
Date:
On 04/08/11 11:42, Jayadevan M wrote:
Hello,

>The most important spec has been omitted. What's the storage subsystem?

We have storage on SAN, RAID 5.

RAID 5? That's *really* not ideal for database workloads, either Pg or Oracle, unless your RAID 5 storage backend has enough battery-backed write cache to keep huge amounts of writes in RAM and reorder them really effectively.

I hope each RAID 5 LUN is only across a few disks and is layered with RAID 1, though. RAID 5 becomes less reliable than using a single disk when used with too many HDDs, because the probability of a double-disk failure becomes greater than that of a single standalone disk failing. After being bitten by that a few times, these days I'm using RAID 6 in most cases where RAID 10 isn't practical.

In any case, "SAN" can be anything from a Linux box running an iSCSI target on top of a RAID 5 `md' software RAID volume on four 5400RPM HDDs, right up to a giant hundreds-of-fast-disks monster filer full of dedicated ASICs and great gobs of battery backed write cache DRAM. Are you able to be any more specific about what you're dealing with?

 
> > We are suing weblogic.
>           ^^^^^
> Best. Typo. Ever.
>
> I hear most people who use it want to, you're just brave enough to do it :-P
I wish I could make a few millions that way.



Thank you for all the replies. The first step is, of course, to migrate the data. I am working with ora2pg for that. I assume creating files with 'COPY' to work as input for PostgreSQL is the right approach? We don't have many stored procedures or packages. So that part should be OK.