Обсуждение: hstore query: Any better idea than adding more memory?

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

hstore query: Any better idea than adding more memory?

От
Stefan Keller
Дата:
Hi all

I'd like to tune the following hstore-related query which selects all
Zoos from table osm_point:

SELECT osm_id, name, tags
  FROM osm_point
  WHERE tags @> hstore('tourism','zoo')
  ORDER BY name;

... given the following table and indexes definition:

CREATE TABLE osm_point (
  osm_id integer,
  name text,
  tags hstore,
  way geometry
)

CREATE INDEX osm_point_index ON osm_point USING gist (way);
CREATE INDEX osm_point_name_idx ON osm_point USING btree  (name) WITH
(FILLFACTOR=100);
ALTER TABLE osm_point CLUSTER ON osm_point_name_idx;
CREATE INDEX osm_point_pkey ON osm_point USING btree (osm_id);
CREATE INDEX osm_point_tags_idx ON osm_point USING gist (tags) WITH
(FILLFACTOR=100);

... and following statistics:
* Live Tuples              9626138  (that's also what COUNT(*) returns)
* Table Size                    1029 MB
* Toast Table Size              32 kB
* Indexes Size                1381 MB (?)
** osm_point_index         1029 MB
** osm_point_name_idx   1029 MB
** osm_point_pkey          1029 MB
** osm_point_tags_idx     1029 MB

PostgreSQL has version 9.0.4, runs on on Ubuntu Linux 10.04 LTS
(64-Bit) with 1 vCPU and 1 GB vRAM.
Adding more memory (say to total of 32 GB) would only postpone the problem.
I already increased the PostgreSQL configuration of shared_buffers
(using pgtune).

Now EXPLAIN ANALYZE returns (if run several times):
Sort  (cost=30819.51..30843.58 rows=9626 width=65) (actual
time=11.502..11.502 rows=19 loops=1)
  Sort Key: name
  Sort Method:  quicksort  Memory: 29kB
  ->  Bitmap Heap Scan on osm_point  (cost=313.21..30182.62 rows=9626
width=65) (actual time=10.727..11.473 rows=19 loops=1)
        Recheck Cond: (tags @> 'tourism=>zoo'::hstore)
        ->  Bitmap Index Scan on osm_point_tags_idx
(cost=0.00..310.80 rows=9626 width=0) (actual time=10.399..10.399
rows=591 loops=1)
              Index Cond: (tags @> 'tourism=>zoo'::hstore)
Total runtime: 11 ms

First time the query lasts about 10 time longer (~ 1010 ms) - but I'd
like to get better results already in the first query.

=> 1. When I add the "actual time" from EXPLAIN above, I get 11 + 10 +
10ms which is three times greater than the 11ms reported.  Why?
=> 2. Why does the planner choose to sort first instead of sorting the
(smaller)  result query at the end the?
=> 3. What could I do to speed up such queries (first time, i.e.
without caching) besides simply adding more memory?

Yours, Stefan

Re: hstore query: Any better idea than adding more memory?

От
Stephen Frost
Дата:
* Stefan Keller (sfkeller@gmail.com) wrote:
> Adding more memory (say to total of 32 GB) would only postpone the problem.

Erm, seems like you're jumping to conclusions here...

> First time the query lasts about 10 time longer (~ 1010 ms) - but I'd
> like to get better results already in the first query.

Do you mean first time after a database restart?

> => 1. When I add the "actual time" from EXPLAIN above, I get 11 + 10 +
> 10ms which is three times greater than the 11ms reported.  Why?

Because they include the times from the nodes under them.

> => 2. Why does the planner choose to sort first instead of sorting the
> (smaller)  result query at the end the?

You're reading the explain 'backwards' regarding time..  It *does* do
the sort last.  Nodes which are indented feed the nodes above them, so
the bitmap index scan and recheck feed into the sort, hence the sort is
actually done after.  Can't really work any other way anyway, PG has to
get the data before it can sort it..

> => 3. What could I do to speed up such queries (first time, i.e.
> without caching) besides simply adding more memory?

There didn't look like anything there that could really be done much
faster, at the plan level.  It's not uncommon for people to
intentionally get a box with more memory than the size of their
database, so everything is in memory.

At the end of the day, if the blocks aren't in memory then PG has to get
them from disk.  If disk is slow, the query is going to be slow.  Now,
hopefully, you're hitting this table often enough with similar queries
that important, common, parts of the table and index are already in
memory, but there's no magic PG can perform to ensure that.

If there's a lot of updates/changes to this table, you might check if
there's a lot of bloat (check_postgres works great for this..).
Eliminating excessive bloat, if there is any, could help with all
accesses to that table, of course, since it would reduce the amount of
data which would need to be.

    Thanks,

        Stephen

Вложения

Re: hstore query: Any better idea than adding more memory?

От
Stefan Keller
Дата:
Hi Stephen

Thanks for your answer and hints.

2011/10/24 Stephen Frost <sfrost@snowman.net> wrote:
> * Stefan Keller (sfkeller@gmail.com) wrote:
>> Adding more memory (say to total of 32 GB) would only postpone the problem.
> Erm, seems like you're jumping to conclusions here...

Sorry. I actually only wanted to report here what's special in my
postgresql.conf.

>> First time the query lasts about 10 time longer (~ 1010 ms) - but I'd
>> like to get better results already in the first query.
>
> Do you mean first time after a database restart?

No: I simply meant doing the query when one can assume that the query
result is not yet in the postgres' cache.
You can check that here online: http://labs.geometa.info/postgisterminal

>> => 1. When I add the "actual time" from EXPLAIN above, I get 11 + 10 +
>> 10ms which is three times greater than the 11ms reported.  Why?
>
> Because they include the times from the nodes under them.
>
>> => 2. Why does the planner choose to sort first instead of sorting the
>> (smaller)  result query at the end the?
>
> You're reading the explain 'backwards' regarding time..  It *does* do
> the sort last.  Nodes which are indented feed the nodes above them, so
> the bitmap index scan and recheck feed into the sort, hence the sort is
> actually done after.  Can't really work any other way anyway, PG has to
> get the data before it can sort it..

Oh, thanks. I should have realized that.

But then what should the arrow ("->") wants to stand for?
Sort (cost=30819.51...
  ->  Bitmap Heap Scan on osm_point  (cost=313.21...
      ->  Bitmap Index Scan on osm_point_tags_idx

I would suggest that the inverse arrow would be more intuitive:
Sort (cost=30819.51...
  <-  Bitmap Heap Scan on osm_point  (cost=313.21...
      <-  Bitmap Index Scan on osm_point_tags_idx

>> => 3. What could I do to speed up such queries (first time, i.e.
>> without caching) besides simply adding more memory?
>
> There didn't look like anything there that could really be done much
> faster, at the plan level.  It's not uncommon for people to
> intentionally get a box with more memory than the size of their
> database, so everything is in memory.
>
> At the end of the day, if the blocks aren't in memory then PG has to get
> them from disk.  If disk is slow, the query is going to be slow.  Now,
> hopefully, you're hitting this table often enough with similar queries
> that important, common, parts of the table and index are already in
> memory, but there's no magic PG can perform to ensure that.
>
> If there's a lot of updates/changes to this table, you might check if
> there's a lot of bloat (check_postgres works great for this..).
> Eliminating excessive bloat, if there is any, could help with all
> accesses to that table, of course, since it would reduce the amount of
> data which would need to be.

Thanks for the hint.

But there are only periodic updates (currently once a night) and these
are actually done by 1. truncating the database and 2. bulk loading
all the stuff, then 3. reindexing.

If one tries to completely fit the whole data into memory, then to me
PostgreSQL features borrowed from in-memory databases become
interesting.

=> Is there anything else than "index-only scans" (planned for 9.2?)
which could be of interest here?

Stefan

Re: hstore query: Any better idea than adding more memory?

От
Stephen Frost
Дата:
* Stefan Keller (sfkeller@gmail.com) wrote:
> >> Adding more memory (say to total of 32 GB) would only postpone the problem.
> > Erm, seems like you're jumping to conclusions here...
>
> Sorry. I actually only wanted to report here what's special in my
> postgresql.conf.

My comment was referring to "postpone the problem".

> No: I simply meant doing the query when one can assume that the query
> result is not yet in the postgres' cache.
> You can check that here online: http://labs.geometa.info/postgisterminal

If it's not in PG's cache, and it's not in the OS's cache, then it's
gotta come from disk. :/

> But then what should the arrow ("->") wants to stand for?

Eh..  I wouldn't read the arrows as meaning all that much. :)  They're
there as a visual aide only, aiui.  Also, explain really shows the
*plan* that PG ended up picking for this query, thinking about it that
way might help.

> I would suggest that the inverse arrow would be more intuitive:

Perhaps, but don't get your hopes up about us breaking explain-reading
applications by changing that. :)

> But there are only periodic updates (currently once a night) and these
> are actually done by 1. truncating the database and 2. bulk loading
> all the stuff, then 3. reindexing.

Well, that would certainly help avoid bloat. :)

> If one tries to completely fit the whole data into memory, then to me
> PostgreSQL features borrowed from in-memory databases become
> interesting.

... huh?  I don't know of any system that's going to be able to make
sure that all your queries perform like in-memory queries when you don't
have enough memory to actually hold it all..

> => Is there anything else than "index-only scans" (planned for 9.2?)
> which could be of interest here?

index-only scans may be able to help with this as it may be able to
reduce the amount of disk i/o that has to be done, and reduce the amount
of memory needed to get everything into memory, but if you don't have
enough memory then you're still going to see a performance difference
between querying data that's cached and data that has to come from disk.

I don't know if index-only scans will, or will not, be able to help with
these specific queries.  I suspect they won't be much help since the
data being returned has to be in the index.  If I remember your query,
you were pulling out data which wasn't actaully in the index that was
being used to filter the result set.  Also, I don't know if we'll have
index-only scans for GIST/GIN indexes in 9.2 or if it won't be available
till a later release.  AIUI, only btree indexes can perform index-only
scans in the currently committed code.

Now, we've also been discussing ways to have PG automatically
re-populate shared buffers and possibly OS cache based on what was in
memory at the time of the last shut-down, but I'm not sure that would
help your case either since you're rebuilding everything every night and
that's what's trashing your buffers (because everything ends up getting
moved around).  You might actually want to consider if that's doing more
harm than good for you.  If you weren't doing that, then the cache
wouldn't be getting destroyed every night..

    Thanks,

        Stephen

Вложения