From 0a4048646b1019580fb8ae6637f30a7e0ac1d8e0 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Fri, 17 Oct 2003 22:38:20 +0000 Subject: [PATCH] Document all the system views created by initdb (several of these were never documented anywhere, sigh). Centralize the detailed documentation of system views into catalogs.sgml, and provide cross-references. --- doc/src/sgml/catalogs.sgml | 816 ++++++++++++++++++++++++++++++++++- doc/src/sgml/monitoring.sgml | 127 +----- doc/src/sgml/mvcc.sgml | 17 +- doc/src/sgml/perform.sgml | 115 +---- doc/src/sgml/runtime.sgml | 117 ++--- 5 files changed, 858 insertions(+), 334 deletions(-) diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml index 9a8e2ff455..a30f0f867b 100644 --- a/doc/src/sgml/catalogs.sgml +++ b/doc/src/sgml/catalogs.sgml @@ -1,6 +1,6 @@ @@ -2937,8 +2937,9 @@ The catalog pg_shadow contains information about database users. The name stems from the fact that this table should not be readable by the public since it contains passwords. - pg_user is a publicly readable view on - pg_shadow that blanks out the password field. + pg_user + is a publicly readable view on + pg_shadow that blanks out the password field. @@ -3066,13 +3067,10 @@ public, since even statistical information about a table's contents may be considered sensitive. (Example: minimum and maximum values of a salary column might be quite interesting.) - pg_stats is a publicly readable view on + pg_stats + is a publicly readable view on pg_statistic that only exposes information about those tables that are readable by the current user. - pg_stats is also designed to present the - information in a more readable format than the underlying - pg_statistic table --- at the cost that - its schema must be extended whenever new slot types are added. @@ -3649,6 +3647,808 @@
+ + + System Views + + + In addition to the system catalogs, PostgreSQL + provides a number of built-in views. The system views provide convenient + access to some commonly used queries on the system catalogs. Some of these + views provide access to internal server state, as well. + + + + lists the system views described here. + More detailed documentation of each view follows below. + There are some additional views that provide access to the results of + the statistics collector; they are described in . + + + + The information schema () provides + an alternative set of views which overlap the functionality of the system + views. Since the information schema is SQL-standard whereas the views + described here are PostgreSQL-specific, + it's usually better to use the information schema if it provides all + the information you need. + + + + Except where noted, all the views described here are read-only. + + + + System Views + + + + + View Name + Purpose + + + + + + pg_indexes + indexes + + + + pg_locks + currently held locks + + + + pg_rules + rules + + + + pg_settings + parameter settings + + + + pg_stats + planner statistics + + + + pg_tables + tables + + + + pg_user + database users + + + + pg_views + views + + + + +
+
+ + + <structname>pg_indexes</structname> + + + pg_indexes + + + + The view pg_indexes provides access to + useful information about each index in the database. + + + + <structname>pg_indexes</> Columns + + + + + Name + Type + References + Description + + + + + schemaname + name + pg_namespace.nspname + name of schema containing table and index + + + tablename + name + pg_class.relname + name of table the index is for + + + indexname + name + pg_class.relname + name of index + + + indexdef + text + + index definition (a reconstructed creation command) + + + +
+ +
+ + + <structname>pg_locks</structname> + + + pg_locks + + + + The view pg_locks provides access to + information about the locks held by open transactions within the + database server. See for more discussion + of locking. + + + + pg_locks contains one row per active lockable + object, requested lock mode, and relevant transaction. Thus, the same + lockable object may + appear many times, if multiple transactions are holding or waiting + for locks on it. However, an object that currently has no locks on it + will not appear at all. A lockable object is either a relation (e.g., a + table) or a transaction ID. + + + + Note that this view includes only table-level + locks, not row-level ones. If a transaction is waiting for a + row-level lock, it will appear in the view as waiting for the + transaction ID of the current holder of that row lock. + + + + <structname>pg_locks</> Columns + + + + + Name + Type + References + Description + + + + + relation + oid + pg_class.oid + + OID of the locked relation, or NULL if the lockable object + is a transaction ID + + + + database + oid + pg_database.oid + + OID of the database in which the locked relation exists, or + zero if the locked relation is a globally-shared table, or + NULL if the lockable object is a transaction ID + + + + transaction + xid + + + ID of a transaction, or NULL if the lockable object is a relation + + + + pid + integer + + process ID of a server process holding or awaiting this + lock + + + mode + text + + name of the lock mode held or desired by this process (see ) + + + granted + boolean + + true if lock is held, false if lock is awaited + + + +
+ + + granted is true in a row representing a lock + held by the indicated session. False indicates that this session is + currently waiting to acquire this lock, which implies that some other + session is holding a conflicting lock mode on the same lockable object. + The waiting session will sleep until the other lock is released (or a + deadlock situation is detected). A single session can be waiting to acquire + at most one lock at a time. + + + + Every transaction holds an exclusive lock on its transaction ID for its + entire duration. If one transaction finds it necessary to wait specifically + for another transaction, it does so by attempting to acquire share lock on + the other transaction ID. That will succeed only when the other transaction + terminates and releases its locks. + + + + When the pg_locks view is accessed, the + internal lock manager data structures are momentarily locked, and + a copy is made for the view to display. This ensures that the + view produces a consistent set of results, while not blocking + normal lock manager operations longer than necessary. Nonetheless + there could be some impact on database performance if this view is + read often. + + + + pg_locks provides a global view of all locks + in the database cluster, not only those relevant to the current database. + Although its relation column can be joined + against pg_class.oid to identify locked + relations, this will only work correctly for relations in the current + database (those for which the database column + is either the current database's OID or zero). + + + + If you have enabled the statistics collector, the + pid column can be joined to the + procpid column of the + pg_stat_activity view to get more + information on the session holding or waiting to hold the lock. + + +
+ + + <structname>pg_rules</structname> + + + pg_rules + + + + The view pg_rules provides access to + useful information about query rewrite rules. + + + + <structname>pg_rules</> Columns + + + + + Name + Type + References + Description + + + + + schemaname + name + pg_namespace.nspname + name of schema containing table + + + tablename + name + pg_class.relname + name of table the rule is for + + + rulename + name + pg_rewrite.rulename + name of rule + + + definition + text + + rule definition (a reconstructed creation command) + + + +
+ + + The pg_rules view excludes the ON SELECT rules of + views; those can be seen in pg_views. + + +
+ + + <structname>pg_settings</structname> + + + pg_settings + + + + The view pg_settings provides access to + run-time parameters of the server. It is essentially an alternative + interface to the SHOW and SET commands. + It also provides access to some facts about each parameter that are + not directly available from SHOW, such as minimum and + maximum values. + + + + <structname>pg_settings</> Columns + + + + + Name + Type + References + Description + + + + + name + text + + run-time configuration parameter name + + + setting + text + + current value of the parameter + + + context + text + + context required to set the parameter's value + + + vartype + text + + parameter type (bool, integer, + real, or string) + + + + source + text + + source of the current parameter value + + + min_val + text + + minimum allowed value of the parameter (NULL for nonnumeric + values) + + + max_val + text + + maximum allowed value of the parameter (NULL for nonnumeric + values) + + + +
+ + + The pg_settings view cannot be inserted into or + deleted from, but it can be updated. An UPDATE applied + to a row of pg_settings is equivalent to executing + the command on that named + parameter. The change only affects the value used by the current + session. If an UPDATE is issued within a transaction + that is later aborted, the effects of the UPDATE command + disappear when the transaction is rolled back. Once the surrounding + transaction is committed, the effects will persist until the end of the + session, unless overridden by another UPDATE or + SET. + + +
+ + + <structname>pg_stats</structname> + + + pg_stats + + + + The view pg_stats provides access to + the information stored in the pg_statistic + catalog. This view allows access only to rows of + pg_statistic that correspond to tables the + user has permission to read, and therefore it is safe to allow public + read access to this view. + + + + pg_stats is also designed to present the + information in a more readable format than the underlying catalog + --- at the cost that its schema must be extended whenever new slot types + are defined for pg_statistic. + + + + <structname>pg_stats</> Columns + + + + + Name + Type + References + Description + + + + + schemaname + name + pg_namespace.nspname + name of schema containing table + + + + tablename + name + pg_class.relname + name of table + + + + attname + name + pg_attribute.attname + name of the column described by this row + + + + null_frac + real + + fraction of column entries that are null + + + + avg_width + integer + + average width in bytes of column's entries + + + + n_distinct + real + + If greater than zero, the estimated number of distinct values + in the column. If less than zero, the negative of the number of + distinct values divided by the number of rows. (The negated form + is used when ANALYZE believes that the number of distinct + values + is likely to increase as the table grows; the positive form is used + when the column seems to have a fixed number of possible values.) + For example, -1 indicates a unique column in which the number of + distinct values is the same as the number of rows. + + + + + most_common_vals + anyarray + + A list of the most common values in the column. (NULL if + no values seem to be more common than any others.) + + + + most_common_freqs + real[] + + A list of the frequencies of the most common values, + i.e., number of occurrences of each divided by total number of rows. + (NULL when most_common_vals is.) + + + + + histogram_bounds + anyarray + + A list of values that divide the column's values into + groups of approximately equal population. The values in + most_common_vals, if present, are omitted from this + histogram calculation. (This column is NULL if the column data type + does not have a < operator or if the + most_common_vals list accounts for the entire + population.) + + + + + correlation + real + + Statistical correlation between physical row ordering and + logical ordering of the column values. This ranges from -1 to +1. + When the value is near -1 or +1, an index scan on the column will + be estimated to be cheaper than when it is near zero, due to reduction + of random access to the disk. (This column is NULL if the column data + type does not have a < operator.) + + + + +
+ + + The maximum number of entries in the most_common_vals + and histogram_bounds arrays can be set on a + column-by-column basis using the ALTER TABLE SET STATISTICS + command, or globally by setting the + default_statistics_target runtime parameter. + + +
+ + + <structname>pg_tables</structname> + + + pg_tables + + + + The view pg_tables provides access to + useful information about each table in the database. + + + + <structname>pg_tables</> Columns + + + + + Name + Type + References + Description + + + + + schemaname + name + pg_namespace.nspname + name of schema containing table + + + tablename + name + pg_class.relname + name of table + + + tableowner + name + pg_shadow.usename + name of table's owner + + + hasindexes + boolean + pg_class.relhasindex + true if table has (or recently had) any indexes + + + hasrules + boolean + pg_class.relhasrules + true if table has rules + + + hastriggers + boolean + pg_class.reltriggers + true if table has triggers + + + +
+ +
+ + + <structname>pg_user</structname> + + + pg_user + + + + The view pg_user provides access to + information about database users. This is simply a publicly + readable view of + pg_shadow + that blanks out the password field. + + + + <structname>pg_user</> Columns + + + + + Name + Type + References + Description + + + + + usename + name + + User name + + + + usesysid + int4 + + User id (arbitrary number used to reference this user) + + + + usecreatedb + bool + + User may create databases + + + + usesuper + bool + + User is a superuser + + + + usecatupd + bool + + + User may update system catalogs. (Even a superuser may not do + this unless this column is true.) + + + + + passwd + text + + Not the password (always reads as ********) + + + + valuntil + abstime + + Account expiry time (only used for password authentication) + + + + useconfig + text[] + + Session defaults for run-time configuration variables + + + +
+ +
+ + + <structname>pg_views</structname> + + + pg_views + + + + The view pg_views provides access to + useful information about each view in the database. + + + + <structname>pg_views</> Columns + + + + + Name + Type + References + Description + + + + + schemaname + name + pg_namespace.nspname + name of schema containing view + + + viewname + name + pg_class.relname + name of view + + + viewowner + name + pg_shadow.usename + name of view's owner + + + definition + text + + view definition (a reconstructed SELECT query) + + + +
+ +
+
@@ -606,7 +606,7 @@ SELECT pg_stat_get_backend_pid(s.backendid) AS procpid, Another useful tool for monitoring database activity is the - pg_locks system table. It allows the + pg_locks system table. It allows the database administrator to view information about the outstanding locks in the lock manager. For example, this capability can be used to: @@ -638,130 +638,11 @@ SELECT pg_stat_get_backend_pid(s.backendid) AS procpid, + Details of the pg_locks view appear in + . For more information on locking and managing concurrency with PostgreSQL, refer to . - - - - When the pg_locks view is accessed, the - internal lock manager data structures are momentarily locked, and - a copy is made for the view to display. This ensures that the - view produces a consistent set of results, while not blocking - normal lock manager operations longer than necessary. Nonetheless - there could be some impact on database performance if this view is - read often. - - - - - shows the definition of the - pg_locks columns. The - pg_locks view contains one row per lockable - object and requested lock mode. Thus, the same lockable object may - appear many times, if multiple transactions are holding or waiting - for locks on it. A lockable object is either a relation (e.g., a table) or a - transaction ID. (Note that this view includes only table-level - locks, not row-level ones. If a transaction is waiting for a - row-level lock, it will appear in the view as waiting for the - transaction ID of the current holder of that row lock.) - - - - <literal>pg_locks</literal> Columns - - - - - Column Name - Data Type - Description - - - - - - relation - oid - - The OID of the locked relation, or null if the lockable object - is a transaction ID. This column can be joined with the column oid of the - pg_class system catalog to get more - information on the locked relation. Note however that this - will only work for relations in the current database (those for - which the database column is either - the current database's OID or zero). - - - - - database - oid - - The OID of the database in which the locked relation exists, or - null if the lockable object is a transaction ID. If the lock - is on a globally-shared table, this field will be zero. This - column can be joined with the column oid of the pg_database - system catalog to get more information on the locked object's - database. - - - - - transaction - xid - - The ID of a transaction, or null if the lockable object is a - relation. Every transaction holds an exclusive lock on its - transaction ID for its entire duration. If one transaction - finds it necessary to wait specifically for another - transaction, it does so by attempting to acquire share lock on - the other transaction ID. That will succeed only when the - other transaction terminates and releases its locks. - - - - - pid - integer - - The process ID of the PostgreSQL - server process belonging to the session that has acquired or is - attempting to acquire the lock. If you have enabled the - statistics collector, this column can be joined with the column - pg_stat_activity view to get more - information on the session holding or waiting to hold the - lock. - - - - - mode - text - - The mode of the requested or held lock on the lockable - object. For more information on the different lock modes - available in PostgreSQL, refer to - . - - - - - isgranted - boolean - - True if this lock has been granted (is held by this session). - False indicates that this session is currently waiting to - acquire this lock, which implies that some other session is - holding a conflicting lock mode on the same lockable object. - The waiting session will sleep until the other lock is released (or a - deadlock situation is detected). A single session can be - waiting to acquire at most one lock at a time. - - - - -
diff --git a/doc/src/sgml/mvcc.sgml b/doc/src/sgml/mvcc.sgml index edc9b1c267..2fdff8be68 100644 --- a/doc/src/sgml/mvcc.sgml +++ b/doc/src/sgml/mvcc.sgml @@ -1,5 +1,5 @@ @@ -399,6 +399,14 @@ ERROR: could not serialize access due to concurrent update executed concurrently with other operations on the same table.) + + To examine a list of the currently outstanding locks in a database + server, use the pg_locks system view + (). For more + information on monitoring the status of the lock manager + subsystem, refer to . + + Table-Level Locks @@ -429,13 +437,6 @@ ERROR: could not serialize access due to concurrent update Once acquired, a lock is held till end of transaction. - - To examine a list of the currently outstanding locks in a database - server, use the pg_locks system view. For more - information on monitoring the status of the lock manager - subsystem, refer to . - - Table-level lock modes diff --git a/doc/src/sgml/perform.sgml b/doc/src/sgml/perform.sgml index cdc96ac56b..d04f5ce89d 100644 --- a/doc/src/sgml/perform.sgml +++ b/doc/src/sgml/perform.sgml @@ -1,5 +1,5 @@ @@ -439,114 +439,19 @@ SELECT attname, n_distinct, most_common_vals FROM pg_stats WHERE tablename = 'ro - shows the columns that - exist in pg_stats. + pg_stats is described in detail in + . - - <structname>pg_stats</structname> Columns - - - - - Name - Data Type - Description - - - - - - schemaname - name - Name of the schema containing the table. - - - - tablename - name - Name of the table containing the column. - - - - attname - name - Name of the column described by this row. - - - - null_frac - real - Fraction of column entries that are null. - - - - avg_width - integer - Average width in bytes of the column entries. - - - - n_distinct - real - If greater than zero, the estimated number of distinct values - in the column. If less than zero, the negative of the number of - distinct values divided by the number of rows. (The negated form - is used when ANALYZE believes that the number of distinct values - is likely to increase as the table grows; the positive form is used - when the column seems to have a fixed number of possible values.) - For example, -1 indicates a unique column in which the number of - distinct values is the same as the number of rows. - - - - - most_common_vals - text[] - A list of the most common values in the column. (Omitted if - no values seem to be more common than any others.) - - - - most_common_freqs - real[] - A list of the frequencies of the most common values, - i.e., number of occurrences of each divided by total number of rows. - - - - - histogram_bounds - text[] - A list of values that divide the column's values into - groups of approximately equal population. The values in - most_common_vals, if present, are omitted from this - histogram calculation. (This columns is not filled if the column data type does not have a - < operator or if the most_common_vals - list accounts for the entire population.) - - - - - correlation - real - Statistical correlation between physical row ordering and - logical ordering of the column values. This ranges from -1 to +1. - When the value is near -1 or +1, an index scan on the column will - be estimated to be cheaper than when it is near zero, due to reduction - of random access to the disk. (This column is not filled if the column data type does - not have a < operator.) - - - - -
- - The maximum number of entries in the most_common_vals - and histogram_bounds arrays can be set on a + The amount of information stored in pg_statistic, + in particular the maximum number of entries in the + most_common_vals and histogram_bounds + arrays for each column, can be set on a column-by-column basis using the ALTER TABLE SET STATISTICS - command. The default limit is presently 10 entries. Raising the limit + command, or globally by setting the + default_statistics_target runtime parameter. + The default limit is presently 10 entries. Raising the limit may allow more accurate planner estimates to be made, particularly for columns with irregular data distributions, at the price of consuming more space in pg_statistic and slightly more diff --git a/doc/src/sgml/runtime.sgml b/doc/src/sgml/runtime.sgml index 4928aeda47..10ac77f275 100644 --- a/doc/src/sgml/runtime.sgml +++ b/doc/src/sgml/runtime.sgml @@ -1,5 +1,5 @@ @@ -466,7 +466,7 @@ psql: could not connect to server: No such file or directory - One way to set these options is to edit the file + One way to set these parameters is to edit the file postgresql.confpostgresql.conf in the data directory. (A default file is installed there.) An example of what this file might look like is: @@ -476,7 +476,7 @@ log_connections = yes syslog = 2 search_path = '$user, public' - One option is specified per line. The equal sign between name and + One parameter is specified per line. The equal sign between name and value is optional. Whitespace is insignificant and blank lines are ignored. Hash marks (#) introduce comments anywhere. Parameter values that are not simple identifiers or @@ -517,110 +517,47 @@ env PGOPTIONS='-c geqo=off' psql (This works for any libpq-based client application, not just psql.) Note that this won't work for - options that are fixed when the server is started, such as the port + parameters that are fixed when the server is started, such as the port number. - - Some options can be changed in individual SQL - sessions with the SET command, for example: - -SET ENABLE_SEQSCAN TO OFF; - - See the SQL command language reference for - details on the syntax. - - Furthermore, it is possible to assign a set of option settings to a user or a database. Whenever a session is started, the default settings for the user and database involved are loaded. The commands ALTER DATABASE and ALTER USER, respectively, are used to configure these - settings. Such per-database settings override anything received + settings. Per-database settings override anything received from the postmaster command-line or the configuration file, and in turn are overridden by per-user - settings. + settings; both are overridden by per-session options. - The virtual table pg_settings allows - displaying and updating session run-time parameters. It contains one - row for each configuration parameter; the columns are shown in - . This table allows the - configuration data to be joined with other tables and have a - selection criteria applied. + Some parameters can be changed in individual SQL + sessions with the + command, for example: + +SET ENABLE_SEQSCAN TO OFF; + + If SET is allowed, it overrides all other sources of + values for the parameter. Superusers are allowed to SET + more values than ordinary users. - - - An UPDATE performed on pg_settings - is equivalent to executing the SET command on that named - parameter. The change only affects the value used by the current session. If - an UPDATE is issued within a transaction that is later - aborted, the effects of the UPDATE command disappear when - the transaction is rolled back. Once the surrounding transaction is - committed, the effects will persist until the end of the session, unless - overridden by another UPDATE or SET. - - - - <literal>pg_settings</> Columns - - - - - Name - Data Type - Description - - - - - - name - text - run-time configuration parameter name - - - - setting - text - current value of the parameter - - - - context - text - context required to set the parameter's value - - - - vartype - text - parameter type - - - - source - text - source of the current parameter value - - - - min_val - text - minimum allowed value of the parameter - - - max_val - text - maximum allowed value of the parameter - + + The + command allows inspection of the current values of all parameters. + - - -
+ + The virtual table pg_settings + (described in ) also allows + displaying and updating session run-time parameters. It is equivalent + to SHOW and SET, but can be more convenient + to use because it can be joined with other tables, or selected from using + any desired selection condition. + Connections and Authentication -- 2.40.0