Обсуждение: Obtaining the exact size of the database.

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

Obtaining the exact size of the database.

От
venu madhav
Дата:
Hi All,
      I am using Postgres 8.1.9 for my application. My application also has a clean up module which cleans up specified percentage of total database size at regular intervals. Now the problem is I use pg_database_size to obtain the size of the database. After deleting the records, we run Vacuum Analyze to reorder the indexes. The problem here is even though some records are cleared, it still shows the original DB Size. Is there any way to find out the actual DB Size or it would be more useful, if I can get the size of each table.
     I can't run Vacuum Full because the application should be run 24*7 without downtime.

Can someone please help me in solving this.

Please let me know if you need any clarifications.

Thank you,
Venu.

Re: Obtaining the exact size of the database.

От
Dave Crooke
Дата:

Hi there

1. PG 8.1.9 is ancient ... you should upgrade.

2. The database gross size on disk is not affected by VACUUM ANALYZE ... all this does is return space used by deleted row-versions to PG for re-use. The only way to reduce it and thus return disk space to the OS is to do a VACUUM FULL, or to delete the entire table.

3. If you can suspend writes for a while, you can pull off an "online" VACCUM FULL, or copy and delete the table in order to repack it. Check out the CLUSTER command.

4. If you're trying to figure out the net size of the table, i.e. how much free space is inside the table files for reuse by PG, then you need the pg_stat_tuple function ... this is built in to PG 8.4, and a plug-in activated by a script for PG 8.3, don't know if it exists in 8.1 or not. Like SELECT COUNT(*) this requires a full table scan.

Cheers
Dave

sent from my Android phone

On Jun 20, 2010 6:18 AM, "venu madhav" <venutaurus539@gmail.com> wrote:

Hi All,
      I am using Postgres 8.1.9 for my application. My application also has a clean up module which cleans up specified percentage of total database size at regular intervals. Now the problem is I use pg_database_size to obtain the size of the database. After deleting the records, we run Vacuum Analyze to reorder the indexes. The problem here is even though some records are cleared, it still shows the original DB Size. Is there any way to find out the actual DB Size or it would be more useful, if I can get the size of each table.
     I can't run Vacuum Full because the application should be run 24*7 without downtime.

Can someone please help me in solving this.

Please let me know if you need any clarifications.

Thank you,
Venu.

Re: Obtaining the exact size of the database.

От
Tom Lane
Дата:
Dave Crooke <dcrooke@gmail.com> writes:
> 4. If you're trying to figure out the net size of the table, i.e. how much
> free space is inside the table files for reuse by PG, then you need the
> pg_stat_tuple function ... this is built in to PG 8.4, and a plug-in
> activated by a script for PG 8.3, don't know if it exists in 8.1 or not.
> Like SELECT COUNT(*) this requires a full table scan.

I think what the OP actually wants is the number of live rows, so plain
old SELECT COUNT(*) would do it.  If that's too slow, a good alternative
is to ANALYZE the table and then look at its pg_class.reltuples entry
--- of course that will only be an approximate count.

            regards, tom lane

Re: Obtaining the exact size of the database.

От
Greg Smith
Дата:
venu madhav wrote:
> The problem here is even though some records are cleared, it still
> shows the original DB Size. Is there any way to find out the actual DB
> Size or it would be more useful, if I can get the size of each table.

One of the queries at http://wiki.postgresql.org/wiki/Disk_Usage should
give you the breakdown per table.  Regular VACUUM doesn't ever shrink
the database from the operating system perspective unless you hit a very
unusual situation (all of the free space is at the end).  There is no
way to do that without system downtime of sorts in the form a
potentially long database lock, such as VACUUM FULL (the main option on
8.1, the alternative of using CLUSTER isn't a good idea until 8.3).  The
best you can do is making sure you VACUUM often enough that space is
regularly reused.

It's hard to run a 24x7 environment on 8.1.  Much easier on 8.4, where
the major things that regularly left people with quite bad VACUUM
cleanup situations are all less likely to occur than on any previous
version.

--
Greg Smith  2ndQuadrant US  Baltimore, MD
PostgreSQL Training, Services and Support
greg@2ndQuadrant.com   www.2ndQuadrant.us


Re: Obtaining the exact size of the database.

От
Scott Marlowe
Дата:
On Sun, Jun 20, 2010 at 2:04 PM, Greg Smith <greg@2ndquadrant.com> wrote:

> It's hard to run a 24x7 environment on 8.1.  Much easier on 8.4, where the
> major things that regularly left people with quite bad VACUUM cleanup
> situations are all less likely to occur than on any previous version.

Here here.  keeping anything before 8.2 fed and happy is pretty
difficult in 24/7 environments.  8.2 and 8.3 are ok if you keep a
close eye on them.  And it just gets better from there.