Query goal: | Too small fillfactor wastes storage space. |
Notes about the query: | The query assumes that the FILLFACTOR reloption is specified only in case of the base tables where it is not default, i.e., 100. Although currently FILLFACTOR is the only reloption this may change in the future. Thus, instead of using the condition reloptions IS NOT NULL, the query filters out reloptions that specify a new FILLFACTOR value. |
Query type: | Problem detection (Each row in the result could represent a flaw in the design) |
Query reliability: | Medium (Medium number of false-positive results) |
Query license: | MIT License |
Fixing suggestion: | Change FILLFACTOR to 90 or 95. It does not have to be smaller because old versions of rows will be soon deleted from blocks by the vacuum process, i.e., it frees space. After changing the FILLFACTOR of an existing table, one has to VACUUM FULL the table to reorganize its internal storage. |
Data source: | INFORMATION_SCHEMA+system catalog |
SQL query: | Click on query to copy it
WITH base_tables AS (SELECT pg_class.relname AS table_name, pg_namespace.nspname AS table_schema, unnest(reloptions) AS reloptions FROM pg_catalog.pg_class, pg_catalog.pg_namespace WHERE pg_class.relnamespace = pg_namespace.oid AND relkind='r'), base_tables_fillfactor AS (SELECT table_schema, table_name, regexp_replace(reloptions,'[^0-9]','','g')::int AS fillfactor FROM base_tables WHERE table_schema NOT IN (SELECT schema_name FROM INFORMATION_SCHEMA.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL) AND reloptions ILIKE 'fillfactor%') SELECT table_schema, table_name, fillfactor FROM base_tables_fillfactor WHERE fillfactor<90 ORDER BY table_schema, table_name; |
SQL query | Description |
---|---|
WITH base_tables AS (SELECT pg_class.relname AS table_name, pg_namespace.nspname AS table_schema, unnest(reloptions) AS reloptions FROM pg_catalog.pg_class, pg_catalog.pg_namespace WHERE pg_class.relnamespace = pg_namespace.oid AND relkind='r'), base_tables_fillfactor AS (SELECT table_schema, table_name, regexp_replace(reloptions,'[^0-9]','','g')::int AS fillfactor FROM base_tables WHERE table_schema NOT IN (SELECT schema_name FROM INFORMATION_SCHEMA.schemata WHERE schema_name<>'public' AND schema_owner='postgres' AND schema_name IS NOT NULL) AND reloptions ILIKE 'fillfactor%') SELECT format('ALTER TABLE %1$I.%2$I SET (FILLFACTOR=90); VACUUM FULL %1$I.%2$I', table_schema, table_name) AS statements FROM base_tables_fillfactor WHERE fillfactor<90 ORDER BY table_schema, table_name; | Change the fillfactor to 90. |
Collection name | Collection description |
---|---|
Find problems automatically | Queries, that results point to problems in the database. Each query in the collection produces an initial assessment. However, a human reviewer has the final say as to whether there is a problem or not . |
Category name | Category description |
---|---|
Data at the database physical level | Queries of this category provide information about the disk usage. |
Performance | Queries of this category provide information about indexes in a database. |