Re: finding fragmented tables
От | Dan Harris |
---|---|
Тема | Re: finding fragmented tables |
Дата | |
Msg-id | 46429E37.9080608@drivefaster.net обсуждение исходный текст |
Ответ на | Re: finding fragmented tables (Dan Harris <fbsd@drivefaster.net>) |
Список | 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
В списке pgsql-admin по дате отправления: