Обсуждение: Big index sizes

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

Big index sizes

От
Laszlo Nagy
Дата:
We have serveral table where the index size is much bigger than the
table size.

Example:

select count(*) from product_price -- 2234244

Table size: 400 MB
Index size: 600 MB

After executing "reindex table product_price", index size reduced to 269MB.

I believe this affects performance.

Vacuuming a table does not rebuild the indexes, am I right? I'm not sure
if I need to do this manually, or is this the result of another problem?
(For example, too many open transactions, frequent updates?)


Thanks


Re: Big index sizes

От
Guillaume Lelarge
Дата:
Laszlo Nagy a écrit :
> We have serveral table where the index size is much bigger than the
> table size.
>
> Example:
>
> select count(*) from product_price -- 2234244
>
> Table size: 400 MB
> Index size: 600 MB
>
> After executing "reindex table product_price", index size reduced to 269MB.
>
> I believe this affects performance.
>
> Vacuuming a table does not rebuild the indexes, am I right?

Neither VACUUM nor VACUUM FULL rebuild the indexes. CLUSTER and REINDEX do.

> I'm not sure
> if I need to do this manually, or is this the result of another problem?

You need to do this manually.

> (For example, too many open transactions, frequent updates?)
>

Regards.


--
Guillaume.
 http://www.postgresqlfr.org
 http://dalibo.com

Re: Big index sizes

От
"Robert Haas"
Дата:
On Tue, Dec 30, 2008 at 4:05 AM, Laszlo Nagy <gandalf@shopzeus.com> wrote:
> We have serveral table where the index size is much bigger than the table
> size.

You'll usually get index bloat in roughly the same measure that you
get table bloat.  If you always (auto)vacuum regularly, then the
amount of bloat in your indexes probably reflects the amount of bloat
that your tables typically accumulate between vacuums, so reindexing
won't help much.  The indexes will just re-bloat back to about the
same point over the next vacuum cycle or two.

On the other hand, if your table has shrunk considerably, or if you've
just removed a lot of bloat by vacuuming, REINDEX is often warranted.

It would be nice if the system could automatically notice and correct
situations that currently require VACUUM FULL or REINDEX, but it
doesn't.

...Robert

Re: Big index sizes

От
Tom Lane
Дата:
Guillaume Lelarge <guillaume@lelarge.info> writes:
> Laszlo Nagy a �crit :
>> We have serveral table where the index size is much bigger than the
>> table size.
>> ...
>> Vacuuming a table does not rebuild the indexes, am I right?

> Neither VACUUM nor VACUUM FULL rebuild the indexes. CLUSTER and REINDEX do.

In fact, VACUUM FULL tends to make indexes *more* bloated not less so.
One fairly likely explanation for how you got into this situation is
overeager use of VACUUM FULL.

            regards, tom lane