PostgreSQL 8.1.23 Documentation | ||||
---|---|---|---|---|
Prev | Fast Backward | Fast Forward | Next |
This chapter discusses how to monitor the disk usage of a PostgreSQL database system.
Each table has a primary heap disk file where most of the data is stored. If the table has any columns with potentially-wide values, there is also a TOAST file associated with the table, which is used to store values too wide to fit comfortably in the main table (see Section 50.2). There will be one index on the TOAST table, if present. There may also be indexes associated with the base table. Each table and index is stored in a separate disk file — possibly more than one file, if the file would exceed one gigabyte. Naming conventions for these files are described in Section 50.1.
You can monitor disk space from three ways: using SQL functions listed in Table 9-47, using VACUUM information, and from the command line using the tools in contrib/oid2name. The SQL functions are the easiest to use and report information about tables, tables with indexes and long value storage (TOAST), databases, and tablespaces.
Using psql on a recently vacuumed or analyzed database, you can issue queries to see the disk usage of any table:
SELECT relfilenode, relpages FROM pg_class WHERE relname = 'customer'; relfilenode | relpages -------------+---------- 16806 | 60 (1 row)
Each page is typically 8 kilobytes. (Remember, relpages is only updated by VACUUM, ANALYZE, and a few DDL commands such as CREATE INDEX.) The relfilenode value is of interest if you want to examine the table's disk file directly.
To show the space used by TOAST tables, use a query like the following:
SELECT relname, relpages FROM pg_class, (SELECT reltoastrelid FROM pg_class WHERE relname = 'customer') ss WHERE oid = ss.reltoastrelid OR oid = (SELECT reltoastidxid FROM pg_class WHERE oid = ss.reltoastrelid) ORDER BY relname; relname | relpages ----------------------+---------- pg_toast_16806 | 0 pg_toast_16806_index | 1
You can easily display index sizes, too:
SELECT c2.relname, c2.relpages FROM pg_class c, pg_class c2, pg_index i WHERE c.relname = 'customer' AND c.oid = i.indrelid AND c2.oid = i.indexrelid ORDER BY c2.relname; relname | relpages ----------------------+---------- customer_id_indexdex | 26
It is easy to find your largest tables and indexes using this information:
SELECT relname, relpages FROM pg_class ORDER BY relpages DESC; relname | relpages ----------------------+---------- bigtable | 3290 customer | 3144
You can also use contrib/oid2name to show disk usage. See README.oid2name in that directory for examples. It includes a script that shows disk usage for each database.