pg_stat_all_tables

The pg_stat_all_tables view shows one row for each table in the current database (including TOAST tables) to display statistics about accesses to that specific table.

The pg_stat_user_tables and pg_stat_sys_table views contain the same information, but filtered to only show user and system tables respectively.

In Greenplum Database 6, the pg_stat_*_tables views display access statistics for tables only from the master instance. Access statistics from segment instances are ignored. You can create views that display usage statistics, see Table Access Statistics from the Master and Segment Instances.

ColumnTypeDescription
relidoidOID of a table
schemanamenameName of the schema that this table is in
relnamenameName of this table
seq_scanbigintTotal number of sequential scans initiated on this table from all segment instances
seq_tup_readbigintNumber of live rows fetched by sequential scans
idx_scanbigintTotal number of index scans initiated on this table from all segment instances
idx_tup_fetchbigintNumber of live rows fetched by index scans
n_tup_insbigintNumber of rows inserted
n_tup_updbigintNumber of rows updated (includes HOT updated rows)
n_tup_delbigintNumber of rows deleted
n_tup_hot_updbigintNumber of rows HOT updated (i.e., with no separate index update required)
n_live_tupbigintEstimated number of live rows
n_dead_tupbigintEstimated number of dead rows
n_mod_since_analyzebigintEstimated number of rows modified since this table was last analyzed
last_vacuumtimestamp with time zoneLast time this table was manually vacuumed (not counting VACUUM FULL)
last_autovacuumtimestamp with time zoneLast time this table was vacuumed by the autovacuum daemon1
last_analyzetimestamp with time zoneLast time this table was manually analyzed
last_autoanalyzetimestamp with time zoneLast time this table was analyzed by the autovacuum daemon1
vacuum_countbigintNumber of times this table has been manually vacuumed (not counting VACUUM FULL)
autovacuum_countbigintNumber of times this table has been vacuumed by the autovacuum daemon1
analyze_countbigintNumber of times this table has been manually analyzed
autoanalyze_countbigintNumber of times this table has been analyzed by the autovacuum daemon 1

Note

1In Greenplum Database, the autovacuum daemon is deactivated and not supported for user defined databases.

Table Access Statistics from the Master and Segment Instances

To display table access statistics that combine statistics from the master and the segment instances you can create these views. A user requires SELECT privilege on the views to use them.

  1. -- Create these table access statistics views
  2. -- pg_stat_all_tables_gpdb6
  3. -- pg_stat_sys_tables_gpdb6
  4. -- pg_stat_user_tables_gpdb6
  5. CREATE VIEW pg_stat_all_tables_gpdb6 AS
  6. SELECT
  7. s.relid,
  8. s.schemaname,
  9. s.relname,
  10. m.seq_scan,
  11. m.seq_tup_read,
  12. m.idx_scan,
  13. m.idx_tup_fetch,
  14. m.n_tup_ins,
  15. m.n_tup_upd,
  16. m.n_tup_del,
  17. m.n_tup_hot_upd,
  18. m.n_live_tup,
  19. m.n_dead_tup,
  20. s.n_mod_since_analyze,
  21. s.last_vacuum,
  22. s.last_autovacuum,
  23. s.last_analyze,
  24. s.last_autoanalyze,
  25. s.vacuum_count,
  26. s.autovacuum_count,
  27. s.analyze_count,
  28. s.autoanalyze_count
  29. FROM
  30. (SELECT
  31. relid,
  32. schemaname,
  33. relname,
  34. sum(seq_scan) as seq_scan,
  35. sum(seq_tup_read) as seq_tup_read,
  36. sum(idx_scan) as idx_scan,
  37. sum(idx_tup_fetch) as idx_tup_fetch,
  38. sum(n_tup_ins) as n_tup_ins,
  39. sum(n_tup_upd) as n_tup_upd,
  40. sum(n_tup_del) as n_tup_del,
  41. sum(n_tup_hot_upd) as n_tup_hot_upd,
  42. sum(n_live_tup) as n_live_tup,
  43. sum(n_dead_tup) as n_dead_tup,
  44. max(n_mod_since_analyze) as n_mod_since_analyze,
  45. max(last_vacuum) as last_vacuum,
  46. max(last_autovacuum) as last_autovacuum,
  47. max(last_analyze) as last_analyze,
  48. max(last_autoanalyze) as last_autoanalyze,
  49. max(vacuum_count) as vacuum_count,
  50. max(autovacuum_count) as autovacuum_count,
  51. max(analyze_count) as analyze_count,
  52. max(autoanalyze_count) as autoanalyze_count
  53. FROM gp_dist_random('pg_stat_all_tables')
  54. WHERE relid >= 16384
  55. GROUP BY relid, schemaname, relname
  56. UNION ALL
  57. SELECT *
  58. FROM pg_stat_all_tables
  59. WHERE relid < 16384) m, pg_stat_all_tables s
  60. WHERE m.relid = s.relid;
  61. CREATE VIEW pg_stat_sys_tables_gpdb6 AS
  62. SELECT * FROM pg_stat_all_tables_gpdb6
  63. WHERE schemaname IN ('pg_catalog', 'information_schema') OR
  64. schemaname ~ '^pg_toast';
  65. CREATE VIEW pg_stat_user_tables_gpdb6 AS
  66. SELECT * FROM pg_stat_all_tables_gpdb6
  67. WHERE schemaname NOT IN ('pg_catalog', 'information_schema') AND
  68. schemaname !~ '^pg_toast';

Parent topic: System Catalogs Definitions