Thread: sql performance and cache

sql performance and cache

From
"Chris Faulkner"
Date:
Hello all

I have two very similar queries which I need to execute. They both have
exactly the same from / where conditions. When I execute the first, it takes
about 16 seconds. The second is executed almost immediately after, it takes
13 seconds. In short, I'd like to know why the query result isn't being
cached and any ideas on how to improve the execution.

The first query attempts to find the maximum size of an array in the result
set- the field is called "level". IT contains anything between 1 and 10
integers. I just need to know what the largest size is. I do this to find
out the maximum size of the "level" array.

"max(replace(split_part(array_dims(level),':',2),']','')::int)"

I know this is big and ugly but is there any better way of doing it ?

The second query just returns the result set - it has exactly the same
FROM/Where clause.

OK - so I could execute the query once, and get the maximum size of the
array and the result set in one. I know what I am doing is less than optimal
but I had expected the query results to be cached. So the second execution
would be very quick. So why aren't they ? I have increased my cache size -
shared_buffers is 2000 and I have doubled the default max_fsm... settings
(although I am not sure what they do). sort_mem is 8192.

The from / where is

FROM oscar_node N, oscar_point P
where N."GEOM_ID_OF_POINT" = P."POINT_ID"
and N."TILE_REF" = P."TILE_REF"
and N."TILE_REF" in ('TQ27NE','TQ28SE','TQ37NW','TQ38SW')
and P."TILE_REF" in ('TQ27NE','TQ28SE','TQ37NW','TQ38SW')
and P."FEAT_CODE" = 3500
and P.wkb_geometry && GeometryFromText('BOX3D(529540.0 179658.88,530540.0
180307.12)'::box3d,-1)

oscar_node and oscar_point both have about 3m rows. PK on oscar_node is
composite of "TILE_REF" and "NODE_ID". PK on oscar_point is "TILE_REF" and
"POINT_ID". The tables are indexed on feat_code and I have an index on
wkb_geometry. (This is a GIST index). I have increased the statistics size
and done the analyze command.

Here is my explain plan

 Nested Loop  (cost=0.00..147.11 rows=1 width=148)
   Join Filter: ("inner"."GEOM_ID_OF_POINT" = "outer"."POINT_ID")
   ->  Index Scan using gidx_oscar_point on oscar_point p  (cost=0.00..61.34
rows=1 width=57)
         Index Cond: (wkb_geometry && 'SRID=-1;BOX3D(529540 179658.88
0,530540 180307.12 0)'::geometry)
         Filter: ((("TILE_REF" = 'TQ27NE'::bpchar) OR ("TILE_REF" =
'TQ28SE'::bpchar) OR ("TILE_REF" = 'TQ37NW'::bpchar) OR ("TILE_REF" =
'TQ38SW'::bpchar)) AND ("FEAT_CODE" = 3500))
   ->  Index Scan using idx_on_tile_ref on oscar_node n  (cost=0.00..85.74
rows=2 width=91)
         Index Cond: (n."TILE_REF" = "outer"."TILE_REF")
         Filter: (("TILE_REF" = 'TQ27NE'::bpchar) OR ("TILE_REF" =
'TQ28SE'::bpchar) OR ("TILE_REF" = 'TQ37NW'::bpchar) OR ("TILE_REF" =
'TQ38SW'::bpchar))


I am seeing this message in my logs.

"bt_fixroot: not valid old root page"

Maybe this is relevant to my performance problems.

I know this has been a long message but I would really appreciate any
performance tips.

Thanks


Chris



Re: sql performance and cache

From
Christopher Kings-Lynne
Date:
> I have two very similar queries which I need to execute. They both have
> exactly the same from / where conditions. When I execute the first, it takes
> about 16 seconds. The second is executed almost immediately after, it takes
> 13 seconds. In short, I'd like to know why the query result isn't being
> cached and any ideas on how to improve the execution.

<snip>

> OK - so I could execute the query once, and get the maximum size of the
> array and the result set in one. I know what I am doing is less than optimal
> but I had expected the query results to be cached. So the second execution
> would be very quick. So why aren't they ? I have increased my cache size -
> shared_buffers is 2000 and I have doubled the default max_fsm... settings
> (although I am not sure what they do). sort_mem is 8192.

PostgreSQL does not have, and has never had a query cache - so nothing
you do is going to make that second query faster.

Perhaps you are confusing it with the MySQL query cache?

Chris


Re: sql performance and cache

From
Christopher Kings-Lynne
Date:
> PostgreSQL does not have, and has never had a query cache - so nothing
> you do is going to make that second query faster.

Let me clarify that.  PostgreSQL will of course cache the disk pages
used in getting the data for your query, which is why the second time
you run it, it is 3 seconds faster.

However, it does not cache the _results_ of the query.  Each time you
run it, it will be fully re-evaluated.

The btree error you give is bad and I'm sure the more experienced list
members will want you to dig into it for them.

Chris



Re: [SQL] sql performance and cache

From
Richard Huxton
Date:
On Saturday 11 October 2003 10:43, Chris Faulkner wrote:
> Hello all
>
> I have two very similar queries which I need to execute. They both have
> exactly the same from / where conditions. When I execute the first, it
> takes about 16 seconds. The second is executed almost immediately after, it
> takes 13 seconds. In short, I'd like to know why the query result isn't
> being cached and any ideas on how to improve the execution.

The short answer is that PG doesn't cache query results. The only way it could
do so safely is to lock all tables you access to make sure that no other
process changes them. That would effectively turn PG into a single-user DB in
short notice.

> The first query attempts to find the maximum size of an array in the result
> set- the field is called "level". IT contains anything between 1 and 10
> integers. I just need to know what the largest size is. I do this to find
> out the maximum size of the "level" array.
>
> "max(replace(split_part(array_dims(level),':',2),']','')::int)"
>
> I know this is big and ugly but is there any better way of doing it ?
>
> The second query just returns the result set - it has exactly the same
> FROM/Where clause.

I assume these two queries are linked? If you rely on the max size being
unchanged and have more than one process using the database, you should make
sure you lock the rows in question.

> OK - so I could execute the query once, and get the maximum size of the
> array and the result set in one. I know what I am doing is less than
> optimal but I had expected the query results to be cached. So the second
> execution would be very quick. So why aren't they ? I have increased my
> cache size - shared_buffers is 2000 and I have doubled the default
> max_fsm... settings (although I am not sure what they do). sort_mem is
> 8192.

PG will cache the underlying data, but not the results. The values you are
changing are used to hold table/index rows etc. This means the second query
shouldn't need to access the disk if the rows it requires are cached.

There is a discussion of the postgresql.conf file and how to tune it at:
  http://www.varlena.com/varlena/GeneralBits/Tidbits/index.php

Given the explain attached, 16 secs seems slow. Could you post an EXPLAIN
ANALYSE of either/both queries to the performance list. I'd drop the sql list
when we're just talking about performance.
--
  Richard Huxton
  Archonet Ltd

Re: [SQL] sql performance and cache

From
"Chris Faulkner"
Date:
Hello

Thanks for the reply.

> The short answer is that PG doesn't cache query results. The only
> way it could
> do so safely is to lock all tables you access to make sure that no other
> process changes them. That would effectively turn PG into a
> single-user DB in
> short notice.

I am not sure I agree with you. I have done similar things with Oracle and
found that the second query will execute much more quickly than the first.
It could be made to work in at least two scenarios

- as a user/application perspective - you accept that the result might not
be up-to-date and take what comes back. This would be acceptable in my case
because I know that the tables will not change.
OR
- the database could cache the result set. If some of the data is changed by
another query or session, then the database flushes the result set out of
the cache.

> I assume these two queries are linked? If you rely on the max size being
> unchanged and have more than one process using the database, you
> should make
> sure you lock the rows in question.

I can rely on the max size remaining the same. As I mentioned above, the
tables are entirely read only. The data will not be updated or deleted by
anyone - I don't need to worry about that. The data will be updated en masse
once every 3 months.

> There is a discussion of the postgresql.conf file and how to tune it at:
>   http://www.varlena.com/varlena/GeneralBits/Tidbits/index.php

Thanks for that.

> Given the explain attached, 16 secs seems slow. Could you post an EXPLAIN
> ANALYSE of either/both queries to the performance list. I'd drop
> the sql list
> when we're just talking about performance.

To be honest, my main concern was about the cache. If the second one could
use a cache amd execute in 2 seconds, that would be better that reducing the
execution of each individual query by 30% or so.

Thanks for the offer of help on this one. explain analyze gives me the same
as the last message - did you want verbose ?

 Nested Loop  (cost=0.00..147.11 rows=1 width=148) (actual
time=84.00..12323.00 rows=67 loops=1)
   Join Filter: ("inner"."GEOM_ID_OF_POINT" = "outer"."POINT_ID")
   ->  Index Scan using gidx_oscar_point on oscar_point p  (cost=0.00..61.34
rows=1 width=57) (actual time=0.00..9.00 rows=67 loops=1)
         Index Cond: (wkb_geometry && 'SRID=-1;BOX3D(529540 179658.88
0,530540 1
80307.12 0)'::geometry)
         Filter: ((("TILE_REF" = 'TQ27NE'::bpchar) OR ("TILE_REF" =
'TQ28SE'::bp
char) OR ("TILE_REF" = 'TQ37NW'::bpchar) OR ("TILE_REF" = 'TQ38SW'::bpchar))
AND
 ("FEAT_CODE" = 3500))
   ->  Index Scan using idx_on_tile_ref on oscar_node n  (cost=0.00..85.74
rows=2 width=91) (actual time=0.06..150.07 rows=4797 loops=67)
         Index Cond: (n."TILE_REF" = "outer"."TILE_REF")
         Filter: (("TILE_REF" = 'TQ27NE'::bpchar) OR ("TILE_REF" =
'TQ28SE'::bpchar) OR ("TILE_REF" = 'TQ37NW'::bpchar) OR ("TILE_REF" =
'TQ38SW'::bpchar))
 Total runtime: 12325.00 msec
(9 rows)

Thanks


Chris



Re: [SQL] sql performance and cache

From
Christopher Kings-Lynne
Date:
>  Nested Loop  (cost=0.00..147.11 rows=1 width=148) (actual
> time=84.00..12323.00 rows=67 loops=1)

The planner estimate doesn't seem to match reality in that particular
step.  Are you sure you've run:

ANALYZE oscar_node;
ANALYZE oscar_point;

And you could even run VACUUM FULL on them just to make sure.

Does that make any difference?

Chris



Re: [SQL] sql performance and cache

From
Christopher Kings-Lynne
Date:
>  Nested Loop  (cost=0.00..147.11 rows=1 width=148) (actual
> time=84.00..12323.00 rows=67 loops=1)

The planner estimate doesn't seem to match reality in that particular
step.  Are you sure you've run:

ANALYZE oscar_node;
ANALYZE oscar_point;

And you could even run VACUUM FULL on them just to make sure.

Does that make any difference?

Chris



Re: [SQL] sql performance and cache

From
Richard Huxton
Date:
On Saturday 11 October 2003 12:12, Chris Faulkner wrote:
> Hello
>
> Thanks for the reply.
>
> > The short answer is that PG doesn't cache query results. The only
> > way it could
> > do so safely is to lock all tables you access to make sure that no other
> > process changes them. That would effectively turn PG into a
> > single-user DB in
> > short notice.
>
> I am not sure I agree with you. I have done similar things with Oracle and
> found that the second query will execute much more quickly than the first.
> It could be made to work in at least two scenarios

I'm guessing because the underlying rows and perhaps the plan are cached,
rather than the results. If you cached the results of the first query you'd
only have the max length, not your other data anyway.

[snip]

> > I assume these two queries are linked? If you rely on the max size being
> > unchanged and have more than one process using the database, you
> > should make
> > sure you lock the rows in question.
>
> I can rely on the max size remaining the same. As I mentioned above, the
> tables are entirely read only. The data will not be updated or deleted by
> anyone - I don't need to worry about that. The data will be updated en
> masse once every 3 months.

Hmm - might be worth adding a column for your array length and pre-calculating
if your data is basically static.

> > There is a discussion of the postgresql.conf file and how to tune it at:
> >   http://www.varlena.com/varlena/GeneralBits/Tidbits/index.php
>
> Thanks for that.
>
> > Given the explain attached, 16 secs seems slow. Could you post an EXPLAIN
> > ANALYSE of either/both queries to the performance list. I'd drop
> > the sql list
> > when we're just talking about performance.
>
> To be honest, my main concern was about the cache. If the second one could
> use a cache amd execute in 2 seconds, that would be better that reducing
> the execution of each individual query by 30% or so.

I'm puzzled as to why they aren't both below 2 seconds to start with - you're
not dealing with that many rows.

> Thanks for the offer of help on this one. explain analyze gives me the same
> as the last message - did you want verbose ?

Nope, this is what I need. Verbose prints pages of stuff that only the
developers would be interested in. This one actually runs the query and gives
you a second set of figures showing times.

>  Nested Loop  (cost=0.00..147.11 rows=1 width=148) (actual
> time=84.00..12323.00 rows=67 loops=1)
>    Join Filter: ("inner"."GEOM_ID_OF_POINT" = "outer"."POINT_ID")
>    ->  Index Scan using gidx_oscar_point on oscar_point p
> (cost=0.00..61.34 rows=1 width=57) (actual time=0.00..9.00 rows=67 loops=1)
>          Index Cond: (wkb_geometry && 'SRID=-1;BOX3D(529540 179658.88
> 0,530540 1
> 80307.12 0)'::geometry)
>          Filter: ((("TILE_REF" = 'TQ27NE'::bpchar) OR ("TILE_REF" =
> 'TQ28SE'::bp
> char) OR ("TILE_REF" = 'TQ37NW'::bpchar) OR ("TILE_REF" =
> 'TQ38SW'::bpchar)) AND
>  ("FEAT_CODE" = 3500))

This next bit is the issue. It's joining on TILE_REF and then filtering by
your three static values. That's taking 67 * 150ms = 10.05secs

>    ->  Index Scan using idx_on_tile_ref on oscar_node n  (cost=0.00..85.74
> rows=2 width=91) (actual time=0.06..150.07 rows=4797 loops=67)
>          Index Cond: (n."TILE_REF" = "outer"."TILE_REF")
>          Filter: (("TILE_REF" = 'TQ27NE'::bpchar) OR ("TILE_REF" =
> 'TQ28SE'::bpchar) OR ("TILE_REF" = 'TQ37NW'::bpchar) OR ("TILE_REF" =
> 'TQ38SW'::bpchar))

Now if you look at the first set of figures, it's estimating 2 rows rather
than the 4797 you're actually getting. That's probably why it's chosen to
join then filter rather than the other way around.

I'd suggest the following:
1. VACUUM FULL on the table in question if you haven't done so since the last
update/reload. If you aren't doing this after every bulk upload, you probably
should be.
2. VACUUM ANALYSE/ANALYSE the table.
3. Check the tuning document I mentioned and make sure your settings are at
least reasonable. They don't have to be perfect - that last 10% takes
forever, but if they are badly wrong it can cripple you.
4. PG should now have up-to-date stats and a reasonable set of config
settings. If it's still getting its row estimates wrong, we'll have to look
at the statistics its got.

If we reach the statistics tinkering stage, it might be better to wait til
Monday if you can - more people on the list then.
--
  Richard Huxton
  Archonet Ltd

Re: [SQL] sql performance and cache

From
Josh Berkus
Date:
Chris,  People:

(Dropped SQL list because we're cross-posting unnecessarily)

> I am not sure I agree with you. I have done similar things with Oracle and
> found that the second query will execute much more quickly than the first.
> It could be made to work in at least two scenarios

Actually, PostgreSQL often DOES cache data, it just uses the Kernel cache
rather than any memory application built into Postgres, and it caches the
underlying data, not the final query results.  Base data for query sets gets
cached in RAM after a query, and the second query often *does* run much
faster.

For example, I was running some queries against the TPC-R OSDL database, and
the first time I ran the queries they took about 11 seconds each, the second
time (for each query) it was about 0.5 seconds because the data hadn't
changed and the underlying rowsets were in memory.

I think it's likely that your machine has *already* cached the data in memory,
which is why you don't see improvement on the second run.  The slow execution
time is the result of bad planner decisions and others are helping you adjust
that.

Now, regarding caching final query results in memory: This seems like a lot of
effort for very little return to me.   Doing so would require that all
underlying data stay the same, and on a complex query would require an
immense infrastructure of data-change tracking to verify.

If you want a data snapshot, ignoring the possibility of changes, there are
already ways to do this:
a) use a temp table;
b) use your middleware to cache the query results

Now, if someone were to present us with an implementation which effectively
built and automated form of option (b) above into a optional PG plug-in, I
wouldn't vote against it.   But I couldn't see voting for putting it on the
TODO list, either.

--
Josh Berkus
Aglio Database Solutions
San Francisco

Re: sql performance and cache

From
johnnnnnn
Date:
On Sat, Oct 11, 2003 at 10:43:04AM +0100, Chris Faulkner wrote:
> I have two very similar queries which I need to execute. They both
> have exactly the same from / where conditions. When I execute the
> first, it takes about 16 seconds. The second is executed almost
> immediately after, it takes 13 seconds. In short, I'd like to know
> why the query result isn't being cached and any ideas on how to
> improve the execution.

The way to do the type of caching you're talking about, if i
understand you correctly, would be to create a temporary
table. Specifically, create a temporary table with the results of the
second query. Then run a select * on that table (with no where
clause), and follow it with a select max(replace(...)) on the same
table (no where clause).

That guarantees two things:

1- The joins/filters are not parsed and evaluated twice, with the
corresponding disk reads.
2- The data is exactly consistent between the two queries.

Correct me if i misunderstood your problem.

-johnnnnnnnnnn


Re: [SQL] sql performance and cache

From
Tom Lane
Date:
"Chris Faulkner" <chrisf@oramap.com> writes:
> I am seeing this message in my logs.
> "bt_fixroot: not valid old root page"

That's not good.  I'd suggest reindexing that index.

            regards, tom lane

Re: sql performance and cache

From
Rod Taylor
Date:
> > Perhaps you are confusing it with the MySQL query cache?

> Is there plan on developing one (query cache)?

For the most part, prepared queries and cursors give you a greater
advantage due to their versatility -- both of which we do have.

In the cases where an actual cache is useful, the client application
could do it just as easily or temp tables can be used.

I suspect it would be implemented more as a caching proxy than as an
actual part of PostgreSQL, should someone really want this feature.

Re: [SQL] sql performance and cache

From
Wei Weng
Date:
On Sat, 11 Oct 2003, Christopher Kings-Lynne wrote:

>
> > I have two very similar queries which I need to execute. They both have
> > exactly the same from / where conditions. When I execute the first, it takes
> > about 16 seconds. The second is executed almost immediately after, it takes
> > 13 seconds. In short, I'd like to know why the query result isn't being
> > cached and any ideas on how to improve the execution.
>
> <snip>
>
> > OK - so I could execute the query once, and get the maximum size of the
> > array and the result set in one. I know what I am doing is less than optimal
> > but I had expected the query results to be cached. So the second execution
> > would be very quick. So why aren't they ? I have increased my cache size -
> > shared_buffers is 2000 and I have doubled the default max_fsm... settings
> > (although I am not sure what they do). sort_mem is 8192.
>
> PostgreSQL does not have, and has never had a query cache - so nothing
> you do is going to make that second query faster.
>
> Perhaps you are confusing it with the MySQL query cache?
>
> Chris
>
Is there plan on developing one (query cache)?

Thanks

Wei