Re: finding fragmented tables - Mailing list pgsql-admin

From Dan Harris
Subject Re: finding fragmented tables
Date
Msg-id 46429C77.5090302@drivefaster.net
Whole thread Raw
In response to finding fragmented tables  ("Carin Westblom" <cwestblom@perpetual.com>)
Responses Re: finding fragmented tables  (Dan Harris <fbsd@drivefaster.net>)
List pgsql-admin
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;

pgsql-admin by date:

Previous
From: "Carin Westblom"
Date:
Subject: finding fragmented tables
Next
From: Dan Harris
Date:
Subject: Re: finding fragmented tables