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.
This commit is contained in:
parent
e5c2c97892
commit
0a4048646b
@ -1,6 +1,6 @@
|
||||
<!--
|
||||
Documentation of the system catalogs, directed toward PostgreSQL developers
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/catalogs.sgml,v 2.75 2003/10/17 00:55:17 tgl Exp $
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/catalogs.sgml,v 2.76 2003/10/17 22:38:20 tgl Exp $
|
||||
-->
|
||||
|
||||
<chapter id="catalogs">
|
||||
@ -2937,8 +2937,9 @@
|
||||
The catalog <structname>pg_shadow</structname> 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.
|
||||
<structfield>pg_user</structfield> is a publicly readable view on
|
||||
<structfield>pg_shadow</structfield> that blanks out the password field.
|
||||
<link linkend="view-pg-user"><structname>pg_user</structname></link>
|
||||
is a publicly readable view on
|
||||
<structname>pg_shadow</structname> that blanks out the password field.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
@ -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.)
|
||||
<structname>pg_stats</structname> is a publicly readable view on
|
||||
<link linkend="view-pg-stats"><structname>pg_stats</structname></link>
|
||||
is a publicly readable view on
|
||||
<structname>pg_statistic</structname> that only exposes information
|
||||
about those tables that are readable by the current user.
|
||||
<structname>pg_stats</structname> is also designed to present the
|
||||
information in a more readable format than the underlying
|
||||
<structname>pg_statistic</structname> table --- at the cost that
|
||||
its schema must be extended whenever new slot types are added.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
@ -3649,6 +3647,808 @@
|
||||
</tgroup>
|
||||
</table>
|
||||
</sect1>
|
||||
|
||||
<sect1 id="views-overview">
|
||||
<title>System Views</title>
|
||||
|
||||
<para>
|
||||
In addition to the system catalogs, <productname>PostgreSQL</productname>
|
||||
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.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
<xref linkend="view-table"> 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 <xref
|
||||
linkend="monitoring-stats-views-table">.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The information schema (<xref linkend="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 <productname>PostgreSQL</productname>-specific,
|
||||
it's usually better to use the information schema if it provides all
|
||||
the information you need.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Except where noted, all the views described here are read-only.
|
||||
</para>
|
||||
|
||||
<table id="view-table">
|
||||
<title>System Views</title>
|
||||
|
||||
<tgroup cols="2">
|
||||
<thead>
|
||||
<row>
|
||||
<entry>View Name</entry>
|
||||
<entry>Purpose</entry>
|
||||
</row>
|
||||
</thead>
|
||||
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><link linkend="view-pg-indexes"><structname>pg_indexes</structname></link></entry>
|
||||
<entry>indexes</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><link linkend="view-pg-locks"><structname>pg_locks</structname></link></entry>
|
||||
<entry>currently held locks</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><link linkend="view-pg-rules"><structname>pg_rules</structname></link></entry>
|
||||
<entry>rules</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><link linkend="view-pg-settings"><structname>pg_settings</structname></link></entry>
|
||||
<entry>parameter settings</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><link linkend="view-pg-stats"><structname>pg_stats</structname></link></entry>
|
||||
<entry>planner statistics</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><link linkend="view-pg-tables"><structname>pg_tables</structname></link></entry>
|
||||
<entry>tables</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><link linkend="view-pg-user"><structname>pg_user</structname></link></entry>
|
||||
<entry>database users</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><link linkend="view-pg-views"><structname>pg_views</structname></link></entry>
|
||||
<entry>views</entry>
|
||||
</row>
|
||||
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
</sect1>
|
||||
|
||||
<sect1 id="view-pg-indexes">
|
||||
<title><structname>pg_indexes</structname></title>
|
||||
|
||||
<indexterm zone="view-pg-indexes">
|
||||
<primary>pg_indexes</primary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
The view <structname>pg_indexes</structname> provides access to
|
||||
useful information about each index in the database.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
<title><structname>pg_indexes</> Columns</title>
|
||||
|
||||
<tgroup cols=4>
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Name</entry>
|
||||
<entry>Type</entry>
|
||||
<entry>References</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><structfield>schemaname</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-namespace"><structname>pg_namespace</structname></link>.nspname</literal></entry>
|
||||
<entry>name of schema containing table and index</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>tablename</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-class"><structname>pg_class</structname></link>.relname</literal></entry>
|
||||
<entry>name of table the index is for</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>indexname</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-class"><structname>pg_class</structname></link>.relname</literal></entry>
|
||||
<entry>name of index</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>indexdef</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry></entry>
|
||||
<entry>index definition (a reconstructed creation command)</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
</sect1>
|
||||
|
||||
<sect1 id="view-pg-locks">
|
||||
<title><structname>pg_locks</structname></title>
|
||||
|
||||
<indexterm zone="view-pg-locks">
|
||||
<primary>pg_locks</primary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
The view <structname>pg_locks</structname> provides access to
|
||||
information about the locks held by open transactions within the
|
||||
database server. See <xref linkend="mvcc"> for more discussion
|
||||
of locking.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
<structname>pg_locks</structname> 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.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
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.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
<title><structname>pg_locks</> Columns</title>
|
||||
|
||||
<tgroup cols=4>
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Name</entry>
|
||||
<entry>Type</entry>
|
||||
<entry>References</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><structfield>relation</structfield></entry>
|
||||
<entry><type>oid</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-class"><structname>pg_class</structname></link>.oid</literal></entry>
|
||||
<entry>
|
||||
OID of the locked relation, or NULL if the lockable object
|
||||
is a transaction ID
|
||||
</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>database</structfield></entry>
|
||||
<entry><type>oid</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-database"><structname>pg_database</structname></link>.oid</literal></entry>
|
||||
<entry>
|
||||
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
|
||||
</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>transaction</structfield></entry>
|
||||
<entry><type>xid</type></entry>
|
||||
<entry></entry>
|
||||
<entry>
|
||||
ID of a transaction, or NULL if the lockable object is a relation
|
||||
</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>pid</structfield></entry>
|
||||
<entry><type>integer</type></entry>
|
||||
<entry></entry>
|
||||
<entry>process ID of a server process holding or awaiting this
|
||||
lock</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>mode</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry></entry>
|
||||
<entry>name of the lock mode held or desired by this process (see <xref
|
||||
linkend="locking-tables">)</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>granted</structfield></entry>
|
||||
<entry><type>boolean</type></entry>
|
||||
<entry></entry>
|
||||
<entry>true if lock is held, false if lock is awaited</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
<para>
|
||||
<structfield>granted</structfield> 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.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
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.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
When the <structname>pg_locks</structname> 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.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
<structname>pg_locks</structname> provides a global view of all locks
|
||||
in the database cluster, not only those relevant to the current database.
|
||||
Although its <structfield>relation</structfield> column can be joined
|
||||
against <structname>pg_class</>.<structfield>oid</> to identify locked
|
||||
relations, this will only work correctly for relations in the current
|
||||
database (those for which the <structfield>database</structfield> column
|
||||
is either the current database's OID or zero).
|
||||
</para>
|
||||
|
||||
<para>
|
||||
If you have enabled the statistics collector, the
|
||||
<structfield>pid</structfield> column can be joined to the
|
||||
<structfield>procpid</structfield> column of the
|
||||
<structname>pg_stat_activity</structname> view to get more
|
||||
information on the session holding or waiting to hold the lock.
|
||||
</para>
|
||||
|
||||
</sect1>
|
||||
|
||||
<sect1 id="view-pg-rules">
|
||||
<title><structname>pg_rules</structname></title>
|
||||
|
||||
<indexterm zone="view-pg-rules">
|
||||
<primary>pg_rules</primary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
The view <structname>pg_rules</structname> provides access to
|
||||
useful information about query rewrite rules.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
<title><structname>pg_rules</> Columns</title>
|
||||
|
||||
<tgroup cols=4>
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Name</entry>
|
||||
<entry>Type</entry>
|
||||
<entry>References</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><structfield>schemaname</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-namespace"><structname>pg_namespace</structname></link>.nspname</literal></entry>
|
||||
<entry>name of schema containing table</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>tablename</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-class"><structname>pg_class</structname></link>.relname</literal></entry>
|
||||
<entry>name of table the rule is for</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>rulename</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-rewrite"><structname>pg_rewrite</structname></link>.rulename</literal></entry>
|
||||
<entry>name of rule</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>definition</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry></entry>
|
||||
<entry>rule definition (a reconstructed creation command)</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
<para>
|
||||
The <structname>pg_rules</structname> view excludes the ON SELECT rules of
|
||||
views; those can be seen in <structname>pg_views</structname>.
|
||||
</para>
|
||||
|
||||
</sect1>
|
||||
|
||||
<sect1 id="view-pg-settings">
|
||||
<title><structname>pg_settings</structname></title>
|
||||
|
||||
<indexterm zone="view-pg-settings">
|
||||
<primary>pg_settings</primary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
The view <structname>pg_settings</structname> provides access to
|
||||
run-time parameters of the server. It is essentially an alternative
|
||||
interface to the <command>SHOW</> and <command>SET</> commands.
|
||||
It also provides access to some facts about each parameter that are
|
||||
not directly available from <command>SHOW</>, such as minimum and
|
||||
maximum values.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
<title><structname>pg_settings</> Columns</title>
|
||||
|
||||
<tgroup cols=4>
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Name</entry>
|
||||
<entry>Type</entry>
|
||||
<entry>References</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><structfield>name</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry></entry>
|
||||
<entry>run-time configuration parameter name</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>setting</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry></entry>
|
||||
<entry>current value of the parameter</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>context</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry></entry>
|
||||
<entry>context required to set the parameter's value</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>vartype</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry></entry>
|
||||
<entry>parameter type (<literal>bool</>, <literal>integer</>,
|
||||
<literal>real</>, or <literal>string</>)
|
||||
</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>source</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry></entry>
|
||||
<entry>source of the current parameter value</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>min_val</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry></entry>
|
||||
<entry>minimum allowed value of the parameter (NULL for nonnumeric
|
||||
values)</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>max_val</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry></entry>
|
||||
<entry>maximum allowed value of the parameter (NULL for nonnumeric
|
||||
values)</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
<para>
|
||||
The <structname>pg_settings</structname> view cannot be inserted into or
|
||||
deleted from, but it can be updated. An <command>UPDATE</command> applied
|
||||
to a row of <structname>pg_settings</structname> is equivalent to executing
|
||||
the <xref linkend="SQL-SET" endterm="SQL-SET-title"> command on that named
|
||||
parameter. The change only affects the value used by the current
|
||||
session. If an <command>UPDATE</command> is issued within a transaction
|
||||
that is later aborted, the effects of the <command>UPDATE</command> 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 <command>UPDATE</command> or
|
||||
<command>SET</command>.
|
||||
</para>
|
||||
|
||||
</sect1>
|
||||
|
||||
<sect1 id="view-pg-stats">
|
||||
<title><structname>pg_stats</structname></title>
|
||||
|
||||
<indexterm zone="view-pg-stats">
|
||||
<primary>pg_stats</primary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
The view <structname>pg_stats</structname> provides access to
|
||||
the information stored in the <link
|
||||
linkend="catalog-pg-statistic"><structname>pg_statistic</structname></link>
|
||||
catalog. This view allows access only to rows of
|
||||
<structname>pg_statistic</structname> that correspond to tables the
|
||||
user has permission to read, and therefore it is safe to allow public
|
||||
read access to this view.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
<structname>pg_stats</structname> 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 <structname>pg_statistic</structname>.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
<title><structname>pg_stats</> Columns</title>
|
||||
|
||||
<tgroup cols=4>
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Name</entry>
|
||||
<entry>Type</entry>
|
||||
<entry>References</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><structfield>schemaname</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-namespace"><structname>pg_namespace</structname></link>.nspname</literal></entry>
|
||||
<entry>name of schema containing table</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>tablename</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-class"><structname>pg_class</structname></link>.relname</literal></entry>
|
||||
<entry>name of table</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>attname</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-attribute"><structname>pg_attribute</structname></link>.attname</literal></entry>
|
||||
<entry>name of the column described by this row</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>null_frac</structfield></entry>
|
||||
<entry><type>real</type></entry>
|
||||
<entry></entry>
|
||||
<entry>fraction of column entries that are null</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>avg_width</structfield></entry>
|
||||
<entry><type>integer</type></entry>
|
||||
<entry></entry>
|
||||
<entry>average width in bytes of column's entries</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>n_distinct</structfield></entry>
|
||||
<entry><type>real</type></entry>
|
||||
<entry></entry>
|
||||
<entry>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 <command>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.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>most_common_vals</structfield></entry>
|
||||
<entry><type>anyarray</type></entry>
|
||||
<entry></entry>
|
||||
<entry>A list of the most common values in the column. (NULL if
|
||||
no values seem to be more common than any others.)</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>most_common_freqs</structfield></entry>
|
||||
<entry><type>real[]</type></entry>
|
||||
<entry></entry>
|
||||
<entry>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 <structfield>most_common_vals</structfield> is.)
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>histogram_bounds</structfield></entry>
|
||||
<entry><type>anyarray</type></entry>
|
||||
<entry></entry>
|
||||
<entry>A list of values that divide the column's values into
|
||||
groups of approximately equal population. The values in
|
||||
<structfield>most_common_vals</>, if present, are omitted from this
|
||||
histogram calculation. (This column is NULL if the column data type
|
||||
does not have a <literal><</> operator or if the
|
||||
<structfield>most_common_vals</> list accounts for the entire
|
||||
population.)
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>correlation</structfield></entry>
|
||||
<entry><type>real</type></entry>
|
||||
<entry></entry>
|
||||
<entry>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 <literal><</> operator.)
|
||||
</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
<para>
|
||||
The maximum number of entries in the <structfield>most_common_vals</>
|
||||
and <structfield>histogram_bounds</> arrays can be set on a
|
||||
column-by-column basis using the <command>ALTER TABLE SET STATISTICS</>
|
||||
command, or globally by setting the
|
||||
<varname>default_statistics_target</varname> runtime parameter.
|
||||
</para>
|
||||
|
||||
</sect1>
|
||||
|
||||
<sect1 id="view-pg-tables">
|
||||
<title><structname>pg_tables</structname></title>
|
||||
|
||||
<indexterm zone="view-pg-tables">
|
||||
<primary>pg_tables</primary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
The view <structname>pg_tables</structname> provides access to
|
||||
useful information about each table in the database.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
<title><structname>pg_tables</> Columns</title>
|
||||
|
||||
<tgroup cols=4>
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Name</entry>
|
||||
<entry>Type</entry>
|
||||
<entry>References</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><structfield>schemaname</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-namespace"><structname>pg_namespace</structname></link>.nspname</literal></entry>
|
||||
<entry>name of schema containing table</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>tablename</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-class"><structname>pg_class</structname></link>.relname</literal></entry>
|
||||
<entry>name of table</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>tableowner</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-shadow"><structname>pg_shadow</structname></link>.usename</literal></entry>
|
||||
<entry>name of table's owner</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>hasindexes</structfield></entry>
|
||||
<entry><type>boolean</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-class"><structname>pg_class</structname></link>.relhasindex</literal></entry>
|
||||
<entry>true if table has (or recently had) any indexes</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>hasrules</structfield></entry>
|
||||
<entry><type>boolean</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-class"><structname>pg_class</structname></link>.relhasrules</literal></entry>
|
||||
<entry>true if table has rules</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>hastriggers</structfield></entry>
|
||||
<entry><type>boolean</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-class"><structname>pg_class</structname></link>.reltriggers</literal></entry>
|
||||
<entry>true if table has triggers</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
</sect1>
|
||||
|
||||
<sect1 id="view-pg-user">
|
||||
<title><structname>pg_user</structname></title>
|
||||
|
||||
<indexterm zone="view-pg-user">
|
||||
<primary>pg_user</primary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
The view <structname>pg_user</structname> provides access to
|
||||
information about database users. This is simply a publicly
|
||||
readable view of
|
||||
<link linkend="catalog-pg-shadow"><structname>pg_shadow</structname></link>
|
||||
that blanks out the password field.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
<title><structname>pg_user</> Columns</title>
|
||||
|
||||
<tgroup cols=4>
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Name</entry>
|
||||
<entry>Type</entry>
|
||||
<entry>References</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><structfield>usename</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry></entry>
|
||||
<entry>User name</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>usesysid</structfield></entry>
|
||||
<entry><type>int4</type></entry>
|
||||
<entry></entry>
|
||||
<entry>User id (arbitrary number used to reference this user)</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>usecreatedb</structfield></entry>
|
||||
<entry><type>bool</type></entry>
|
||||
<entry></entry>
|
||||
<entry>User may create databases</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>usesuper</structfield></entry>
|
||||
<entry><type>bool</type></entry>
|
||||
<entry></entry>
|
||||
<entry>User is a superuser</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>usecatupd</structfield></entry>
|
||||
<entry><type>bool</type></entry>
|
||||
<entry></entry>
|
||||
<entry>
|
||||
User may update system catalogs. (Even a superuser may not do
|
||||
this unless this column is true.)
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>passwd</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry></entry>
|
||||
<entry>Not the password (always reads as <literal>********</>)</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>valuntil</structfield></entry>
|
||||
<entry><type>abstime</type></entry>
|
||||
<entry></entry>
|
||||
<entry>Account expiry time (only used for password authentication)</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>useconfig</structfield></entry>
|
||||
<entry><type>text[]</type></entry>
|
||||
<entry></entry>
|
||||
<entry>Session defaults for run-time configuration variables</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
</sect1>
|
||||
|
||||
<sect1 id="view-pg-views">
|
||||
<title><structname>pg_views</structname></title>
|
||||
|
||||
<indexterm zone="view-pg-views">
|
||||
<primary>pg_views</primary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
The view <structname>pg_views</structname> provides access to
|
||||
useful information about each view in the database.
|
||||
</para>
|
||||
|
||||
<table>
|
||||
<title><structname>pg_views</> Columns</title>
|
||||
|
||||
<tgroup cols=4>
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Name</entry>
|
||||
<entry>Type</entry>
|
||||
<entry>References</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><structfield>schemaname</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-namespace"><structname>pg_namespace</structname></link>.nspname</literal></entry>
|
||||
<entry>name of schema containing view</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>viewname</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-class"><structname>pg_class</structname></link>.relname</literal></entry>
|
||||
<entry>name of view</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>viewowner</structfield></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry><literal><link linkend="catalog-pg-shadow"><structname>pg_shadow</structname></link>.usename</literal></entry>
|
||||
<entry>name of view's owner</entry>
|
||||
</row>
|
||||
<row>
|
||||
<entry><structfield>definition</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry></entry>
|
||||
<entry>view definition (a reconstructed SELECT query)</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
</sect1>
|
||||
|
||||
</chapter>
|
||||
|
||||
<!-- Keep this comment at the end of the file
|
||||
|
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/monitoring.sgml,v 1.21 2003/08/31 17:32:19 petere Exp $
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/monitoring.sgml,v 1.22 2003/10/17 22:38:20 tgl Exp $
|
||||
-->
|
||||
|
||||
<chapter id="monitoring">
|
||||
@ -606,7 +606,7 @@ SELECT pg_stat_get_backend_pid(s.backendid) AS procpid,
|
||||
|
||||
<para>
|
||||
Another useful tool for monitoring database activity is the
|
||||
<literal>pg_locks</literal> system table. It allows the
|
||||
<structname>pg_locks</structname> 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,
|
||||
</listitem>
|
||||
</itemizedlist>
|
||||
|
||||
Details of the <structname>pg_locks</structname> view appear in
|
||||
<xref linkend="view-pg-locks">.
|
||||
For more information on locking and managing concurrency with
|
||||
<productname>PostgreSQL</productname>, refer to <xref linkend="mvcc">.
|
||||
</para>
|
||||
|
||||
<note>
|
||||
<para>
|
||||
When the <literal>pg_locks</literal> 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.
|
||||
</para>
|
||||
</note>
|
||||
|
||||
<para>
|
||||
<xref linkend="monitoring-locks-table"> shows the definition of the
|
||||
<literal>pg_locks</literal> columns. The
|
||||
<literal>pg_locks</literal> 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.)
|
||||
</para>
|
||||
|
||||
<table id="monitoring-locks-table">
|
||||
<title><literal>pg_locks</literal> Columns</title>
|
||||
|
||||
<tgroup cols="3">
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Column Name</entry>
|
||||
<entry>Data Type</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><structfield>relation</structfield></entry>
|
||||
<entry><type>oid</type></entry>
|
||||
<entry>
|
||||
The OID of the locked relation, or null if the lockable object
|
||||
is a transaction ID. This column can be joined with the column <literal>oid</> of the
|
||||
<literal>pg_class</literal> 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 <structfield>database</structfield> column is either
|
||||
the current database's OID or zero).
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>database</structfield></entry>
|
||||
<entry><type>oid</type></entry>
|
||||
<entry>
|
||||
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 <literal>oid</> of the <literal>pg_database</literal>
|
||||
system catalog to get more information on the locked object's
|
||||
database.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>transaction</structfield></entry>
|
||||
<entry><type>xid</type></entry>
|
||||
<entry>
|
||||
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.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>pid</structfield></entry>
|
||||
<entry><type>integer</type></entry>
|
||||
<entry>
|
||||
The process ID of the <productname>PostgreSQL</productname>
|
||||
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
|
||||
<literal>pg_stat_activity</literal> view to get more
|
||||
information on the session holding or waiting to hold the
|
||||
lock.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>mode</structfield></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry>
|
||||
The mode of the requested or held lock on the lockable
|
||||
object. For more information on the different lock modes
|
||||
available in <productname>PostgreSQL</productname>, refer to
|
||||
<xref linkend="mvcc">.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><structfield>isgranted</structfield></entry>
|
||||
<entry><type>boolean</type></entry>
|
||||
<entry>
|
||||
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.
|
||||
</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
</sect1>
|
||||
</chapter>
|
||||
|
||||
|
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/mvcc.sgml,v 2.38 2003/09/20 20:12:05 tgl Exp $
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/mvcc.sgml,v 2.39 2003/10/17 22:38:20 tgl Exp $
|
||||
-->
|
||||
|
||||
<chapter id="mvcc">
|
||||
@ -399,6 +399,14 @@ ERROR: could not serialize access due to concurrent update
|
||||
executed concurrently with other operations on the same table.)
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To examine a list of the currently outstanding locks in a database
|
||||
server, use the <structname>pg_locks</structname> system view
|
||||
(<xref linkend="view-pg-locks">). For more
|
||||
information on monitoring the status of the lock manager
|
||||
subsystem, refer to <xref linkend="monitoring">.
|
||||
</para>
|
||||
|
||||
<sect2 id="locking-tables">
|
||||
<title>Table-Level Locks</title>
|
||||
|
||||
@ -429,13 +437,6 @@ ERROR: could not serialize access due to concurrent update
|
||||
Once acquired, a lock is held till end of transaction.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To examine a list of the currently outstanding locks in a database
|
||||
server, use the <literal>pg_locks</literal> system view. For more
|
||||
information on monitoring the status of the lock manager
|
||||
subsystem, refer to <xref linkend="monitoring">.
|
||||
</para>
|
||||
|
||||
<variablelist>
|
||||
<title>Table-level lock modes</title>
|
||||
<varlistentry>
|
||||
|
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/perform.sgml,v 1.35 2003/10/17 01:14:26 tgl Exp $
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/perform.sgml,v 1.36 2003/10/17 22:38:20 tgl Exp $
|
||||
-->
|
||||
|
||||
<chapter id="performance-tips">
|
||||
@ -439,114 +439,19 @@ SELECT attname, n_distinct, most_common_vals FROM pg_stats WHERE tablename = 'ro
|
||||
</para>
|
||||
|
||||
<para>
|
||||
<xref linkend="planner-pg-stats-table"> shows the columns that
|
||||
exist in <structname>pg_stats</structname>.
|
||||
<structname>pg_stats</structname> is described in detail in
|
||||
<xref linkend="view-pg-stats">.
|
||||
</para>
|
||||
|
||||
<table id="planner-pg-stats-table">
|
||||
<title><structname>pg_stats</structname> Columns</title>
|
||||
|
||||
<tgroup cols=3>
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Name</entry>
|
||||
<entry>Data Type</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><literal>schemaname</literal></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry>Name of the schema containing the table.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>tablename</literal></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry>Name of the table containing the column.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>attname</literal></entry>
|
||||
<entry><type>name</type></entry>
|
||||
<entry>Name of the column described by this row.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>null_frac</literal></entry>
|
||||
<entry><type>real</type></entry>
|
||||
<entry>Fraction of column entries that are null.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>avg_width</literal></entry>
|
||||
<entry><type>integer</type></entry>
|
||||
<entry>Average width in bytes of the column entries.</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>n_distinct</literal></entry>
|
||||
<entry><type>real</type></entry>
|
||||
<entry>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 <command>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.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>most_common_vals</literal></entry>
|
||||
<entry><type>text[]</type></entry>
|
||||
<entry>A list of the most common values in the column. (Omitted if
|
||||
no values seem to be more common than any others.)</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>most_common_freqs</literal></entry>
|
||||
<entry><type>real[]</type></entry>
|
||||
<entry>A list of the frequencies of the most common values,
|
||||
i.e., number of occurrences of each divided by total number of rows.
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>histogram_bounds</literal></entry>
|
||||
<entry><type>text[]</type></entry>
|
||||
<entry>A list of values that divide the column's values into
|
||||
groups of approximately equal population. The values in
|
||||
<structfield>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
|
||||
<literal><</> operator or if the <structfield>most_common_vals</>
|
||||
list accounts for the entire population.)
|
||||
</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>correlation</literal></entry>
|
||||
<entry><type>real</type></entry>
|
||||
<entry>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 <literal><</> operator.)
|
||||
</entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
<para>
|
||||
The maximum number of entries in the <structfield>most_common_vals</>
|
||||
and <structfield>histogram_bounds</> arrays can be set on a
|
||||
The amount of information stored in <structname>pg_statistic</structname>,
|
||||
in particular the maximum number of entries in the
|
||||
<structfield>most_common_vals</> and <structfield>histogram_bounds</>
|
||||
arrays for each column, can be set on a
|
||||
column-by-column basis using the <command>ALTER TABLE SET STATISTICS</>
|
||||
command. The default limit is presently 10 entries. Raising the limit
|
||||
command, or globally by setting the
|
||||
<varname>default_statistics_target</varname> 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 <structname>pg_statistic</structname> and slightly more
|
||||
|
@ -1,5 +1,5 @@
|
||||
<!--
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/runtime.sgml,v 1.213 2003/10/10 02:08:42 momjian Exp $
|
||||
$Header: /cvsroot/pgsql/doc/src/sgml/runtime.sgml,v 1.214 2003/10/17 22:38:20 tgl Exp $
|
||||
-->
|
||||
|
||||
<Chapter Id="runtime">
|
||||
@ -466,7 +466,7 @@ psql: could not connect to server: No such file or directory
|
||||
</para>
|
||||
|
||||
<para>
|
||||
One way to set these options is to edit the file
|
||||
One way to set these parameters is to edit the file
|
||||
<filename>postgresql.conf</filename><indexterm><primary>postgresql.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'
|
||||
</programlisting>
|
||||
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 (<literal>#</literal>) introduce comments
|
||||
anywhere. Parameter values that are not simple identifiers or
|
||||
@ -517,110 +517,47 @@ env PGOPTIONS='-c geqo=off' psql
|
||||
</programlisting>
|
||||
(This works for any <application>libpq</>-based client application, not just
|
||||
<application>psql</application>.) 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.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Some options can be changed in individual <acronym>SQL</acronym>
|
||||
sessions with the <command>SET</command> command, for example:
|
||||
<screen>
|
||||
SET ENABLE_SEQSCAN TO OFF;
|
||||
</screen>
|
||||
See the <acronym>SQL</acronym> command language reference for
|
||||
details on the syntax.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
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 <command>ALTER DATABASE</command> and <command>ALTER
|
||||
USER</command>, respectively, are used to configure these
|
||||
settings. Such per-database settings override anything received
|
||||
settings. Per-database settings override anything received
|
||||
from the <command>postmaster</command> command-line or the
|
||||
configuration file, and in turn are overridden by per-user
|
||||
settings.
|
||||
settings; both are overridden by per-session options.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The virtual table <structname>pg_settings</structname> allows
|
||||
displaying and updating session run-time parameters. It contains one
|
||||
row for each configuration parameter; the columns are shown in
|
||||
<xref linkend="runtime-pgsettings-table">. 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 <acronym>SQL</acronym>
|
||||
sessions with the <xref linkend="SQL-SET" endterm="SQL-SET-title">
|
||||
command, for example:
|
||||
<screen>
|
||||
SET ENABLE_SEQSCAN TO OFF;
|
||||
</screen>
|
||||
If <command>SET</> is allowed, it overrides all other sources of
|
||||
values for the parameter. Superusers are allowed to <command>SET</>
|
||||
more values than ordinary users.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
An <command>UPDATE</command> performed on <structname>pg_settings</structname>
|
||||
is equivalent to executing the <command>SET</command> command on that named
|
||||
parameter. The change only affects the value used by the current session. If
|
||||
an <command>UPDATE</command> is issued within a transaction that is later
|
||||
aborted, the effects of the <command>UPDATE</command> 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 <command>UPDATE</command> or <command>SET</command>.
|
||||
</para>
|
||||
|
||||
<table id="runtime-pgsettings-table">
|
||||
<title><literal>pg_settings</> Columns</title>
|
||||
|
||||
<tgroup cols=3>
|
||||
<thead>
|
||||
<row>
|
||||
<entry>Name</entry>
|
||||
<entry>Data Type</entry>
|
||||
<entry>Description</entry>
|
||||
</row>
|
||||
</thead>
|
||||
|
||||
<tbody>
|
||||
<row>
|
||||
<entry><literal>name</literal></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry>run-time configuration parameter name</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>setting</literal></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry>current value of the parameter</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>context</literal></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry>context required to set the parameter's value</entry>
|
||||
</row>
|
||||
<para>
|
||||
The <xref linkend="SQL-SHOW" endterm="SQL-SHOW-title">
|
||||
command allows inspection of the current values of all parameters.
|
||||
</para>
|
||||
|
||||
<row>
|
||||
<entry><literal>vartype</literal></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry>parameter type</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>source</literal></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry>source of the current parameter value</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>min_val</literal></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry>minimum allowed value of the parameter</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>max_val</literal></entry>
|
||||
<entry><type>text</type></entry>
|
||||
<entry>maximum allowed value of the parameter</entry>
|
||||
</row>
|
||||
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
<para>
|
||||
The virtual table <structname>pg_settings</structname>
|
||||
(described in <xref linkend="view-pg-settings">) also allows
|
||||
displaying and updating session run-time parameters. It is equivalent
|
||||
to <command>SHOW</> and <command>SET</>, but can be more convenient
|
||||
to use because it can be joined with other tables, or selected from using
|
||||
any desired selection condition.
|
||||
</para>
|
||||
|
||||
<sect2 id="runtime-config-connection">
|
||||
<title>Connections and Authentication</title>
|
||||
|
Loading…
Reference in New Issue
Block a user