Thread: REINDEX not working for wastedspace
I am using Postgresql 9.0.1.
Using the query http://wiki.postgresql.org/wiki/Show_database_bloat, I got the following result for a table:
-[ RECORD 1 ]----+-----------------------------------------------
current_database | crm
schemaname | public
tablename | _attachments
tbloat | 0.9
wastedbytes | 0
iname | attachments_description_type_attachmentsid_idx
ibloat | 2.3
wastedibytes | 5439488
-[ RECORD 2 ]----+-----------------------------------------------
current_database | crm
schemaname | public
tablename | _attachments
tbloat | 0.9
wastedbytes | 0
iname | attachments_attachmentsid_idx
ibloat | 0.2
wastedibytes | 0
-[ RECORD 3 ]----+-----------------------------------------------
current_database | crm
schemaname | public
tablename | _attachments
tbloat | 0.9
wastedbytes | 0
iname | _attachments_pkey
ibloat | 0.2
wastedibytes | 0
I REINDEXED both the indexes and table, but I did not find any change in wastedspace or wastedispace.
Could you please tell me why?
Using the query http://wiki.postgresql.org/wiki/Show_database_bloat, I got the following result for a table:
-[ RECORD 1 ]----+-----------------------------------------------
current_database | crm
schemaname | public
tablename | _attachments
tbloat | 0.9
wastedbytes | 0
iname | attachments_description_type_attachmentsid_idx
ibloat | 2.3
wastedibytes | 5439488
-[ RECORD 2 ]----+-----------------------------------------------
current_database | crm
schemaname | public
tablename | _attachments
tbloat | 0.9
wastedbytes | 0
iname | attachments_attachmentsid_idx
ibloat | 0.2
wastedibytes | 0
-[ RECORD 3 ]----+-----------------------------------------------
current_database | crm
schemaname | public
tablename | _attachments
tbloat | 0.9
wastedbytes | 0
iname | _attachments_pkey
ibloat | 0.2
wastedibytes | 0
I REINDEXED both the indexes and table, but I did not find any change in wastedspace or wastedispace.
Could you please tell me why?
On Wed, 2011-09-21 at 13:01 +0600, AI Rumman wrote: > I am using Postgresql 9.0.1. > > Using the query http://wiki.postgresql.org/wiki/Show_database_bloat, I got > the following result for a table: > > -[ RECORD 1 ]----+----------------------------------------------- > current_database | crm > schemaname | public > tablename | _attachments > tbloat | 0.9 > wastedbytes | 0 > iname | attachments_description_type_attachmentsid_idx > ibloat | 2.3 > wastedibytes | 5439488 > -[ RECORD 2 ]----+----------------------------------------------- > current_database | crm > schemaname | public > tablename | _attachments > tbloat | 0.9 > wastedbytes | 0 > iname | attachments_attachmentsid_idx > ibloat | 0.2 > wastedibytes | 0 > -[ RECORD 3 ]----+----------------------------------------------- > current_database | crm > schemaname | public > tablename | _attachments > tbloat | 0.9 > wastedbytes | 0 > iname | _attachments_pkey > ibloat | 0.2 > wastedibytes | 0 > > I REINDEXED both the indexes and table, but I did not find any change in > wastedspace or wastedispace. > Could you please tell me why? REINDEX only rebuilds indexes. And you'll obviously have a bit of "lost space" because of the FILLFACTOR value (90% on indexes IIRC). -- Guillaume http://blog.guillaume.lelarge.info http://www.dalibo.com
Could you please let us know if you have analyzed after the re-indexing is done ?
This must show differences for only Indexes not the Tables.
For Tables, you need to do VACUUM FULL to show the difference.
Thanks
Venkat
On Wed, Sep 21, 2011 at 12:31 PM, AI Rumman <rummandba@gmail.com> wrote:
I am using Postgresql 9.0.1.
Using the query http://wiki.postgresql.org/wiki/Show_database_bloat, I got the following result for a table:
-[ RECORD 1 ]----+-----------------------------------------------
current_database | crm
schemaname | public
tablename | _attachments
tbloat | 0.9
wastedbytes | 0
iname | attachments_description_type_attachmentsid_idx
ibloat | 2.3
wastedibytes | 5439488
-[ RECORD 2 ]----+-----------------------------------------------
current_database | crm
schemaname | public
tablename | _attachments
tbloat | 0.9
wastedbytes | 0
iname | attachments_attachmentsid_idx
ibloat | 0.2
wastedibytes | 0
-[ RECORD 3 ]----+-----------------------------------------------
current_database | crm
schemaname | public
tablename | _attachments
tbloat | 0.9
wastedbytes | 0
iname | _attachments_pkey
ibloat | 0.2
wastedibytes | 0
I REINDEXED both the indexes and table, but I did not find any change in wastedspace or wastedispace.
Could you please tell me why?
Yes I ANALYZE the table, but no change for wastedispace.
On Wed, Sep 21, 2011 at 1:06 PM, Guillaume Lelarge <guillaume@lelarge.info> wrote:
REINDEX only rebuilds indexes. And you'll obviously have a bit of "lostOn Wed, 2011-09-21 at 13:01 +0600, AI Rumman wrote:
> I am using Postgresql 9.0.1.
>
> Using the query http://wiki.postgresql.org/wiki/Show_database_bloat, I got
> the following result for a table:
>
> -[ RECORD 1 ]----+-----------------------------------------------
> current_database | crm
> schemaname | public
> tablename | _attachments
> tbloat | 0.9
> wastedbytes | 0
> iname | attachments_description_type_attachmentsid_idx
> ibloat | 2.3
> wastedibytes | 5439488
> -[ RECORD 2 ]----+-----------------------------------------------
> current_database | crm
> schemaname | public
> tablename | _attachments
> tbloat | 0.9
> wastedbytes | 0
> iname | attachments_attachmentsid_idx
> ibloat | 0.2
> wastedibytes | 0
> -[ RECORD 3 ]----+-----------------------------------------------
> current_database | crm
> schemaname | public
> tablename | _attachments
> tbloat | 0.9
> wastedbytes | 0
> iname | _attachments_pkey
> ibloat | 0.2
> wastedibytes | 0
>
> I REINDEXED both the indexes and table, but I did not find any change in
> wastedspace or wastedispace.
> Could you please tell me why?
space" because of the FILLFACTOR value (90% on indexes IIRC).
--
Guillaume
http://blog.guillaume.lelarge.info
http://www.dalibo.com
On Wed, 2011-09-21 at 13:01 +0600, AI Rumman wrote: > I am using Postgresql 9.0.1. > > I REINDEXED both the indexes and table, but I did not find any change > in wastedspace or wastedispace. > Could you please tell me why? you need to 1) either vacuum full or cluster the table 2) analyze the table 3) check bloat again
Show_database_bloat reliability? [was: Re: REINDEX not working for wastedspace]
From
Guillaume Cottenceau
Date:
AI Rumman <rummandba 'at' gmail.com> writes: > Using the query http://wiki.postgresql.org/wiki/Show_database_bloat, I got the Is this stuff to show database bloat reliable? After a VACUUM FULL of the table reported as the top responsible of bloat, performing the same request again still gives the same result (still that table is the top responsible of bloat): current_database | schemaname | tablename | tbloat | wastedbytes | iname | ibloat | wastedibytes ------------------+------------+-----------------------------------------+--------+-------------+------------------------------------------------------+--------+-------------- test | public | requests | 1.1 | 14565376 | requests_pkey | 0.4 | 0 test | public | requests | 1.1 | 14565376 | idx_whatever | 0.8 | 0 test | public | requests | 1.1 | 14565376 | idx_whatever2 | 0.6 | 0 ... A few investigations show that when tbloat is close to 1.0 then it seems not reliable, otherwise it seems useful. pg 8.4.7 -- Guillaume Cottenceau
On 09/21/2011 02:01 AM, AI Rumman wrote: > Using the query http://wiki.postgresql.org/wiki/Show_database_bloat, > I got the following result for a table: God. I wish they would erase that Wiki page, or at least add a disclaimer. That query is no better than a loose estimate. Never, ever, ever depend on it for critical information about your tables. Ever. Ever. With that said, there are a lot of ways which can get the information you want. One is the pgstattuple contrib, the other is the pg_freespacemap contrib (though that didn't get really useful until 8.4 and above). Check out those documentation pages for usage info. More importantly, ignore the results of that query. It's wrong. If you've just reindexed, those indexes are about as small as they're ever going to be. -- Shaun Thomas OptionsHouse | 141 W. Jackson Blvd. | Suite 800 | Chicago IL, 60604 312-676-8870 sthomas@peak6.com ______________________________________________ See http://www.peak6.com/email-disclaimer/ for terms and conditions related to this email
Shaun Thomas <sthomas@peak6.com> writes: > On 09/21/2011 02:01 AM, AI Rumman wrote: >> Using the query http://wiki.postgresql.org/wiki/Show_database_bloat, >> I got the following result for a table: > God. I wish they would erase that Wiki page, or at least add a > disclaimer. That query is no better than a loose estimate. Never, ever, > ever depend on it for critical information about your tables. Ever. The PG wiki is editable by anyone who signs up for an account. Feel free to put in an appropriate disclaimer, or improve the sample query. regards, tom lane
On Sep 21, 2011, at 8:30 AM, Shaun Thomas wrote:
I wish they would erase that Wiki page, or at least add a disclaimer.
On 09/21/2011 09:12 AM, Tom Lane wrote: > The PG wiki is editable by anyone who signs up for an account. Feel > free to put in an appropriate disclaimer, or improve the sample > query. Ah, well then. I do have an account, but thought there were more granular page restrictions than that. I may have to start wading into them when I see stuff like this. :) -- Shaun Thomas OptionsHouse | 141 W. Jackson Blvd. | Suite 800 | Chicago IL, 60604 312-676-8870 sthomas@peak6.com ______________________________________________ See http://www.peak6.com/email-disclaimer/ for terms and conditions related to this email
Re: Show_database_bloat reliability? [was: Re: REINDEX not working for wastedspace]
From
Greg Smith
Date:
On 09/21/2011 08:43 AM, Guillaume Cottenceau wrote: > AI Rumman<rummandba 'at' gmail.com> writes: > > >> Using the query http://wiki.postgresql.org/wiki/Show_database_bloat, I got the >> > Is this stuff to show database bloat reliable? Only in that increase and decreases of the number reported can be useful for determining if bloat is likely increasing or decreasing--which is the purpose of that query. The value returned is a rough estimate, and should not be considered useful as any sort of absolute measurement. -- Greg Smith 2ndQuadrant US greg@2ndQuadrant.com Baltimore, MD PostgreSQL Training, Services, and 24x7 Support www.2ndQuadrant.us
It is very important to remove it from the WIKI page.
I ran it on production PG9.0 and it does not error out and displays numbered output.
I noticed that, this works till PG-8.2 (as per the message).
Venkat
On Wed, Sep 21, 2011 at 8:25 PM, Shaun Thomas <sthomas@peak6.com> wrote:
On 09/21/2011 09:12 AM, Tom Lane wrote:Ah, well then. I do have an account, but thought there were more granular page restrictions than that. I may have to start wading into them when I see stuff like this. :)The PG wiki is editable by anyone who signs up for an account. Feel
free to put in an appropriate disclaimer, or improve the sample
query.
--
Shaun Thomas
OptionsHouse | 141 W. Jackson Blvd. | Suite 800 | Chicago IL, 60604
312-676-8870
sthomas@peak6.com
______________________________________________
See http://www.peak6.com/email-disclaimer/ for terms and conditions related to this email
--Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance
On 09/21/2011 11:20 AM, Venkat Balaji wrote: > It is very important to remove it from the WIKI page. Removing it is a little premature. :) Definitely going to add a warning about relying on its output, though. The query itself was created and integrated into the check_postgres.pl nagios plugin as a very, very gross estimate of bloated tables. It wasn't the most accurate thing in the world, but considering what it had to work with, it did a pretty good job. Generally CLUSTER or VACUUM FULL would remove a table from the query output, but not always. It's those edge cases that cause problems. -- Shaun Thomas OptionsHouse | 141 W. Jackson Blvd. | Suite 800 | Chicago IL, 60604 312-676-8870 sthomas@peak6.com ______________________________________________ See http://www.peak6.com/email-disclaimer/ for terms and conditions related to this email