From: | Dan Harris <fbsd(at)drivefaster(dot)net> |
---|---|
To: | pgsql-admin(at)postgresql(dot)org |
Subject: | Re: finding fragmented tables |
Date: | 2007-05-10 04:23:19 |
Message-ID: | 46429E37.9080608@drivefaster.net |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-admin |
Dan Harris wrote:
> Carin Westblom wrote:
>> How can I easily find specific tables and/or databases with a lot of
>> space that may be reclaimed w a vacuum full?
>>
>
> I picked up this tip on the list a while ago:
>
> SELECT pg_namespace.nspname, pg_class.relname, pg_class.reltuples,
> pg_class.relpages, rowwidths.avgwidth, ceil(pg_class.reltuples *
> rowwidths.avgwidth::double precision /
> current_setting('block_size'::text)::double precision) AS expectedpages,
> pg_class.relpages::double precision / ceil(pg_class.reltuples *
> rowwidths.avgwidth::double precision /
> current_setting('block_size'::text)::double precision) AS bloat,
> ceil((pg_class.relpages::double precision *
> current_setting('block_size'::text)::double precision -
> ceil(pg_class.reltuples * rowwidths.avgwidth::double precision)) /
> 1024::double precision) AS wastedspace
> FROM ( SELECT pg_statistic.starelid, sum(pg_statistic.stawidth) AS
> avgwidth
> FROM pg_statistic
> GROUP BY pg_statistic.starelid) rowwidths
> JOIN pg_class ON rowwidths.starelid = pg_class.oid
> JOIN pg_namespace ON pg_namespace.oid = pg_class.relnamespace
> WHERE pg_class.relpages > 1;
>
>
> then do:
>
> select * from relbloat order by wastedspace desc;
I forgot to add that the select needs to be prepended by:
create view relbloat as ...
sorry about that!
-Dan
From | Date | Subject | |
---|---|---|---|
Next Message | Steve Holdoway | 2007-05-10 05:07:51 | upgrade 8.0.3 -> 8.2.4 |
Previous Message | Dan Harris | 2007-05-10 04:15:51 | Re: finding fragmented tables |