Re: [PERFORM] Seeking performance advice and explanation for high I/O on 8.3

2009-09-04 Thread Magnus Hagander
On Fri, Sep 4, 2009 at 08:54, Scott Otis wrote:
> Robert Haas :
>
>> Do you by any chance have a bazillion databases in this cluster?  Can
>> you do these?
>
>> select sum(1) from pg_database;
>
> 1555

Note that there are two features in 8.4 specifically designed to deal
with the situation where you have lots of databases and/or lots of
tables (depending on how many tables you have in each database, this
would definitely qualify). They both deal with the "pgstats temp file
too large generating i/o issue".

First, it will only write the file when it's actually necessary - 8.3
and earlier will always write it.

Second, you will have the ability to move the location of the file to
a different filesystem - specifically intended so that you can move it
off to a ramdrive.

Could be worth investigating an upgrade for this issue alone. The fact
that you don't have to struggle with tuning the FSM in 8.4 is another
thing that makes life a *lot* easier in this kind of installations.


-- 
 Magnus Hagander
 Me: http://www.hagander.net/
 Work: http://www.redpill-linpro.com/

-- 
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance


[PERFORM] Planner question - "bit" data types

2009-09-04 Thread Karl Denninger
Does the planner know how to use indices to optimize these queries?

For reference, I was having SEVERE performance problems with the
following comparison in an SQL statement where "mask" was an integer:

"select ... from  where .. and (permission & mask = permission)"

This resulted in the planner deciding to run a nested loop and
extraordinarily poor performance.

I can probably recode the application to use a field of type "bit(32)"
and either cast to an integer or have the code do the conversion
internally (its just a shift eh?)

The question is whether the above statement will be reasonably planned
if "mask" is a bit type.


-- Karl Denninger
<>
-- 
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance


Re: [PERFORM] Seeking performance advice and explanation for high I/O on 8.3

2009-09-04 Thread Scott Otis
So is there anything I can do in 8.3 to help this?  I have tried setting ' 
track_activities', 'track_counts' and 'autovacuum' to 'off' (which has reduced 
CPU and I/O a bit) - but the stats collector process is still using up a good 
deal of CPU and I/O - is there any way to turn stats collecting completely off?

Scott Otis
CIO / Lead Developer
Intand
www.intand.com


-Original Message-
From: Magnus Hagander [mailto:mag...@hagander.net] 
Sent: Friday, September 04, 2009 1:19 AM
To: Scott Otis
Cc: Robert Haas; Ivan Voras; pgsql-performance@postgresql.org
Subject: Re: [PERFORM] Seeking performance advice and explanation for high I/O 
on 8.3

On Fri, Sep 4, 2009 at 08:54, Scott Otis wrote:
> Robert Haas :
>
>> Do you by any chance have a bazillion databases in this cluster?  Can 
>> you do these?
>
>> select sum(1) from pg_database;
>
> 1555

Note that there are two features in 8.4 specifically designed to deal with the 
situation where you have lots of databases and/or lots of tables (depending on 
how many tables you have in each database, this would definitely qualify). They 
both deal with the "pgstats temp file too large generating i/o issue".

First, it will only write the file when it's actually necessary - 8.3 and 
earlier will always write it.

Second, you will have the ability to move the location of the file to a 
different filesystem - specifically intended so that you can move it off to a 
ramdrive.

Could be worth investigating an upgrade for this issue alone. The fact that you 
don't have to struggle with tuning the FSM in 8.4 is another thing that makes 
life a *lot* easier in this kind of installations.


--
 Magnus Hagander
 Me: http://www.hagander.net/
 Work: http://www.redpill-linpro.com/

-- 
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance


Re: [PERFORM] Seeking performance advice and explanation for high I/O on 8.3

2009-09-04 Thread Kevin Grittner
"Scott Otis"  wrote:
 
> So is there anything I can do in 8.3 to help this?  I have tried
> setting 'track_activities', 'track_counts' and 'autovacuum' to 'off'
> (which has reduced CPU and I/O a bit)
 
You're going to regret that very soon, unless you are *very* sure you
have adequate manual vacuums scheduled.
 
http://www.postgresql.org/docs/8.3/interactive/routine-vacuuming.html
 
-Kevin

-- 
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance


Re: [PERFORM] Planner question - "bit" data types

2009-09-04 Thread Josh Berkus
Karl,

> For reference, I was having SEVERE performance problems with the
> following comparison in an SQL statement where "mask" was an integer:
> 
> "select ... from  where .. and (permission & mask = permission)"

AFAIK, the only way to use an index on these queries is through
expression indexes.  That's why a lot of folks use INTARRAY instead; it
comes with a GIN index type.

It would probably be possible to create a new index type using GiST or
GIN which indexed bitstrings automatically, but I don't know that anyone
has done it yet.

Changing your integer to a bitstring will not, to my knowledge, improve
this.

-- 
Josh Berkus
PostgreSQL Experts Inc.
www.pgexperts.com

-- 
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance