System Catalogs
The system catalogs are the place where a relational database
management system stores schema metadata, such as information about
tables and columns, and internal bookkeeping information.
PostgreSQL's system catalogs are regular
tables. You can drop and recreate the tables, add columns, insert
and update values, and severely mess up your system that way.
Normally, one should not change the system catalogs by hand, there
are always SQL commands to do that. (For example, CREATE
DATABASE inserts a row into the
pg_database catalog — and actually
creates the database on disk.) There are some exceptions for
particularly esoteric operations, such as adding index access methods.
Overview lists the system catalogs.
More detailed documentation of each catalog follows below.
Most system catalogs are copied from the template database during
database creation and are thereafter database-specific. A few
catalogs are physically shared across all databases in a cluster;
these are noted in the descriptions of the individual catalogs.
System CatalogsCatalog NamePurposepg_aggregateaggregate functionspg_amindex access methodspg_amopaccess method operatorspg_amprocaccess method support procedurespg_attrdefcolumn default valuespg_attributetable columns (attributes)pg_authidauthorization identifiers (roles)pg_auth_membersauthorization identifier membership relationshipspg_castcasts (data type conversions)pg_classtables, indexes, sequences, views (relations)pg_collationcollations (locale information)pg_constraintcheck constraints, unique constraints, primary key constraints, foreign key constraintspg_conversionencoding conversion informationpg_databasedatabases within this database clusterpg_db_role_settingper-role and per-database settingspg_default_acldefault privileges for object typespg_dependdependencies between database objectspg_descriptiondescriptions or comments on database objectspg_enumenum label and value definitionspg_event_triggerevent triggerspg_extensioninstalled extensionspg_foreign_data_wrapperforeign-data wrapper definitionspg_foreign_serverforeign server definitionspg_foreign_tableadditional foreign table informationpg_indexadditional index informationpg_inheritstable inheritance hierarchypg_languagelanguages for writing functionspg_largeobjectdata pages for large objectspg_largeobject_metadatametadata for large objectspg_namespaceschemaspg_opclassaccess method operator classespg_operatoroperatorspg_opfamilyaccess method operator familiespg_pltemplatetemplate data for procedural languagespg_policyrow-security policiespg_procfunctions and procedurespg_rangeinformation about range typespg_rewritequery rewrite rulespg_replication_originregistered replication originspg_replication_origin_statusinformation about replication origins, including replication progresspg_replication_slotsreplication slot informationpg_seclabelsecurity labels on database objectspg_shdependdependencies on shared objectspg_shdescriptioncomments on shared objectspg_shseclabelsecurity labels on shared database objectspg_statisticplanner statisticspg_tablesample_methodtable sampling methodspg_tablespacetablespaces within this database clusterpg_transformtransforms (data type to procedural language conversions)pg_triggertriggerspg_ts_configtext search configurationspg_ts_config_maptext search configurations' token mappingspg_ts_dicttext search dictionariespg_ts_parsertext search parserspg_ts_templatetext search templatespg_typedata typespg_user_mappingmappings of users to foreign servers
pg_aggregatepg_aggregate
The catalog pg_aggregate stores information about
aggregate functions. An aggregate function is a function that
operates on a set of values (typically one column from each row
that matches a query condition) and returns a single value computed
from all these values. Typical aggregate functions are
sum, count, and
max. Each entry in
pg_aggregate is an extension of an entry
in pg_proc. The pg_proc
entry carries the aggregate's name, input and output data types, and
other information that is similar to ordinary functions.
pg_aggregate> ColumnsNameTypeReferencesDescriptionaggfnoidregprocpg_proc.oidpg_proc OID of the aggregate functionaggkindcharAggregate kind:
n for normal> aggregates,
o for ordered-set> aggregates, or
h for hypothetical-set> aggregates
aggnumdirectargsint2Number of direct (non-aggregated) arguments of an ordered-set or
hypothetical-set aggregate, counting a variadic array as one argument.
If equal to pronargs>, the aggregate must be variadic
and the variadic array describes the aggregated arguments as well as
the final direct arguments.
Always zero for normal aggregates.aggtransfnregprocpg_proc.oidTransition functionaggfinalfnregprocpg_proc.oidFinal function (zero if none)aggmtransfnregprocpg_proc.oidForward transition function for moving-aggregate mode (zero if none)aggminvtransfnregprocpg_proc.oidInverse transition function for moving-aggregate mode (zero if none)aggmfinalfnregprocpg_proc.oidFinal function for moving-aggregate mode (zero if none)aggfinalextraboolTrue to pass extra dummy arguments to aggfinalfnaggmfinalextraboolTrue to pass extra dummy arguments to aggmfinalfnaggsortopoidpg_operator.oidAssociated sort operator (zero if none)aggtranstypeoidpg_type.oidData type of the aggregate function's internal transition (state) dataaggtransspaceint4Approximate average size (in bytes) of the transition state
data, or zero to use a default estimateaggmtranstypeoidpg_type.oidData type of the aggregate function's internal transition (state)
data for moving-aggregate mode (zero if none)aggmtransspaceint4Approximate average size (in bytes) of the transition state data
for moving-aggregate mode, or zero to use a default estimateagginitvaltext
The initial value of the transition state. This is a text
field containing the initial value in its external string
representation. If this field is null, the transition state
value starts out null.
aggminitvaltext
The initial value of the transition state for moving-aggregate mode.
This is a text field containing the initial value in its external
string representation. If this field is null, the transition state
value starts out null.
New aggregate functions are registered with the
command. See for more information about
writing aggregate functions and the meaning of the transition
functions, etc.
pg_ampg_am
The catalog pg_am stores information about index
access methods. There is one row for each index access method supported by
the system. The contents of this catalog are discussed in detail in
.
pg_am> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)amnamenameName of the access methodamstrategiesint2Number of operator strategies for this access method,
or zero if access method does not have a fixed set of operator
strategiesamsupportint2Number of support routines for this access methodamcanorderboolDoes the access method support ordered scans sorted by the
indexed column's value?amcanorderbyopboolDoes the access method support ordered scans sorted by the result
of an operator on the indexed column?amcanbackwardboolDoes the access method support backward scanning?amcanuniqueboolDoes the access method support unique indexes?amcanmulticolboolDoes the access method support multicolumn indexes?amoptionalkeyboolDoes the access method support a scan without any constraint
for the first index column?amsearcharrayboolDoes the access method support ScalarArrayOpExpr> searches?amsearchnullsboolDoes the access method support IS NULL>/NOT NULL> searches?amstorageboolCan index storage data type differ from column data type?amclusterableboolCan an index of this type be clustered on?ampredlocksboolDoes an index of this type manage fine-grained predicate locks?amkeytypeoidpg_type.oidType of data stored in index, or zero if not a fixed typeaminsertregprocpg_proc.oidInsert this tuple functionambeginscanregprocpg_proc.oidPrepare for index scan functionamgettupleregprocpg_proc.oidNext valid tuple function, or zero if noneamgetbitmapregprocpg_proc.oidFetch all valid tuples function, or zero if noneamrescanregprocpg_proc.oid(Re)start index scan functionamendscanregprocpg_proc.oidClean up after index scan functionammarkposregprocpg_proc.oidMark current scan position functionamrestrposregprocpg_proc.oidRestore marked scan position functionambuildregprocpg_proc.oidBuild new index functionambuildemptyregprocpg_proc.oidBuild empty index functionambulkdeleteregprocpg_proc.oidBulk-delete functionamvacuumcleanupregprocpg_proc.oidPost-VACUUM cleanup functionamcanreturnregprocpg_proc.oidFunction to check whether an index column supports index-only
scans. Can be zero if index-only scans are never supported.amcostestimateregprocpg_proc.oidFunction to estimate cost of an index scanamoptionsregprocpg_proc.oidFunction to parse and validate reloptions> for an index
pg_amoppg_amop
The catalog pg_amop stores information about
operators associated with access method operator families. There is one
row for each operator that is a member of an operator family. A family
member can be either a search> operator or an
ordering> operator. An operator
can appear in more than one family, but cannot appear in more than one
search position nor more than one ordering position within a family.
(It is allowed, though unlikely, for an operator to be used for both
search and ordering purposes.)
pg_amop> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)amopfamilyoidpg_opfamily.oidThe operator family this entry is foramoplefttypeoidpg_type.oidLeft-hand input data type of operatoramoprighttypeoidpg_type.oidRight-hand input data type of operatoramopstrategyint2Operator strategy numberamoppurposecharOperator purpose, either s> for search or
o> for orderingamopoproidpg_operator.oidOID of the operatoramopmethodoidpg_am.oidIndex access method operator family is foramopsortfamilyoidpg_opfamily.oidThe B-tree operator family this entry sorts according to, if an
ordering operator; zero if a search operator
A search> operator entry indicates that an index of this operator
family can be searched to find all rows satisfying
WHERE>
indexed_column>
operator>
constant>.
Obviously, such an operator must return boolean, and its left-hand input
type must match the index's column data type.
An ordering> operator entry indicates that an index of this
operator family can be scanned to return rows in the order represented by
ORDER BY>
indexed_column>
operator>
constant>.
Such an operator could return any sortable data type, though again
its left-hand input type must match the index's column data type.
The exact semantics of the ORDER BY> are specified by the
amopsortfamily column, which must reference
a B-tree operator family for the operator's result type.
At present, it's assumed that the sort order for an ordering operator
is the default for the referenced operator family, i.e., ASC NULLS
LAST>. This might someday be relaxed by adding additional columns
to specify sort options explicitly.
An entry's amopmethod> must match the
opfmethod> of its containing operator family (including
amopmethod> here is an intentional denormalization of the
catalog structure for performance reasons). Also,
amoplefttype> and amoprighttype> must match
the oprleft> and oprright> fields of the
referenced pg_operator> entry.
pg_amprocpg_amproc
The catalog pg_amproc stores information about
support procedures associated with access method operator families. There
is one row for each support procedure belonging to an operator family.
pg_amproc ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)amprocfamilyoidpg_opfamily.oidThe operator family this entry is foramproclefttypeoidpg_type.oidLeft-hand input data type of associated operatoramprocrighttypeoidpg_type.oidRight-hand input data type of associated operatoramprocnumint2Support procedure numberamprocregprocpg_proc.oidOID of the procedure
The usual interpretation of the
amproclefttype> and amprocrighttype> fields
is that they identify the left and right input types of the operator(s)
that a particular support procedure supports. For some access methods
these match the input data type(s) of the support procedure itself, for
others not. There is a notion of default> support procedures for
an index, which are those with amproclefttype> and
amprocrighttype> both equal to the index operator class's
opcintype>.
pg_attrdefpg_attrdef
The catalog pg_attrdef stores column default values. The main information
about columns is stored in pg_attribute
(see below). Only columns that explicitly specify a default value
(when the table is created or the column is added) will have an
entry here.
pg_attrdef> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)adrelidoidpg_class.oidThe table this column belongs toadnumint2pg_attribute.attnumThe number of the columnadbinpg_node_treeThe internal representation of the column default valueadsrctextA human-readable representation of the default value
The adsrc field is historical, and is best
not used, because it does not track outside changes that might affect
the representation of the default value. Reverse-compiling the
adbin field (with pg_get_expr> for
example) is a better way to display the default value.
pg_attributepg_attribute
The catalog pg_attribute stores information about
table columns. There will be exactly one
pg_attribute row for every column in every
table in the database. (There will also be attribute entries for
indexes, and indeed all objects that have pg_class
entries.)
The term attribute is equivalent to column and is used for
historical reasons.
pg_attribute> ColumnsNameTypeReferencesDescriptionattrelidoidpg_class.oidThe table this column belongs toattnamenameThe column nameatttypidoidpg_type.oidThe data type of this columnattstattargetint4attstattarget controls the level of detail
of statistics accumulated for this column by
.
A zero value indicates that no statistics should be collected.
A negative value says to use the system default statistics target.
The exact meaning of positive values is data type-dependent.
For scalar data types, attstattarget
is both the target number of most common values
to collect, and the target number of histogram bins to create.
attlenint2
A copy of pg_type.typlen of this column's
type
attnumint2
The number of the column. Ordinary columns are numbered from 1
up. System columns, such as oid,
have (arbitrary) negative numbers.
attndimsint4
Number of dimensions, if the column is an array type; otherwise 0.
(Presently, the number of dimensions of an array is not enforced,
so any nonzero value effectively means it's an array>.)
attcacheoffint4
Always -1 in storage, but when loaded into a row descriptor
in memory this might be updated to cache the offset of the attribute
within the row
atttypmodint4atttypmod records type-specific data
supplied at table creation time (for example, the maximum
length of a varchar column). It is passed to
type-specific input functions and length coercion functions.
The value will generally be -1 for types that do not need atttypmod>.
attbyvalbool
A copy of pg_type.typbyval> of this column's type
attstoragechar
Normally a copy of pg_type.typstorage> of this
column's type. For TOAST-able data types, this can be altered
after column creation to control storage policy.
attalignchar
A copy of pg_type.typalign> of this column's type
attnotnullbool
This represents a not-null constraint.
atthasdefbool
This column has a default value, in which case there will be a
corresponding entry in the pg_attrdef
catalog that actually defines the value.
attisdroppedbool
This column has been dropped and is no longer valid. A dropped
column is still physically present in the table, but is
ignored by the parser and so cannot be accessed via SQL.
attislocalbool
This column is defined locally in the relation. Note that a column can
be locally defined and inherited simultaneously.
attinhcountint4
The number of direct ancestors this column has. A column with a
nonzero number of ancestors cannot be dropped nor renamed.
attcollationoidpg_collation.oid
The defined collation of the column, or zero if the column is
not of a collatable data type.
attaclaclitem[]
Column-level access privileges, if any have been granted specifically
on this column
attoptionstext[]
Attribute-level options, as keyword=value> strings
attfdwoptionstext[]
Attribute-level foreign data wrapper options, as keyword=value> strings
In a dropped column's pg_attribute entry,
atttypid is reset to zero, but
attlen and the other fields copied from
pg_type> are still valid. This arrangement is needed
to cope with the situation where the dropped column's data type was
later dropped, and so there is no pg_type> row anymore.
attlen and the other fields can be used
to interpret the contents of a row of the table.
pg_authidpg_authid
The catalog pg_authid contains information about
database authorization identifiers (roles). A role subsumes the concepts
of users> and groups>. A user is essentially just a
role with the rolcanlogin> flag set. Any role (with or
without rolcanlogin>) can have other roles as members; see
pg_auth_members.
Since this catalog contains passwords, it must not be publicly readable.
pg_roles
is a publicly readable view on
pg_authid that blanks out the password field.
contains detailed information about user and
privilege management.
Because user identities are cluster-wide,
pg_authid
is shared across all databases of a cluster: there is only one
copy of pg_authid per cluster, not
one per database.
pg_authid> ColumnsNameTypeDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)rolnamenameRole namerolsuperboolRole has superuser privilegesrolinheritboolRole automatically inherits privileges of roles it is a
member ofrolcreateroleboolRole can create more rolesrolcreatedbboolRole can create databasesrolcanloginbool
Role can log in. That is, this role can be given as the initial
session authorization identifier
rolreplicationbool
Role is a replication role. That is, this role can initiate streaming
replication (see ) and set/unset
the system backup mode using pg_start_backup> and
pg_stop_backup>
rolbypassrlsbool
Role can bypass row level security policies, see
for more information.
rolconnlimitint4
For roles that can log in, this sets maximum number of concurrent
connections this role can make. -1 means no limit.
rolpasswordtext
Password (possibly encrypted); null if none. If the password
is encrypted, this column will begin with the string md5>
followed by a 32-character hexadecimal MD5 hash. The MD5 hash
will be of the user's password concatenated to their user name.
For example, if user joe> has password xyzzy>,
PostgreSQL> will store the md5 hash of
xyzzyjoe>. A password that does not follow that
format is assumed to be unencrypted.
rolvaliduntiltimestamptzPassword expiry time (only used for password authentication);
null if no expiration
pg_auth_memberspg_auth_members
The catalog pg_auth_members shows the membership
relations between roles. Any non-circular set of relationships is allowed.
Because user identities are cluster-wide,
pg_auth_members
is shared across all databases of a cluster: there is only one
copy of pg_auth_members per cluster, not
one per database.
pg_auth_members> ColumnsNameTypeReferencesDescriptionroleidoidpg_authid.oidID of a role that has a membermemberoidpg_authid.oidID of a role that is a member of roleid>grantoroidpg_authid.oidID of the role that granted this membershipadmin_optionboolTrue if member> can grant membership in
roleid> to others
pg_castpg_cast
The catalog pg_cast stores data type conversion
paths, both built-in and user-defined.
It should be noted that pg_cast does not represent
every type conversion that the system knows how to perform; only those that
cannot be deduced from some generic rule. For example, casting between a
domain and its base type is not explicitly represented in
pg_cast. Another important exception is that
automatic I/O conversion casts>, those performed using a data
type's own I/O functions to convert to or from text> or other
string types, are not explicitly represented in
pg_cast.
pg_cast> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)castsourceoidpg_type.oidOID of the source data typecasttargetoidpg_type.oidOID of the target data typecastfuncoidpg_proc.oid
The OID of the function to use to perform this cast. Zero is
stored if the cast method doesn't require a function.
castcontextchar
Indicates what contexts the cast can be invoked in.
e> means only as an explicit cast (using
CAST> or ::> syntax).
a> means implicitly in assignment
to a target column, as well as explicitly.
i> means implicitly in expressions, as well as the
other cases.
castmethodchar
Indicates how the cast is performed.
f> means that the function specified in the castfunc> field is used.
i> means that the input/output functions are used.
b> means that the types are binary-coercible, thus no conversion is required.
The cast functions listed in pg_cast must
always take the cast source type as their first argument type, and
return the cast destination type as their result type. A cast
function can have up to three arguments. The second argument,
if present, must be type integer>; it receives the type
modifier associated with the destination type, or -1
if there is none. The third argument,
if present, must be type boolean>; it receives true>
if the cast is an explicit cast, false> otherwise.
It is legitimate to create a pg_cast entry
in which the source and target types are the same, if the associated
function takes more than one argument. Such entries represent
length coercion functions> that coerce values of the type
to be legal for a particular type modifier value.
When a pg_cast entry has different source and
target types and a function that takes more than one argument, it
represents converting from one type to another and applying a length
coercion in a single step. When no such entry is available, coercion
to a type that uses a type modifier involves two steps, one to
convert between data types and a second to apply the modifier.
pg_classpg_class
The catalog pg_class catalogs tables and most
everything else that has columns or is otherwise similar to a
table. This includes indexes (but see also
pg_index), sequences, views, materialized
views, composite types, and TOAST tables; see relkind>.
Below, when we mean all of these
kinds of objects we speak of relations. Not all
columns are meaningful for all relation types.
pg_class> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)relnamenameName of the table, index, view, etc.relnamespaceoidpg_namespace.oid
The OID of the namespace that contains this relation
reltypeoidpg_type.oid
The OID of the data type that corresponds to this table's row type,
if any (zero for indexes, which have no pg_type> entry)
reloftypeoidpg_type.oid
For typed tables, the OID of the underlying composite type,
zero for all other relations
relowneroidpg_authid.oidOwner of the relationrelamoidpg_am.oidIf this is an index, the access method used (B-tree, hash, etc.)relfilenodeoidName of the on-disk file of this relation; zero means this
is a mapped> relation whose disk file name is determined
by low-level statereltablespaceoidpg_tablespace.oid
The tablespace in which this relation is stored. If zero,
the database's default tablespace is implied. (Not meaningful
if the relation has no on-disk file.)
relpagesint4
Size of the on-disk representation of this table in pages (of size
BLCKSZ). This is only an estimate used by the
planner. It is updated by VACUUM,
ANALYZE, and a few DDL commands such as
CREATE INDEX.
reltuplesfloat4
Number of rows in the table. This is only an estimate used by the
planner. It is updated by VACUUM,
ANALYZE, and a few DDL commands such as
CREATE INDEX.
relallvisibleint4
Number of pages that are marked all-visible in the table's
visibility map. This is only an estimate used by the
planner. It is updated by VACUUM,
ANALYZE, and a few DDL commands such as
CREATE INDEX.
reltoastrelidoidpg_class.oid
OID of the TOAST table associated with this table, 0 if none. The
TOAST table stores large attributes out of line in a
secondary table.
relhasindexbool
True if this is a table and it has (or recently had) any indexes
relissharedbool
True if this table is shared across all databases in the cluster. Only
certain system catalogs (such as pg_database)
are shared.
relpersistencecharp> = permanent table, u> = unlogged table,
t> = temporary table
relkindcharr> = ordinary table, i> = index,
S> = sequence, v> = view,
m> = materialized view,
c> = composite type, t> = TOAST table,
f> = foreign table
relnattsint2
Number of user columns in the relation (system columns not
counted). There must be this many corresponding entries in
pg_attribute. See also
pg_attribute.attnum.
relchecksint2
Number of CHECK> constraints on the table; see
pg_constraint catalog
relhasoidsbool
True if we generate an OID for each row of the relation
relhaspkeybool
True if the table has (or once had) a primary key
relhasrulesbool
True if table has (or once had) rules; see
pg_rewrite catalog
relhastriggersbool
True if table has (or once had) triggers; see
pg_trigger catalog
relhassubclassboolTrue if table has (or once had) any inheritance childrenrelrowsecuritybool
True if table has row level security enabled; see
pg_policy catalog
relispopulatedboolTrue if relation is populated (this is true for all
relations other than some materialized views)relreplidentchar
Columns used to form replica identity> for rows:
d> = default (primary key, if any),
n> = nothing,
f> = all columns
i> = index with indisreplident set, or default
relfrozenxidxid
All transaction IDs before this one have been replaced with a permanent
(frozen>) transaction ID in this table. This is used to track
whether the table needs to be vacuumed in order to prevent transaction
ID wraparound or to allow pg_clog> to be shrunk. Zero
(InvalidTransactionId) if the relation is not a table.
relminmxidxid
All multitransaction IDs before this one have been replaced by a
transaction ID in this table. This is used to track
whether the table needs to be vacuumed in order to prevent multitransaction ID
ID wraparound or to allow pg_clog> to be shrunk. Zero
(InvalidTransactionId) if the relation is not a table.
relaclaclitem[]
Access privileges; see
and
for details
reloptionstext[]
Access-method-specific options, as keyword=value> strings
Several of the Boolean flags in pg_class> are maintained
lazily: they are guaranteed to be true if that's the correct state, but
may not be reset to false immediately when the condition is no longer
true. For example, relhasindex> is set by
CREATE INDEX, but it is never cleared by
DROP INDEX. Instead, VACUUM clears
relhasindex> if it finds the table has no indexes. This
arrangement avoids race conditions and improves concurrency.
pg_collationpg_collation
The catalog pg_collation describes the
available collations, which are essentially mappings from an SQL
name to operating system locale categories.
See for more information.
pg_collation> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)collnamenameCollation name (unique per namespace and encoding)collnamespaceoidpg_namespace.oid
The OID of the namespace that contains this collation
collowneroidpg_authid.oidOwner of the collationcollencodingint4Encoding in which the collation is applicable, or -1 if it
works for any encodingcollcollatenameLC_COLLATE> for this collation objectcollctypenameLC_CTYPE> for this collation object
Note that the unique key on this catalog is (collname>,
collencoding>, collnamespace>) not just
(collname>, collnamespace>).
PostgreSQL generally ignores all
collations that do not have collencoding> equal to
either the current database's encoding or -1, and creation of new entries
with the same name as an entry with collencoding> = -1
is forbidden. Therefore it is sufficient to use a qualified SQL name
(schema>.name>) to identify a collation,
even though this is not unique according to the catalog definition.
The reason for defining the catalog this way is that
initdb> fills it in at cluster initialization time with
entries for all locales available on the system, so it must be able to
hold entries for all encodings that might ever be used in the cluster.
In the template0> database, it could be useful to create
collations whose encoding does not match the database encoding,
since they could match the encodings of databases later cloned from
template0>. This would currently have to be done manually.
pg_constraintpg_constraint
The catalog pg_constraint stores check, primary
key, unique, foreign key, and exclusion constraints on tables.
(Column constraints are not treated specially. Every column constraint is
equivalent to some table constraint.)
Not-null constraints are represented in the pg_attribute>
catalog, not here.
User-defined constraint triggers (created with CREATE CONSTRAINT
TRIGGER>) also give rise to an entry in this table.
Check constraints on domains are stored here, too.
pg_constraint> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)connamenameConstraint name (not necessarily unique!)connamespaceoidpg_namespace.oid
The OID of the namespace that contains this constraint
contypecharc> = check constraint,
f> = foreign key constraint,
p> = primary key constraint,
u> = unique constraint,
t> = constraint trigger,
x> = exclusion constraint
condeferrableboolIs the constraint deferrable?condeferredboolIs the constraint deferred by default?convalidatedboolHas the constraint been validated?
Currently, can only be false for foreign keys and CHECK constraintsconrelidoidpg_class.oidThe table this constraint is on; 0 if not a table constraintcontypidoidpg_type.oidThe domain this constraint is on; 0 if not a domain constraintconindidoidpg_class.oidThe index supporting this constraint, if it's a unique, primary
key, foreign key, or exclusion constraint; else 0confrelidoidpg_class.oidIf a foreign key, the referenced table; else 0confupdtypecharForeign key update action code:
a> = no action,
r> = restrict,
c> = cascade,
n> = set null,
d> = set default
confdeltypecharForeign key deletion action code:
a> = no action,
r> = restrict,
c> = cascade,
n> = set null,
d> = set default
confmatchtypecharForeign key match type:
f> = full,
p> = partial,
s> = simple
conislocalbool
This constraint is defined locally for the relation. Note that a
constraint can be locally defined and inherited simultaneously.
coninhcountint4
The number of direct inheritance ancestors this constraint has.
A constraint with
a nonzero number of ancestors cannot be dropped nor renamed.
connoinheritbool
This constraint is defined locally for the relation. It is a
non-inheritable constraint.
conkeyint2[]pg_attribute.attnum>If a table constraint (including foreign keys, but not constraint
triggers), list of the constrained columnsconfkeyint2[]pg_attribute.attnum>If a foreign key, list of the referenced columnsconpfeqopoid[]pg_operator.oid>If a foreign key, list of the equality operators for PK = FK comparisonsconppeqopoid[]pg_operator.oid>If a foreign key, list of the equality operators for PK = PK comparisonsconffeqopoid[]pg_operator.oid>If a foreign key, list of the equality operators for FK = FK comparisonsconexclopoid[]pg_operator.oid>If an exclusion constraint, list of the per-column exclusion operatorsconbinpg_node_treeIf a check constraint, an internal representation of the expressionconsrctextIf a check constraint, a human-readable representation of the expression
In the case of an exclusion constraint, conkey
is only useful for constraint elements that are simple column references.
For other cases, a zero appears in conkey
and the associated index must be consulted to discover the expression
that is constrained. (conkey thus has the
same contents as pg_index>.indkey> for the
index.)
consrc is not updated when referenced objects
change; for example, it won't track renaming of columns. Rather than
relying on this field, it's best to use pg_get_constraintdef()>
to extract the definition of a check constraint.
pg_class.relchecks needs to agree with the
number of check-constraint entries found in this table for each
relation.
pg_conversionpg_conversion
The catalog pg_conversion describes
encoding conversion procedures. See
for more information.
pg_conversion> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)connamenameConversion name (unique within a namespace)connamespaceoidpg_namespace.oid
The OID of the namespace that contains this conversion
conowneroidpg_authid.oidOwner of the conversionconforencodingint4Source encoding IDcontoencodingint4Destination encoding IDconprocregprocpg_proc.oidConversion procedurecondefaultboolTrue if this is the default conversion
pg_databasepg_database
The catalog pg_database stores information about
the available databases. Databases are created with the command.
Consult for details about the meaning
of some of the parameters.
Unlike most system catalogs, pg_database
is shared across all databases of a cluster: there is only one
copy of pg_database per cluster, not
one per database.
pg_database> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)datnamenameDatabase namedatdbaoidpg_authid.oidOwner of the database, usually the user who created itencodingint4Character encoding for this database
(pg_encoding_to_char() can translate
this number to the encoding name)datcollatenameLC_COLLATE for this databasedatctypenameLC_CTYPE for this databasedatistemplatebool
If true, then this database can be cloned by
any user with CREATEDB> privileges;
if false, then only superusers or the owner of
the database can clone it.
datallowconnbool
If false then no one can connect to this database. This is
used to protect the template0> database from being altered.
datconnlimitint4
Sets maximum number of concurrent connections that can be made
to this database. -1 means no limit.
datlastsysoidoid
Last system OID in the database; useful
particularly to pg_dumpdatfrozenxidxid
All transaction IDs before this one have been replaced with a permanent
(frozen>) transaction ID in this database. This is used to
track whether the database needs to be vacuumed in order to prevent
transaction ID wraparound or to allow pg_clog> to be shrunk.
It is the minimum of the per-table
pg_class>.relfrozenxid> values.
datminmxidxid
All multitransaction IDs before this one have been replaced with a
transaction ID in this database. This is used to
track whether the database needs to be vacuumed in order to prevent
transaction ID wraparound or to allow pg_clog> to be shrunk.
It is the minimum of the per-table
pg_class>.relminmxid> values.
dattablespaceoidpg_tablespace.oid
The default tablespace for the database.
Within this database, all tables for which
pg_class>.reltablespace> is zero
will be stored in this tablespace; in particular, all the non-shared
system catalogs will be there.
dataclaclitem[]
Access privileges; see
and
for details
pg_db_role_settingpg_db_role_setting
The catalog pg_db_role_setting records the default
values that have been set for run-time configuration variables,
for each role and database combination.
Unlike most system catalogs, pg_db_role_setting
is shared across all databases of a cluster: there is only one
copy of pg_db_role_setting per cluster, not
one per database.
pg_db_role_setting> ColumnsNameTypeReferencesDescriptionsetdatabaseoidpg_database.oidThe OID of the database the setting is applicable to, or zero if not database-specificsetroleoidpg_authid.oidThe OID of the role the setting is applicable to, or zero if not role-specificsetconfigtext[]Defaults for run-time configuration variables
pg_default_aclpg_default_acl
The catalog pg_default_acl> stores initial
privileges to be assigned to newly created objects.
pg_default_acl> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)defaclroleoidpg_authid.oidThe OID of the role associated with this entrydefaclnamespaceoidpg_namespace.oidThe OID of the namespace associated with this entry,
or 0 if nonedefaclobjtypechar
Type of object this entry is for:
r> = relation (table, view),
S> = sequence,
f> = function,
T> = type
defaclaclaclitem[]
Access privileges that this type of object should have on creation
A pg_default_acl> entry shows the initial privileges to
be assigned to an object belonging to the indicated user. There are
currently two types of entry: global> entries with
defaclnamespace> = 0, and per-schema> entries
that reference a particular schema. If a global entry is present then
it overrides> the normal hard-wired default privileges
for the object type. A per-schema entry, if present, represents privileges
to be added to> the global or hard-wired default privileges.
Note that when an ACL entry in another catalog is null, it is taken
to represent the hard-wired default privileges for its object,
not> whatever might be in pg_default_acl>
at the moment. pg_default_acl> is only consulted during
object creation.
pg_dependpg_depend
The catalog pg_depend records the dependency
relationships between database objects. This information allows
DROP> commands to find which other objects must be dropped
by DROP CASCADE> or prevent dropping in the DROP
RESTRICT> case.
See also pg_shdepend,
which performs a similar function for dependencies involving objects
that are shared across a database cluster.
pg_depend> ColumnsNameTypeReferencesDescriptionclassidoidpg_class.oidThe OID of the system catalog the dependent object is inobjidoidany OID columnThe OID of the specific dependent objectobjsubidint4
For a table column, this is the column number (the
objid> and classid> refer to the
table itself). For all other object types, this column is
zero.
refclassidoidpg_class.oidThe OID of the system catalog the referenced object is inrefobjidoidany OID columnThe OID of the specific referenced objectrefobjsubidint4
For a table column, this is the column number (the
refobjid> and refclassid> refer
to the table itself). For all other object types, this column
is zero.
deptypechar
A code defining the specific semantics of this dependency relationship; see text
In all cases, a pg_depend entry indicates that the
referenced object cannot be dropped without also dropping the dependent
object. However, there are several subflavors identified by
deptype>:
DEPENDENCY_NORMAL> (n>)
A normal relationship between separately-created objects. The
dependent object can be dropped without affecting the
referenced object. The referenced object can only be dropped
by specifying CASCADE>, in which case the dependent
object is dropped, too. Example: a table column has a normal
dependency on its data type.
DEPENDENCY_AUTO> (a>)
The dependent object can be dropped separately from the
referenced object, and should be automatically dropped
(regardless of RESTRICT> or CASCADE>
mode) if the referenced object is dropped. Example: a named
constraint on a table is made autodependent on the table, so
that it will go away if the table is dropped.
DEPENDENCY_INTERNAL> (i>)
The dependent object was created as part of creation of the
referenced object, and is really just a part of its internal
implementation. A DROP> of the dependent object
will be disallowed outright (we'll tell the user to issue a
DROP> against the referenced object, instead). A
DROP> of the referenced object will be propagated
through to drop the dependent object whether
CASCADE> is specified or not. Example: a trigger
that's created to enforce a foreign-key constraint is made
internally dependent on the constraint's
pg_constraint> entry.
DEPENDENCY_EXTENSION> (e>)
The dependent object is a member of the extension> that is
the referenced object (see
pg_extension).
The dependent object can be dropped only via
DROP EXTENSION> on the referenced object. Functionally
this dependency type acts the same as an internal dependency, but
it's kept separate for clarity and to simplify pg_dump>.
DEPENDENCY_PIN> (p>)
There is no dependent object; this type of entry is a signal
that the system itself depends on the referenced object, and so
that object must never be deleted. Entries of this type are
created only by initdb. The columns for the
dependent object contain zeroes.
Other dependency flavors might be needed in future.
pg_descriptionpg_description
The catalog pg_description> stores optional descriptions
(comments) for each database object. Descriptions can be manipulated
with the command and viewed with
psql's \d commands.
Descriptions of many built-in system objects are provided in the initial
contents of pg_description.
See also pg_shdescription,
which performs a similar function for descriptions involving objects that
are shared across a database cluster.
pg_description> ColumnsNameTypeReferencesDescriptionobjoidoidany OID columnThe OID of the object this description pertains toclassoidoidpg_class.oidThe OID of the system catalog this object appears inobjsubidint4
For a comment on a table column, this is the column number (the
objoid> and classoid> refer to
the table itself). For all other object types, this column is
zero.
descriptiontextArbitrary text that serves as the description of this object
pg_enumpg_enum
The pg_enum catalog contains entries
showing the values and labels for each enum type. The
internal representation of a given enum value is actually the OID
of its associated row in pg_enum.
pg_enum> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)enumtypidoidpg_type.oidThe OID of the pg_type> entry owning this enum valueenumsortorderfloat4The sort position of this enum value within its enum typeenumlabelnameThe textual label for this enum value
The OIDs for pg_enum rows follow a special
rule: even-numbered OIDs are guaranteed to be ordered in the same way
as the sort ordering of their enum type. That is, if two even OIDs
belong to the same enum type, the smaller OID must have the smaller
enumsortorder value. Odd-numbered OID values
need bear no relationship to the sort order. This rule allows the
enum comparison routines to avoid catalog lookups in many common cases.
The routines that create and alter enum types attempt to assign even
OIDs to enum values whenever possible.
When an enum type is created, its members are assigned sort-order
positions 1..n>. But members added later might be given
negative or fractional values of enumsortorder.
The only requirement on these values is that they be correctly
ordered and unique within each enum type.
pg_event_triggerpg_event_trigger
The catalog pg_event_trigger stores event triggers.
See for more information.
pg_event_trigger> ColumnsNameTypeReferencesDescriptionevtnamenameTrigger name (must be unique)evteventnameIdentifies the event for which this trigger firesevtowneroidpg_authid.oidOwner of the event triggerevtfoidoidpg_proc.oidThe function to be calledevtenabledchar
Controls in which modes
the event trigger fires.
O> = trigger fires in origin> and local> modes,
D> = trigger is disabled,
R> = trigger fires in replica> mode,
A> = trigger fires always.
evttagstext[]
Command tags for which this trigger will fire. If NULL, the firing
of this trigger is not restricted on the basis of the command tag.
pg_extensionpg_extension
The catalog pg_extension stores information
about the installed extensions. See
for details about extensions.
pg_extension> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)extnamenameName of the extensionextowneroidpg_authid.oidOwner of the extensionextnamespaceoidpg_namespace.oidSchema containing the extension's exported objectsextrelocatableboolTrue if extension can be relocated to another schemaextversiontextVersion name for the extensionextconfigoid[]pg_class.oidArray of regclass> OIDs for the extension's configuration
table(s), or NULL> if noneextconditiontext[]Array of WHERE>-clause filter conditions for the
extension's configuration table(s), or NULL> if none
Note that unlike most catalogs with a namespace> column,
extnamespace is not meant to imply
that the extension belongs to that schema. Extension names are never
schema-qualified. Rather, extnamespace
indicates the schema that contains most or all of the extension's
objects. If extrelocatable is true, then
this schema must in fact contain all schema-qualifiable objects
belonging to the extension.
pg_foreign_data_wrapperpg_foreign_data_wrapper
The catalog pg_foreign_data_wrapper stores
foreign-data wrapper definitions. A foreign-data wrapper is the
mechanism by which external data, residing on foreign servers, is
accessed.
pg_foreign_data_wrapper> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)fdwnamenameName of the foreign-data wrapperfdwowneroidpg_authid.oidOwner of the foreign-data wrapperfdwhandleroidpg_proc.oid
References a handler function that is responsible for
supplying execution routines for the foreign-data wrapper.
Zero if no handler is provided
fdwvalidatoroidpg_proc.oid
References a validator function that is responsible for
checking the validity of the options given to the
foreign-data wrapper, as well as options for foreign servers and user
mappings using the foreign-data wrapper. Zero if no validator
is provided
fdwaclaclitem[]
Access privileges; see
and
for details
fdwoptionstext[]
Foreign-data wrapper specific options, as keyword=value> strings
pg_foreign_serverpg_foreign_server
The catalog pg_foreign_server stores
foreign server definitions. A foreign server describes a source
of external data, such as a remote server. Foreign
servers are accessed via foreign-data wrappers.
pg_foreign_server> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)srvnamenameName of the foreign serversrvowneroidpg_authid.oidOwner of the foreign serversrvfdwoidpg_foreign_data_wrapper.oidOID of the foreign-data wrapper of this foreign serversrvtypetextType of the server (optional)srvversiontextVersion of the server (optional)srvaclaclitem[]
Access privileges; see
and
for details
srvoptionstext[]
Foreign server specific options, as keyword=value> strings
pg_foreign_tablepg_foreign_table
The catalog pg_foreign_table contains
auxiliary information about foreign tables. A foreign table is
primarily represented by a pg_class entry,
just like a regular table. Its pg_foreign_table
entry contains the information that is pertinent only to foreign tables
and not any other kind of relation.
pg_foreign_table> ColumnsNameTypeReferencesDescriptionftrelidoidpg_class.oidOID of the pg_class> entry for this foreign tableftserveroidpg_foreign_server.oidOID of the foreign server for this foreign tableftoptionstext[]
Foreign table options, as keyword=value> strings
pg_indexpg_index
The catalog pg_index contains part of the information
about indexes. The rest is mostly in
pg_class.
pg_index> ColumnsNameTypeReferencesDescriptionindexrelidoidpg_class.oidThe OID of the pg_class> entry for this indexindrelidoidpg_class.oidThe OID of the pg_class> entry for the table this index is forindnattsint2The number of columns in the index (duplicates
pg_class.relnatts)indisuniqueboolIf true, this is a unique indexindisprimaryboolIf true, this index represents the primary key of the table
(indisunique> should always be true when this is true)indisexclusionboolIf true, this index supports an exclusion constraintindimmediateboolIf true, the uniqueness check is enforced immediately on
insertion
(irrelevant if indisunique> is not true)indisclusteredboolIf true, the table was last clustered on this indexindisvalidbool
If true, the index is currently valid for queries. False means the
index is possibly incomplete: it must still be modified by
INSERT>/UPDATE> operations, but it cannot safely
be used for queries. If it is unique, the uniqueness property is not
guaranteed true either.
indcheckxminbool
If true, queries must not use the index until the xmin>
of this pg_index> row is below their TransactionXmin
event horizon, because the table may contain broken HOT chains with
incompatible rows that they can see
indisreadybool
If true, the index is currently ready for inserts. False means the
index must be ignored by INSERT>/UPDATE>
operations.
indislivebool
If false, the index is in process of being dropped, and should be
ignored for all purposes (including HOT-safety decisions)
indisreplidentbool
If true this index has been chosen as replica identity>
using ALTER TABLE ... REPLICA IDENTITY USING INDEX
...>
indkeyint2vectorpg_attribute.attnum
This is an array of indnatts values that
indicate which table columns this index indexes. For example a value
of 1 3 would mean that the first and the third table
columns make up the index key. A zero in this array indicates that the
corresponding index attribute is an expression over the table columns,
rather than a simple column reference.
indcollationoidvectorpg_collation.oid
For each column in the index key, this contains the OID of the
collation to use for the index.
indclassoidvectorpg_opclass.oid
For each column in the index key, this contains the OID of
the operator class to use. See
pg_opclass for details.
indoptionint2vector
This is an array of indnatts values that
store per-column flag bits. The meaning of the bits is defined by
the index's access method.
indexprspg_node_tree
Expression trees (in nodeToString()
representation) for index attributes that are not simple column
references. This is a list with one element for each zero
entry in indkey>. Null if all index attributes
are simple references.
indpredpg_node_tree
Expression tree (in nodeToString()
representation) for partial index predicate. Null if not a
partial index.
pg_inheritspg_inherits
The catalog pg_inherits> records information about
table inheritance hierarchies. There is one entry for each direct
child table in the database. (Indirect inheritance can be determined
by following chains of entries.)
pg_inherits> ColumnsNameTypeReferencesDescriptioninhrelidoidpg_class.oid
The OID of the child table
inhparentoidpg_class.oid
The OID of the parent table
inhseqnoint4
If there is more than one direct parent for a child table (multiple
inheritance), this number tells the order in which the
inherited columns are to be arranged. The count starts at 1.
pg_languagepg_language
The catalog pg_language registers
languages in which you can write functions or stored procedures.
See
and for more information about language handlers.
pg_language> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)lannamenameName of the languagelanowneroidpg_authid.oidOwner of the languagelanisplbool
This is false for internal languages (such as
SQL) and true for user-defined languages.
Currently, pg_dump still uses this
to determine which languages need to be dumped, but this might be
replaced by a different mechanism in the future.
lanpltrustedbool
True if this is a trusted language, which means that it is believed
not to grant access to anything outside the normal SQL execution
environment. Only superusers can create functions in untrusted
languages.
lanplcallfoidoidpg_proc.oid
For noninternal languages this references the language
handler, which is a special function that is responsible for
executing all functions that are written in the particular
language
laninlineoidpg_proc.oid
This references a function that is responsible for executing
inline> anonymous code blocks
( blocks).
Zero if inline blocks are not supported.
lanvalidatoroidpg_proc.oid
This references a language validator function that is responsible
for checking the syntax and validity of new functions when they
are created. Zero if no validator is provided.
lanaclaclitem[]
Access privileges; see
and
for details
pg_largeobjectpg_largeobject
The catalog pg_largeobject holds the data making up
large objects. A large object is identified by an OID
assigned when it is created. Each large object is broken into
segments or pages> small enough to be conveniently stored as rows
in pg_largeobject.
The amount of data per page is defined to be LOBLKSIZE> (which is currently
BLCKSZ/4>, or typically 2 kB).
Prior to PostgreSQL> 9.0, there was no permission structure
associated with large objects. As a result,
pg_largeobject was publicly readable and could be
used to obtain the OIDs (and contents) of all large objects in the system.
This is no longer the case; use
pg_largeobject_metadata>
to obtain a list of large object OIDs.
pg_largeobject> ColumnsNameTypeReferencesDescriptionloidoidpg_largeobject_metadata.oidIdentifier of the large object that includes this pagepagenoint4Page number of this page within its large object
(counting from zero)databytea
Actual data stored in the large object.
This will never be more than LOBLKSIZE> bytes and might be less.
Each row of pg_largeobject holds data
for one page of a large object, beginning at
byte offset (pageno * LOBLKSIZE>) within the object. The implementation
allows sparse storage: pages might be missing, and might be shorter than
LOBLKSIZE> bytes even if they are not the last page of the object.
Missing regions within a large object read as zeroes.
pg_largeobject_metadatapg_largeobject_metadata
The catalog pg_largeobject_metadata
holds metadata associated with large objects. The actual large object
data is stored in
pg_largeobject>.
pg_largeobject_metadata> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)lomowneroidpg_authid.oidOwner of the large objectlomaclaclitem[]
Access privileges; see
and
for details
pg_namespacepg_namespace
The catalog pg_namespace> stores namespaces.
A namespace is the structure underlying SQL schemas: each namespace
can have a separate collection of relations, types, etc. without name
conflicts.
pg_namespace> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)nspnamenameName of the namespacenspowneroidpg_authid.oidOwner of the namespacenspaclaclitem[]
Access privileges; see
and
for details
pg_opclasspg_opclass
The catalog pg_opclass defines
index access method operator classes. Each operator class defines
semantics for index columns of a particular data type and a particular
index access method. An operator class essentially specifies that a
particular operator family is applicable to a particular indexable column
data type. The set of operators from the family that are actually usable
with the indexed column are whichever ones accept the column's data type
as their left-hand input.
Operator classes are described at length in .
pg_opclass> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)opcmethodoidpg_am.oidIndex access method operator class is foropcnamenameName of this operator classopcnamespaceoidpg_namespace.oidNamespace of this operator classopcowneroidpg_authid.oidOwner of the operator classopcfamilyoidpg_opfamily.oidOperator family containing the operator classopcintypeoidpg_type.oidData type that the operator class indexesopcdefaultboolTrue if this operator class is the default for opcintype>opckeytypeoidpg_type.oidType of data stored in index, or zero if same as opcintype>
An operator class's opcmethod> must match the
opfmethod> of its containing operator family.
Also, there must be no more than one pg_opclass
row having opcdefault> true for any given combination of
opcmethod> and opcintype>.
pg_operatorpg_operator
The catalog pg_operator> stores information about operators.
See
and for more information.
pg_operator> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)oprnamenameName of the operatoroprnamespaceoidpg_namespace.oid
The OID of the namespace that contains this operator
oprowneroidpg_authid.oidOwner of the operatoroprkindcharb> = infix (both), l> = prefix
(left), r> = postfix (right)
oprcanmergeboolThis operator supports merge joinsoprcanhashboolThis operator supports hash joinsoprleftoidpg_type.oidType of the left operandoprrightoidpg_type.oidType of the right operandoprresultoidpg_type.oidType of the resultoprcomoidpg_operator.oidCommutator of this operator, if anyoprnegateoidpg_operator.oidNegator of this operator, if anyoprcoderegprocpg_proc.oidFunction that implements this operatoroprrestregprocpg_proc.oidRestriction selectivity estimation function for this operatoroprjoinregprocpg_proc.oidJoin selectivity estimation function for this operator
Unused column contain zeroes. For example, oprleft
is zero for a prefix operator.
pg_opfamilypg_opfamily
The catalog pg_opfamily defines operator families.
Each operator family is a collection of operators and associated
support routines that implement the semantics specified for a particular
index access method. Furthermore, the operators in a family are all
compatible>, in a way that is specified by the access method.
The operator family concept allows cross-data-type operators to be used
with indexes and to be reasoned about using knowledge of access method
semantics.
Operator families are described at length in .
pg_opfamily> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)opfmethodoidpg_am.oidIndex access method operator family is foropfnamenameName of this operator familyopfnamespaceoidpg_namespace.oidNamespace of this operator familyopfowneroidpg_authid.oidOwner of the operator family
The majority of the information defining an operator family is not in its
pg_opfamily row, but in the associated rows in
pg_amop,
pg_amproc,
and
pg_opclass.
pg_pltemplatepg_pltemplate
The catalog pg_pltemplate stores
template> information for procedural languages.
A template for a language allows the language to be created in a
particular database by a simple CREATE LANGUAGE> command,
with no need to specify implementation details.
Unlike most system catalogs, pg_pltemplate
is shared across all databases of a cluster: there is only one
copy of pg_pltemplate per cluster, not
one per database. This allows the information to be accessible in
each database as it is needed.
pg_pltemplate> ColumnsNameTypeDescriptiontmplnamenameName of the language this template is fortmpltrustedbooleanTrue if language is considered trustedtmpldbacreatebooleanTrue if language may be created by a database ownertmplhandlertextName of call handler functiontmplinlinetextName of anonymous-block handler function, or null if nonetmplvalidatortextName of validator function, or null if nonetmpllibrarytextPath of shared library that implements languagetmplaclaclitem[]Access privileges for template (not actually used)
There are not currently any commands that manipulate procedural language
templates; to change the built-in information, a superuser must modify
the table using ordinary INSERT, DELETE,
or UPDATE commands.
It is likely that pg_pltemplate> will be removed in some
future release of PostgreSQL, in favor of
keeping this knowledge about procedural languages in their respective
extension installation scripts.
pg_policypg_policy
The catalog pg_policy stores row level
security policies for tables. A policy includes the kind of
command that it applies to (possibly all commands), the roles that it
applies to, the expression to be added as a security-barrier
qualification to queries that include the table, and the expression
to be added as a WITH CHECK> option for queries that attempt to
add new records to the table.
pg_policy ColumnsNameTypeReferencesDescriptionpolnamenameThe name of the policypolrelidoidpg_class.oidThe table to which the policy appliespolcmdcharThe command type to which the policy is applied:
r> for SELECT>,
a> for INSERT>,
w> for UPDATE>,
d> for DELETE>,
or *> for allpolrolesoid[]pg_authid.oidThe roles to which the policy is appliedpolqualpg_node_treeThe expression tree to be added to the security barrier qualifications for queries that use the tablepolwithcheckpg_node_treeThe expression tree to be added to the WITH CHECK qualifications for queries that attempt to add rows to the table
Policies stored in pg_policy> are applied only when
pg_class>.relrowsecurity> is set for
their table.
pg_procpg_proc
The catalog pg_proc> stores information about functions (or procedures).
See
and for more information.
The table contains data for aggregate functions as well as plain functions.
If proisagg is true, there should be a matching
row in pg_aggregate.
pg_proc> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)pronamenameName of the functionpronamespaceoidpg_namespace.oid
The OID of the namespace that contains this function
proowneroidpg_authid.oidOwner of the functionprolangoidpg_language.oidImplementation language or call interface of this functionprocostfloat4Estimated execution cost (in units of
); if proretset>,
this is cost per row returnedprorowsfloat4Estimated number of result rows (zero if not proretset>)provariadicoidpg_type.oidData type of the variadic array parameter's elements,
or zero if the function does not have a variadic parameterprotransformregprocpg_proc.oidCalls to this function can be simplified by this other function
(see )proisaggboolFunction is an aggregate functionproiswindowboolFunction is a window functionprosecdefboolFunction is a security definer (i.e., a setuid>
function)proleakproofbool
The function has no side effects. No information about the
arguments is conveyed except via the return value. Any function
that might throw an error depending on the values of its arguments
is not leak-proof.
proisstrictbool
Function returns null if any call argument is null. In that
case the function won't actually be called at all. Functions
that are not strict must be prepared to handle
null inputs.
proretsetboolFunction returns a set (i.e., multiple values of the specified
data type)provolatilecharprovolatile tells whether the function's
result depends only on its input arguments, or is affected by outside
factors.
It is i for immutable> functions,
which always deliver the same result for the same inputs.
It is s for stable> functions,
whose results (for fixed inputs) do not change within a scan.
It is v for volatile> functions,
whose results might change at any time. (Use v also
for functions with side-effects, so that calls to them cannot get
optimized away.)
pronargsint2Number of input argumentspronargdefaultsint2Number of arguments that have defaultsprorettypeoidpg_type.oidData type of the return valueproargtypesoidvectorpg_type.oid
An array with the data types of the function arguments. This includes
only input arguments (including INOUT and
VARIADIC> arguments), and thus represents
the call signature of the function.
proallargtypesoid[]pg_type.oid
An array with the data types of the function arguments. This includes
all arguments (including OUT and
INOUT arguments); however, if all the
arguments are IN arguments, this field will be null.
Note that subscripting is 1-based, whereas for historical reasons
proargtypes> is subscripted from 0.
proargmodeschar[]
An array with the modes of the function arguments, encoded as
i for IN> arguments,
o for OUT> arguments,
b for INOUT> arguments,
v for VARIADIC> arguments,
t for TABLE> arguments.
If all the arguments are IN arguments,
this field will be null.
Note that subscripts correspond to positions of
proallargtypes> not proargtypes>.
proargnamestext[]
An array with the names of the function arguments.
Arguments without a name are set to empty strings in the array.
If none of the arguments have a name, this field will be null.
Note that subscripts correspond to positions of
proallargtypes> not proargtypes>.
proargdefaultspg_node_tree
Expression trees (in nodeToString() representation)
for default values. This is a list with
pronargdefaults> elements, corresponding to the last
N> input> arguments (i.e., the last
N> proargtypes> positions).
If none of the arguments have defaults, this field will be null.
protrftypesoid[]
Data type OIDs for which to apply transforms.
prosrctext
This tells the function handler how to invoke the function. It
might be the actual source code of the function for interpreted
languages, a link symbol, a file name, or just about anything
else, depending on the implementation language/call convention.
probintext
Additional information about how to invoke the function.
Again, the interpretation is language-specific.
proconfigtext[]Function's local settings for run-time configuration variablesproaclaclitem[]
Access privileges; see
and
for details
For compiled functions, both built-in and dynamically loaded,
prosrc contains the function's C-language
name (link symbol). For all other currently-known language types,
prosrc contains the function's source
text. probin is unused except for
dynamically-loaded C functions, for which it gives the name of the
shared library file containing the function.
pg_rangepg_range
The catalog pg_range stores information about
range types. This is in addition to the types' entries in
pg_type.
pg_range> ColumnsNameTypeReferencesDescriptionrngtypidoidpg_type.oidOID of the range typerngsubtypeoidpg_type.oidOID of the element type (subtype) of this range typerngcollationoidpg_collation.oidOID of the collation used for range comparisons, or 0 if nonerngsubopcoidpg_opclass.oidOID of the subtype's operator class used for range comparisonsrngcanonicalregprocpg_proc.oidOID of the function to convert a range value into canonical form,
or 0 if nonerngsubdiffregprocpg_proc.oidOID of the function to return the difference between two element
values as double precision, or 0 if none
rngsubopc> (plus rngcollation>, if the
element type is collatable) determines the sort ordering used by the range
type. rngcanonical> is used when the element type is
discrete. rngsubdiff> is optional but should be supplied to
improve performance of GiST indexes on the range type.
pg_rewritepg_rewrite
The catalog pg_rewrite stores rewrite rules for tables and views.
pg_rewrite> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)rulenamenameRule nameev_classoidpg_class.oidThe table this rule is forev_typechar
Event type that the rule is for: 1 = SELECT>, 2 =
UPDATE>, 3 = INSERT>, 4 =
DELETE>
ev_enabledchar
Controls in which modes
the rule fires.
O> = rule fires in origin> and local> modes,
D> = rule is disabled,
R> = rule fires in replica> mode,
A> = rule fires always.
is_insteadboolTrue if the rule is an INSTEAD ruleev_qualpg_node_tree
Expression tree (in the form of a
nodeToString() representation) for the
rule's qualifying condition
ev_actionpg_node_tree
Query tree (in the form of a
nodeToString() representation) for the
rule's action
pg_class.relhasrules
must be true if a table has any rules in this catalog.
pg_replication_originpg_replication_origin
The pg_replication_origin catalog contains
all replication origins created. For more on replication origins
see .
pg_replication_origin ColumnsNameTypeReferencesDescriptionroidentOidA unique, cluster-wide identifier for the replication
origin. Should never leave the system.ronametextThe external, user defined, name of a replication
origin.
pg_replication_origin_statuspg_replication_origin_status
The pg_replication_origin_status view
contains information about how far replay for a certain origin has
progressed. For more on replication origins
see .
pg_replication_origin_status ColumnsNameTypeReferencesDescriptionlocal_idOidpg_replication_origin.roidentinternal node identifierexternal_idtextpg_replication_origin.ronameexternal node identifierremote_lsnpg_lsnThe origin node's LSN up to which data has been replicated.local_lsnpg_lsnThis node's LSN that at
which remote_lsn has been replicated. Used to
flush commit records before persisting data to disk when using
asynchronous commits.
pg_replication_slotspg_replication_slots
The pg_replication_slots view provides a listing
of all replication slots that currently exist on the database cluster,
along with their current state.
For more on replication slots,
see and .
pg_replication_slots ColumnsNameTypeReferencesDescriptionslot_namenameA unique, cluster-wide identifier for the replication slotpluginnameThe base name of the shared object containing the output plugin this logical slot is using, or null for physical slots.slot_typetextThe slot type - physical> or logical>datoidoidpg_database.oidThe OID of the database this slot is associated with, or
null. Only logical slots have an associated database.databasetextpg_database.datnameThe name of the database this slot is associated with, or
null. Only logical slots have an associated database.activebooleanTrue if this slot is currently actively being usedactive_pidintegerThe process ID of the session using this slot if the slot
is currently actively being used. NULL if
inactive.
xminxidThe oldest transaction that this slot needs the database to
retain. VACUUM cannot remove tuples deleted
by any later transaction.
catalog_xminxidThe oldest transaction affecting the system catalogs that this
slot needs the database to retain. VACUUM cannot
remove catalog tuples deleted by any later transaction.
restart_lsnpg_lsnThe address (LSN) of oldest WAL which still
might be required by the consumer of this slot and thus won't be
automatically removed during checkpoints.
pg_seclabelpg_seclabel
The catalog pg_seclabel stores security
labels on database objects. Security labels can be manipulated
with the command. For an easier
way to view security labels, see .
See also pg_shseclabel,
which performs a similar function for security labels of database objects
that are shared across a database cluster.
pg_seclabel ColumnsNameTypeReferencesDescriptionobjoidoidany OID columnThe OID of the object this security label pertains toclassoidoidpg_class.oidThe OID of the system catalog this object appears inobjsubidint4
For a security label on a table column, this is the column number (the
objoid> and classoid> refer to
the table itself). For all other object types, this column is
zero.
providertextThe label provider associated with this label.labeltextThe security label applied to this object.
pg_shdependpg_shdepend
The catalog pg_shdepend records the
dependency relationships between database objects and shared objects,
such as roles. This information allows
PostgreSQL to ensure that those objects are
unreferenced before attempting to delete them.
See also pg_depend,
which performs a similar function for dependencies involving objects
within a single database.
Unlike most system catalogs, pg_shdepend
is shared across all databases of a cluster: there is only one
copy of pg_shdepend per cluster, not
one per database.
pg_shdepend> ColumnsNameTypeReferencesDescriptiondbidoidpg_database.oidThe OID of the database the dependent object is in,
or zero for a shared objectclassidoidpg_class.oidThe OID of the system catalog the dependent object is inobjidoidany OID columnThe OID of the specific dependent objectobjsubidint4
For a table column, this is the column number (the
objid> and classid> refer to the
table itself). For all other object types, this column is zero.
refclassidoidpg_class.oidThe OID of the system catalog the referenced object is in
(must be a shared catalog)refobjidoidany OID columnThe OID of the specific referenced objectdeptypechar
A code defining the specific semantics of this dependency relationship; see text
In all cases, a pg_shdepend entry indicates that
the referenced object cannot be dropped without also dropping the dependent
object. However, there are several subflavors identified by
deptype>:
SHARED_DEPENDENCY_OWNER> (o>)
The referenced object (which must be a role) is the owner of the
dependent object.
SHARED_DEPENDENCY_ACL> (a>)
The referenced object (which must be a role) is mentioned in the
ACL (access control list, i.e., privileges list) of the
dependent object. (A SHARED_DEPENDENCY_ACL> entry is
not made for the owner of the object, since the owner will have
a SHARED_DEPENDENCY_OWNER> entry anyway.)
SHARED_DEPENDENCY_PIN> (p>)
There is no dependent object; this type of entry is a signal
that the system itself depends on the referenced object, and so
that object must never be deleted. Entries of this type are
created only by initdb. The columns for the
dependent object contain zeroes.
Other dependency flavors might be needed in future. Note in particular
that the current definition only supports roles as referenced objects.
pg_shdescriptionpg_shdescription
The catalog pg_shdescription stores optional
descriptions (comments) for shared database objects. Descriptions can be
manipulated with the command and viewed with
psql's \d commands.
See also pg_description,
which performs a similar function for descriptions involving objects
within a single database.
Unlike most system catalogs, pg_shdescription
is shared across all databases of a cluster: there is only one
copy of pg_shdescription per cluster, not
one per database.
pg_shdescription> ColumnsNameTypeReferencesDescriptionobjoidoidany OID columnThe OID of the object this description pertains toclassoidoidpg_class.oidThe OID of the system catalog this object appears indescriptiontextArbitrary text that serves as the description of this object
pg_shseclabelpg_shseclabel
The catalog pg_shseclabel stores security
labels on shared database objects. Security labels can be manipulated
with the command. For an easier
way to view security labels, see .
See also pg_seclabel,
which performs a similar function for security labels involving objects
within a single database.
Unlike most system catalogs, pg_shseclabel
is shared across all databases of a cluster: there is only one
copy of pg_shseclabel per cluster, not
one per database.
pg_shseclabel ColumnsNameTypeReferencesDescriptionobjoidoidany OID columnThe OID of the object this security label pertains toclassoidoidpg_class.oidThe OID of the system catalog this object appears inprovidertextThe label provider associated with this label.labeltextThe security label applied to this object.
pg_statisticpg_statistic
The catalog pg_statistic stores
statistical data about the contents of the database. Entries are
created by
and subsequently used by the query planner. Note that all the
statistical data is inherently approximate, even assuming that it
is up-to-date.
Normally there is one entry, with stainherit> =
false>, for each table column that has been analyzed.
If the table has inheritance children, a second entry with
stainherit> = true> is also created. This row
represents the column's statistics over the inheritance tree, i.e.,
statistics for the data you'd see with
SELECT column> FROM table>*,
whereas the stainherit> = false> row represents
the results of
SELECT column> FROM ONLY table>.
pg_statistic also stores statistical data about
the values of index expressions. These are described as if they were
actual data columns; in particular, starelid
references the index. No entry is made for an ordinary non-expression
index column, however, since it would be redundant with the entry
for the underlying table column. Currently, entries for index expressions
always have stainherit> = false>.
Since different kinds of statistics might be appropriate for different
kinds of data, pg_statistic is designed not
to assume very much about what sort of statistics it stores. Only
extremely general statistics (such as nullness) are given dedicated
columns in pg_statistic. Everything else
is stored in slots, which are groups of associated columns
whose content is identified by a code number in one of the slot's columns.
For more information see
src/include/catalog/pg_statistic.h.
pg_statistic should not be readable by the
public, since even statistical information about a table's contents
might 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_statistic that only exposes information
about those tables that are readable by the current user.
pg_statistic> ColumnsNameTypeReferencesDescriptionstarelidoidpg_class.oidThe table or index that the described column belongs tostaattnumint2pg_attribute.attnumThe number of the described columnstainheritboolIf true, the stats include inheritance child columns, not just the
values in the specified relationstanullfracfloat4The fraction of the column's entries that are nullstawidthint4The average stored width, in bytes, of nonnull entriesstadistinctfloat4The number of distinct nonnull data values in the column.
A value greater than zero is the actual number of distinct values.
A value less than zero is the negative of a multiplier for the number
of rows in the table; for example, a column in which values appear about
twice on the average could be represented by
stadistinct> = -0.5.
A zero value means the number of distinct values is unknown.
stakindN>int2
A code number indicating the kind of statistics stored in the
N>th slot of the
pg_statistic row.
staopN>oidpg_operator.oid
An operator used to derive the statistics stored in the
N>th slot. For example, a
histogram slot would show the < operator
that defines the sort order of the data.
stanumbersN>float4[]
Numerical statistics of the appropriate kind for the
N>th slot, or null if the slot
kind does not involve numerical values
stavaluesN>anyarray
Column data values of the appropriate kind for the
N>th slot, or null if the slot
kind does not store any data values. Each array's element
values are actually of the specific column's data type, or a related
type such as an array's element type, so there is no way to define
these columns' type more specifically than anyarray>.
pg_tabesample_methodpg_am
The catalog pg_tablesample_method stores
information about table sampling methods which can be used in
TABLESAMPLE clause of a SELECT
statement.
pg_tablesample_method> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)tsmnamenameName of the sampling methodtsmseqscanboolIf true, the sampling method scans the whole table sequentially.
tsmpagemodeboolIf true, the sampling method always reads the pages completely.
tsminitregprocpg_proc.oidInitialize the sampling scan functiontsmnextblockregprocpg_proc.oidGet next block number functiontsmnexttupleregprocpg_proc.oidGet next tuple offset functiontsmexaminetupleregprocpg_proc.oidFunction which examines the tuple contents and decides if to
return it, or zero if nonetsmendregprocpg_proc.oidEnd the sampling scan functiontsmresetregprocpg_proc.oidRestart the state of sampling scan functiontsmcostregprocpg_proc.oidCosting function
pg_tablespacepg_tablespace
The catalog pg_tablespace stores information
about the available tablespaces. Tables can be placed in particular
tablespaces to aid administration of disk layout.
Unlike most system catalogs, pg_tablespace
is shared across all databases of a cluster: there is only one
copy of pg_tablespace per cluster, not
one per database.
pg_tablespace> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)spcnamenameTablespace namespcowneroidpg_authid.oidOwner of the tablespace, usually the user who created itspcaclaclitem[]
Access privileges; see
and
for details
spcoptionstext[]
Tablespace-level options, as keyword=value> strings
pg_transformpg_transform
The catalog pg_transform stores information about
transforms, which are a mechanism to adapt data types to procedural
languages. See for more information.
pg_transform> ColumnsNameTypeReferencesDescriptiontrftypeoidpg_type.oidOID of the data type this transform is fortrflangoidpg_language.oidOID of the language this transform is fortrffromsqlregprocpg_proc.oid
The OID of the function to use when converting the data type for input
to the procedural language (e.g., function parameters). Zero is stored
if this operation is not supported.
trftosqlregprocpg_proc.oid
The OID of the function to use when converting output from the
procedural language (e.g., return values) to the data type. Zero is
stored if this operation is not supported.
pg_triggerpg_trigger
The catalog pg_trigger stores triggers on tables
and views.
See
for more information.
pg_trigger> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)tgrelidoidpg_class.oidThe table this trigger is ontgnamenameTrigger name (must be unique among triggers of same table)tgfoidoidpg_proc.oidThe function to be calledtgtypeint2Bit mask identifying trigger firing conditionstgenabledchar
Controls in which modes
the trigger fires.
O> = trigger fires in origin> and local> modes,
D> = trigger is disabled,
R> = trigger fires in replica> mode,
A> = trigger fires always.
tgisinternalboolTrue if trigger is internally generated (usually, to enforce
the constraint identified by tgconstraint>)tgconstrrelidoidpg_class.oidThe table referenced by a referential integrity constrainttgconstrindidoidpg_class.oidThe index supporting a unique, primary key, referential integrity,
or exclusion constrainttgconstraintoidpg_constraint.oidThe pg_constraint> entry associated with the trigger, if anytgdeferrableboolTrue if constraint trigger is deferrabletginitdeferredboolTrue if constraint trigger is initially deferredtgnargsint2Number of argument strings passed to trigger functiontgattrint2vectorpg_attribute.attnumColumn numbers, if trigger is column-specific; otherwise an
empty arraytgargsbyteaArgument strings to pass to trigger, each NULL-terminatedtgqualpg_node_treeExpression tree (in nodeToString()
representation) for the trigger's WHEN> condition, or null
if none
Currently, column-specific triggering is supported only for
UPDATE> events, and so tgattr> is relevant
only for that event type. tgtype might
contain bits for other event types as well, but those are presumed
to be table-wide regardless of what is in tgattr>.
When tgconstraint> is nonzero,
tgconstrrelid>, tgconstrindid>,
tgdeferrable>, and tginitdeferred> are
largely redundant with the referenced pg_constraint> entry.
However, it is possible for a non-deferrable trigger to be associated
with a deferrable constraint: foreign key constraints can have some
deferrable and some non-deferrable triggers.
pg_class.relhastriggers
must be true if a relation has any triggers in this catalog.
pg_ts_configpg_ts_config
The pg_ts_config catalog contains entries
representing text search configurations. A configuration specifies
a particular text search parser and a list of dictionaries to use
for each of the parser's output token types. The parser is shown
in the pg_ts_config entry, but the
token-to-dictionary mapping is defined by subsidiary entries in pg_ts_config_map.
PostgreSQL's text search features are
described at length in .
pg_ts_config> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)cfgnamenameText search configuration namecfgnamespaceoidpg_namespace.oid
The OID of the namespace that contains this configuration
cfgowneroidpg_authid.oidOwner of the configurationcfgparseroidpg_ts_parser.oidThe OID of the text search parser for this configuration
pg_ts_config_mappg_ts_config_map
The pg_ts_config_map catalog contains entries
showing which text search dictionaries should be consulted, and in
what order, for each output token type of each text search configuration's
parser.
PostgreSQL's text search features are
described at length in .
pg_ts_config_map> ColumnsNameTypeReferencesDescriptionmapcfgoidpg_ts_config.oidThe OID of the pg_ts_config> entry owning this map entrymaptokentypeintegerA token type emitted by the configuration's parsermapseqnointegerOrder in which to consult this entry (lower
mapseqno>s first)mapdictoidpg_ts_dict.oidThe OID of the text search dictionary to consult
pg_ts_dictpg_ts_dict
The pg_ts_dict catalog contains entries
defining text search dictionaries. A dictionary depends on a text
search template, which specifies all the implementation functions
needed; the dictionary itself provides values for the user-settable
parameters supported by the template. This division of labor allows
dictionaries to be created by unprivileged users. The parameters
are specified by a text string dictinitoption>,
whose format and meaning vary depending on the template.
PostgreSQL's text search features are
described at length in .
pg_ts_dict> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)dictnamenameText search dictionary namedictnamespaceoidpg_namespace.oid
The OID of the namespace that contains this dictionary
dictowneroidpg_authid.oidOwner of the dictionarydicttemplateoidpg_ts_template.oidThe OID of the text search template for this dictionarydictinitoptiontextInitialization option string for the template
pg_ts_parserpg_ts_parser
The pg_ts_parser catalog contains entries
defining text search parsers. A parser is responsible for splitting
input text into lexemes and assigning a token type to each lexeme.
Since a parser must be implemented by C-language-level functions,
creation of new parsers is restricted to database superusers.
PostgreSQL's text search features are
described at length in .
pg_ts_parser> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)prsnamenameText search parser nameprsnamespaceoidpg_namespace.oid
The OID of the namespace that contains this parser
prsstartregprocpg_proc.oidOID of the parser's startup functionprstokenregprocpg_proc.oidOID of the parser's next-token functionprsendregprocpg_proc.oidOID of the parser's shutdown functionprsheadlineregprocpg_proc.oidOID of the parser's headline functionprslextyperegprocpg_proc.oidOID of the parser's lextype function
pg_ts_templatepg_ts_template
The pg_ts_template catalog contains entries
defining text search templates. A template is the implementation
skeleton for a class of text search dictionaries.
Since a template must be implemented by C-language-level functions,
creation of new templates is restricted to database superusers.
PostgreSQL's text search features are
described at length in .
pg_ts_template> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)tmplnamenameText search template nametmplnamespaceoidpg_namespace.oid
The OID of the namespace that contains this template
tmplinitregprocpg_proc.oidOID of the template's initialization functiontmpllexizeregprocpg_proc.oidOID of the template's lexize function
pg_typepg_type
The catalog pg_type stores information about data
types. Base types and enum types (scalar types) are created with
, and
domains with
.
A composite type is automatically created for each table in the database, to
represent the row structure of the table. It is also possible to create
composite types with CREATE TYPE AS.
pg_type> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)typnamenameData type nametypnamespaceoidpg_namespace.oid
The OID of the namespace that contains this type
typowneroidpg_authid.oidOwner of the typetyplenint2
For a fixed-size type, typlen is the number
of bytes in the internal representation of the type. But for a
variable-length type, typlen is negative.
-1 indicates a varlena> type (one that has a length word),
-2 indicates a null-terminated C string.
typbyvalbooltypbyval determines whether internal
routines pass a value of this type by value or by reference.
typbyval had better be false if
typlen is not 1, 2, or 4 (or 8 on machines
where Datum is 8 bytes).
Variable-length types are always passed by reference. Note that
typbyval can be false even if the
length would allow pass-by-value.
typtypechartyptype is
b for a base type,
c for a composite type (e.g., a table's row type),
d for a domain,
e for an enum type,
p for a pseudo-type, or
r for a range type.
See also typrelid and
typbasetype.
typcategorychartypcategory is an arbitrary classification
of data types that is used by the parser to determine which implicit
casts should be preferred>.
See .
typispreferredbool
True if the type is a preferred cast target within its
typcategorytypisdefinedbool
True if the type is defined, false if this is a placeholder
entry for a not-yet-defined type. When
typisdefined is false, nothing
except the type name, namespace, and OID can be relied on.
typdelimchar
Character that separates two values of this type when parsing
array input. Note that the delimiter is associated with the array
element data type, not the array data type.
typrelidoidpg_class.oid
If this is a composite type (see
typtype), then this column points to
the pg_class entry that defines the
corresponding table. (For a free-standing composite type, the
pg_class entry doesn't really represent
a table, but it is needed anyway for the type's
pg_attribute entries to link to.)
Zero for non-composite types.
typelemoidpg_type.oid
If typelem is not 0 then it
identifies another row in pg_type.
The current type can then be subscripted like an array yielding
values of type typelem. A
true array type is variable length
(typlen = -1),
but some fixed-length (typlen > 0) types
also have nonzero typelem, for example
name and point.
If a fixed-length type has a typelem then
its internal representation must be some number of values of the
typelem data type with no other data.
Variable-length array types have a header defined by the array
subroutines.
typarrayoidpg_type.oid
If typarray is not 0 then it
identifies another row in pg_type, which
is the true array type having this type as element
typinputregprocpg_proc.oidInput conversion function (text format)typoutputregprocpg_proc.oidOutput conversion function (text format)typreceiveregprocpg_proc.oidInput conversion function (binary format), or 0 if nonetypsendregprocpg_proc.oidOutput conversion function (binary format), or 0 if nonetypmodinregprocpg_proc.oidType modifier input function, or 0 if type does not support modifierstypmodoutregprocpg_proc.oidType modifier output function, or 0 to use the standard formattypanalyzeregprocpg_proc.oidCustom ANALYZE function, or 0 to use the standard functiontypalignchartypalign is the alignment required
when storing a value of this type. It applies to storage on
disk as well as most representations of the value inside
PostgreSQL>.
When multiple values are stored consecutively, such
as in the representation of a complete row on disk, padding is
inserted before a datum of this type so that it begins on the
specified boundary. The alignment reference is the beginning
of the first datum in the sequence.
Possible values are:
c> = char alignment, i.e., no alignment needed.s> = short alignment (2 bytes on most machines).i> = int alignment (4 bytes on most machines).d> = double alignment (8 bytes on many machines, but by no means all).
For types used in system tables, it is critical that the size
and alignment defined in pg_type
agree with the way that the compiler will lay out the column in
a structure representing a table row.
typstoragechartypstorage tells for varlena
types (those with typlen = -1) if
the type is prepared for toasting and what the default strategy
for attributes of this type should be.
Possible values are
p>: Value must always be stored plain.e>: Value can be stored in a secondary
relation (if relation has one, see
pg_class.reltoastrelid).
m>: Value can be stored compressed inline.x>: Value can be stored compressed inline or stored in secondary storage.
Note that m> columns can also be moved out to secondary
storage, but only as a last resort (e> and x> columns are
moved first).
typnotnullbooltypnotnull represents a not-null
constraint on a type. Used for domains only.
typbasetypeoidpg_type.oid
If this is a domain (see typtype), then
typbasetype identifies the type that this
one is based on. Zero if this type is not a domain.
typtypmodint4
Domains use typtypmod to record the typmod>
to be applied to their base type (-1 if base type does not use a
typmod>). -1 if this type is not a domain.
typndimsint4typndims is the number of array dimensions
for a domain over an array (that is, typbasetype> is
an array type).
Zero for types other than domains over array types.
typcollationoidpg_collation.oidtypcollation specifies the collation
of the type. If the type does not support collations, this will
be zero. A base type that supports collations will have
DEFAULT_COLLATION_OID here. A domain over a
collatable type can have some other collation OID, if one was
specified for the domain.
typdefaultbinpg_node_tree
If typdefaultbin> is not null, it is the
nodeToString()
representation of a default expression for the type. This is
only used for domains.
typdefaulttexttypdefault> is null if the type has no associated
default value. If typdefaultbin> is not null,
typdefault> must contain a human-readable version of the
default expression represented by typdefaultbin>. If
typdefaultbin> is null and typdefault> is
not, then typdefault> is the external representation of
the type's default value, which can be fed to the type's input
converter to produce a constant.
typaclaclitem[]
Access privileges; see
and
for details
lists the system-defined values
of typcategory>. Any future additions to this list will
also be upper-case ASCII letters. All other ASCII characters are reserved
for user-defined categories.
pg_user_mappingpg_user_mapping
The catalog pg_user_mapping stores
the mappings from local user to remote. Access to this catalog is
restricted from normal users, use the view
pg_user_mappings
instead.
pg_user_mapping> ColumnsNameTypeReferencesDescriptionoidoidRow identifier (hidden attribute; must be explicitly selected)umuseroidpg_authid.oidOID of the local role being mapped, 0 if the user mapping is publicumserveroidpg_foreign_server.oid
The OID of the foreign server that contains this mapping
umoptionstext[]
User mapping specific options, as keyword=value> strings
System Views
In addition to the system catalogs, PostgreSQL
provides a number of built-in views. Some system views provide convenient
access to some commonly used queries on the system catalogs. Other views
provide access to internal server state.
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.
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 .
Except where noted, all the views described here are read-only.
System ViewsView NamePurposepg_available_extensionsavailable extensionspg_available_extension_versionsavailable versions of extensionspg_cursorsopen cursorspg_groupgroups of database userspg_indexesindexespg_lockscurrently held lockspg_matviewsmaterialized viewspg_policiespoliciespg_prepared_statementsprepared statementspg_prepared_xactsprepared transactionspg_rolesdatabase rolespg_rulesrulespg_seclabelssecurity labelspg_settingsparameter settingspg_file_settingsfile location of parameter settingspg_shadowdatabase userspg_statsplanner statisticspg_tablestablespg_timezone_abbrevstime zone abbreviationspg_timezone_namestime zone namespg_userdatabase userspg_user_mappingsuser mappingspg_viewsviews
pg_available_extensionspg_available_extensions
The pg_available_extensions view lists the
extensions that are available for installation.
See also the
pg_extension
catalog, which shows the extensions currently installed.
pg_available_extensions> ColumnsNameTypeDescriptionnamenameExtension namedefault_versiontextName of default version, or NULL if none is
specifiedinstalled_versiontextCurrently installed version of the extension,
or NULL if not installedcommenttextComment string from the extension's control file
The pg_available_extensions view is read only.
pg_available_extension_versionspg_available_extension_versions
The pg_available_extension_versions view lists the
specific extension versions that are available for installation.
See also the pg_extension
catalog, which shows the extensions currently installed.
pg_available_extension_versions> ColumnsNameTypeDescriptionnamenameExtension nameversiontextVersion nameinstalledboolTrue if this version of this extension is currently
installedsuperuserboolTrue if only superusers are allowed to install this extensionrelocatableboolTrue if extension can be relocated to another schemaschemanameName of the schema that the extension must be installed into,
or NULL if partially or fully relocatablerequiresname[]Names of prerequisite extensions,
or NULL if nonecommenttextComment string from the extension's control file
The pg_available_extension_versions view is read
only.
pg_cursorspg_cursors
The pg_cursors view lists the cursors that
are currently available. Cursors can be defined in several ways:
via the
statement in SQL
via the Bind message in the frontend/backend protocol, as
described in
via the Server Programming Interface (SPI), as described in
The pg_cursors view displays cursors
created by any of these means. Cursors only exist for the duration
of the transaction that defines them, unless they have been
declared WITH HOLD. Therefore non-holdable
cursors are only present in the view until the end of their
creating transaction.
Cursors are used internally to implement some of the components
of PostgreSQL>, such as procedural languages.
Therefore, the pg_cursors> view might include cursors
that have not been explicitly created by the user.
pg_cursors> ColumnsNameTypeDescriptionnametextThe name of the cursorstatementtextThe verbatim query string submitted to declare this cursoris_holdablebooleantrue if the cursor is holdable (that is, it
can be accessed after the transaction that declared the cursor
has committed); false otherwise
is_binarybooleantrue if the cursor was declared
BINARY; false
otherwise
is_scrollablebooleantrue> if the cursor is scrollable (that is, it
allows rows to be retrieved in a nonsequential manner);
false otherwise
creation_timetimestamptzThe time at which the cursor was declared
The pg_cursors view is read only.
pg_grouppg_group
The view pg_group exists for backwards
compatibility: it emulates a catalog that existed in
PostgreSQL before version 8.1.
It shows the names and members of all roles that are marked as not
rolcanlogin>, which is an approximation to the set
of roles that are being used as groups.
pg_group> ColumnsNameTypeReferencesDescriptiongronamenamepg_authid.rolnameName of the groupgrosysidoidpg_authid.oidID of this groupgrolistoid[]pg_authid.oidAn array containing the IDs of the roles in this group
pg_indexespg_indexes
The view pg_indexes provides access to
useful information about each index in the database.
pg_indexes> ColumnsNameTypeReferencesDescriptionschemanamenamepg_namespace.nspnameName of schema containing table and indextablenamenamepg_class.relnameName of table the index is forindexnamenamepg_class.relnameName of indextablespacenamepg_tablespace.spcnameName of tablespace containing index (null if default for database)indexdeftextIndex definition (a reconstructed CREATE INDEX
command)
pg_lockspg_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 might
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.
There are several distinct types of lockable objects:
whole relations (e.g., tables), individual pages of relations,
individual tuples of relations,
transaction IDs (both virtual and permanent IDs),
and general database objects (identified by class OID and object OID,
in the same way as in pg_description or
pg_depend). Also, the right to extend a
relation is represented as a separate lockable object.
Also, advisory> locks can be taken on numbers that have
user-defined meanings.
pg_locks> ColumnsNameTypeReferencesDescriptionlocktypetext
Type of the lockable object:
relation>,
extend>,
page>,
tuple>,
transactionid>,
virtualxid>,
object>,
userlock>, or
advisory>
databaseoidpg_database.oid
OID of the database in which the lock target exists, or
zero if the target is a shared object, or
null if the target is a transaction ID
relationoidpg_class.oid
OID of the relation targeted by the lock, or null if the target is not
a relation or part of a relation
pageinteger
Page number targeted by the lock within the relation,
or null if the target is not a relation page or tuple
tuplesmallint
Tuple number targeted by the lock within the page,
or null if the target is not a tuple
virtualxidtext
Virtual ID of the transaction targeted by the lock,
or null if the target is not a virtual transaction ID
transactionidxid
ID of the transaction targeted by the lock,
or null if the target is not a transaction ID
classidoidpg_class.oid
OID of the system catalog containing the lock target, or null if the
target is not a general database object
objidoidany OID column
OID of the lock target within its system catalog, or null if the
target is not a general database object
objsubidsmallint
Column number targeted by the lock (the
classid> and objid> refer to the
table itself),
or zero if the target is some other general database object,
or null if the target is not a general database object
virtualtransactiontext
Virtual ID of the transaction that is holding or awaiting this lock
pidinteger
Process ID of the server process holding or awaiting this
lock, or null if the lock is held by a prepared transaction
modetextName of the lock mode held or desired by this process (see and )grantedbooleanTrue if lock is held, false if lock is awaitedfastpathbooleanTrue if lock was taken via fast path, false if taken via main
lock table
granted is true in a row representing a lock
held by the indicated transaction. False indicates that this transaction is
currently waiting to acquire this lock, which implies that some other
transaction is holding a conflicting lock mode on the same lockable object.
The waiting transaction will sleep until the other lock is released (or a
deadlock situation is detected). A single transaction can be waiting to
acquire at most one lock at a time.
Every transaction holds an exclusive lock on its virtual transaction ID for
its entire duration. If a permanent ID is assigned to the transaction
(which normally happens only if the transaction changes the state of the
database), it also holds an exclusive lock on its permanent transaction ID
until it ends. When 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 (either virtual or permanent ID depending on the
situation). That will succeed only when the other transaction
terminates and releases its locks.
Although tuples are a lockable type of object,
information about row-level locks is stored on disk, not in memory,
and therefore row-level locks normally do not appear in this view.
If a transaction is waiting for a
row-level lock, it will usually appear in the view as waiting for the
permanent transaction ID of the current holder of that row lock.
Advisory locks can be acquired on keys consisting of either a single
bigint value or two integer values.
A bigint key is displayed with its
high-order half in the classid> column, its low-order half
in the objid> column, and objsubid> equal
to 1. The original bigint value can be reassembled with the
expression (classid::bigint << 32) |
objid::bigint. Integer keys are displayed with the
first key in the
classid> column, the second key in the objid>
column, and objsubid> equal to 2. The actual meaning of
the keys is up to the user. Advisory locks are local to each database,
so the database> column is meaningful for an advisory lock.
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).
The pid column can be joined to the
pid column of the pg_stat_activity
view to get more
information on the session holding or waiting to hold each lock,
for example
SELECT * FROM pg_locks pl LEFT JOIN pg_stat_activity psa
ON pl.pid = psa.pid;
Also, if you are using prepared transactions, the
virtualtransaction> column can be joined to the
transaction column of the pg_prepared_xacts
view to get more information on prepared transactions that hold locks.
(A prepared transaction can never be waiting for a lock,
but it continues to hold the locks it acquired while running.)
For example:
SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
ON pl.virtualtransaction = '-1/' || ppx.transaction;
The pg_locks view displays data from both the
regular lock manager and the predicate lock manager, which are
separate systems; in addition, the regular lock manager subdivides its
locks into regular and fast-path> locks.
This data is not guaranteed to be entirely consistent.
When the view is queried,
data on fast-path locks (with fastpath> = true>)
is gathered from each backend one at a time, without freezing the state of
the entire lock manager, so it is possible for locks to be taken or
released while information is gathered. Note, however, that these locks are
known not to conflict with any other lock currently in place. After
all backends have been queried for fast-path locks, the remainder of the
regular lock manager is locked as a unit, and a consistent snapshot of all
remaining locks is collected as an atomic action. After unlocking the
regular lock manager, the predicate lock manager is similarly locked and all
predicate locks are collected as an atomic action. Thus, with the exception
of fast-path locks, each lock manager will deliver a consistent set of
results, but as we do not lock both lock managers simultaneously, it is
possible for locks to be taken or released after we interrogate the regular
lock manager and before we interrogate the predicate lock manager.
Locking the regular and/or predicate lock manager could have some
impact on database performance if this view is very frequently accessed.
The locks are held only for the minimum amount of time necessary to
obtain data from the lock managers, but this does not completely eliminate
the possibility of a performance impact.
pg_matviewspg_matviewsmaterialized views
The view pg_matviews provides access to
useful information about each materialized view in the database.
pg_matviews> ColumnsNameTypeReferencesDescriptionschemanamenamepg_namespace.nspnameName of schema containing materialized viewmatviewnamenamepg_class.relnameName of materialized viewmatviewownernamepg_authid.rolnameName of materialized view's ownertablespacenamepg_tablespace.spcnameName of tablespace containing materialized view (null if default for database)hasindexesbooleanTrue if materialized view has (or recently had) any indexesispopulatedbooleanTrue if materialized view is currently populateddefinitiontextMaterialized view definition (a reconstructed SELECT query)
pg_policiespg_policies
The view pg_policies provides access to
useful information about each row-level security policy in the database.
pg_policies> ColumnsNameTypeReferencesDescriptionschemanamenamepg_namespace.nspnameName of schema containing table policy is ontablenamenamepg_class.relnameName of table policy is onpolicynamenamepg_policy.polnameName of policyrolesname[]The roles to which this policy appliescmdtextThe command type to which the policy is appliedqualtextThe expression added to the security barrier qualifications for
queries that this policy applies towith_checktextThe expression added to the WITH CHECK qualifications for
queries that attempt to add rows to this table
pg_prepared_statementspg_prepared_statements
The pg_prepared_statements view displays
all the prepared statements that are available in the current
session. See for more information about prepared
statements.
pg_prepared_statements contains one row
for each prepared statement. Rows are added to the view when a new
prepared statement is created and removed when a prepared statement
is released (for example, via the command).
pg_prepared_statements> ColumnsNameTypeDescriptionnametext
The identifier of the prepared statement
statementtext
The query string submitted by the client to create this
prepared statement. For prepared statements created via SQL,
this is the PREPARE statement submitted by
the client. For prepared statements created via the
frontend/backend protocol, this is the text of the prepared
statement itself.
prepare_timetimestamptz
The time at which the prepared statement was created
parameter_typesregtype[]
The expected parameter types for the prepared statement in the
form of an array of regtype. The OID corresponding
to an element of this array can be obtained by casting the
regtype value to oid.
from_sqlbooleantrue if the prepared statement was created
via the PREPARE SQL statement;
false if the statement was prepared via the
frontend/backend protocol
The pg_prepared_statements view is read only.
pg_prepared_xactspg_prepared_xacts
The view pg_prepared_xacts displays
information about transactions that are currently prepared for two-phase
commit (see for details).
pg_prepared_xacts contains one row per prepared
transaction. An entry is removed when the transaction is committed or
rolled back.
pg_prepared_xacts> ColumnsNameTypeReferencesDescriptiontransactionxid
Numeric transaction identifier of the prepared transaction
gidtext
Global transaction identifier that was assigned to the transaction
preparedtimestamp with time zone
Time at which the transaction was prepared for commit
ownernamepg_authid.rolname
Name of the user that executed the transaction
databasenamepg_database.datname
Name of the database in which the transaction was executed
When the pg_prepared_xacts view is accessed, the
internal transaction 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 operations longer than necessary. Nonetheless
there could be some impact on database performance if this view is
frequently accessed.
pg_rolespg_roles
The view pg_roles provides access to
information about database roles. This is simply a publicly
readable view of
pg_authid
that blanks out the password field.
This view explicitly exposes the OID column of the underlying table,
since that is needed to do joins to other catalogs.
pg_roles> ColumnsNameTypeReferencesDescriptionrolnamenameRole namerolsuperboolRole has superuser privilegesrolinheritboolRole automatically inherits privileges of roles it is a
member ofrolcreateroleboolRole can create more rolesrolcreatedbboolRole can create databasesrolcanloginbool
Role can log in. That is, this role can be given as the initial
session authorization identifier
rolreplicationbool
Role is a replication role. That is, this role can initiate streaming
replication (see ) and set/unset
the system backup mode using pg_start_backup> and
pg_stop_backup>
rolconnlimitint4
For roles that can log in, this sets maximum number of concurrent
connections this role can make. -1 means no limit.
rolpasswordtextNot the password (always reads as ********>)rolvaliduntiltimestamptzPassword expiry time (only used for password authentication);
null if no expirationrolconfigtext[]Role-specific defaults for run-time configuration variablesoidoidpg_authid.oidID of role
pg_rulespg_rules
The view pg_rules provides access to
useful information about query rewrite rules.
pg_rules> ColumnsNameTypeReferencesDescriptionschemanamenamepg_namespace.nspnameName of schema containing tabletablenamenamepg_class.relnameName of table the rule is forrulenamenamepg_rewrite.rulenameName of ruledefinitiontextRule definition (a reconstructed creation command)
The pg_rules> view excludes the ON SELECT> rules
of views and materialized views; those can be seen in
pg_views> and pg_matviews>.
pg_seclabelspg_seclabels
The view pg_seclabels provides information about
security labels. It as an easier-to-query version of the
pg_seclabel>> catalog.
pg_seclabels> ColumnsNameTypeReferencesDescriptionobjoidoidany OID columnThe OID of the object this security label pertains toclassoidoidpg_class.oidThe OID of the system catalog this object appears inobjsubidint4
For a security label on a table column, this is the column number (the
objoid> and classoid> refer to
the table itself). For all other object types, this column is
zero.
objtypetext
The type of object to which this label applies, as text.
objnamespaceoidpg_namespace.oid
The OID of the namespace for this object, if applicable;
otherwise NULL.
objnametext
The name of the object to which this label applies, as text.
providertextpg_seclabel.providerThe label provider associated with this label.labeltextpg_seclabel.labelThe security label applied to this object.
pg_settingspg_settings
The view pg_settings provides access to
run-time parameters of the server. It is essentially an alternative
interface to the
and commands.
It also provides access to some facts about each parameter that are
not directly available from SHOW>, such as minimum and
maximum values.
pg_settings> ColumnsNameTypeDescriptionnametextRun-time configuration parameter namesettingtextCurrent value of the parameterunittextImplicit unit of the parametercategorytextLogical group of the parametershort_desctextA brief description of the parameterextra_desctextAdditional, more detailed, description of the parametercontexttextContext required to set the parameter's value (see below)vartypetextParameter type (bool>, enum>,
integer>, real>, or string>)
sourcetextSource of the current parameter valuemin_valtextMinimum allowed value of the parameter (null for non-numeric
values)max_valtextMaximum allowed value of the parameter (null for non-numeric
values)enumvalstext[]Allowed values of an enum parameter (null for non-enum
values)boot_valtextParameter value assumed at server startup if the parameter is
not otherwise setreset_valtextValue that RESET would reset the parameter to
in the current sessionsourcefiletextConfiguration file the current value was set in (null for
values set from sources other than configuration files, or when
examined by a non-superuser);
helpful when using include> directives in configuration filessourcelineintegerLine number within the configuration file the current value was
set at (null for values set from sources other than configuration files,
or when examined by a non-superuser)
pending_restartbooleantrue if the value has been changed in the
configuration file but needs a restart; or false
otherwise.
There are several possible values of context.
In order of decreasing difficulty of changing the setting, they are:
internal
These settings cannot be changed directly; they reflect internally
determined values. Some of them may be adjustable by rebuilding the
server with different configuration options, or by changing options
supplied to initdb.
postmaster
These settings can only be applied when the server starts, so any change
requires restarting the server. Values for these settings are typically
stored in the postgresql.conf file, or passed on
the command line when starting the server. Of course, settings with any
of the lower context types can also be
set at server start time.
sighup
Changes to these settings can be made in
postgresql.conf without restarting the server.
Send a SIGHUP signal to the postmaster to
cause it to re-read postgresql.conf and apply
the changes. The postmaster will also forward the
SIGHUP signal to its child processes so that
they all pick up the new value.
superuser-backend
Changes to these settings can be made in
postgresql.conf without restarting the server.
They can also be set for a particular session in the connection request
packet (for example, via libpq>'s PGOPTIONS>
environment variable), but only if the connecting user is a superuser.
However, these settings never change in a session after it is started.
If you change them in postgresql.conf, send a
SIGHUP signal to the postmaster to cause it to
re-read postgresql.conf. The new values will only
affect subsequently-launched sessions.
backend
Changes to these settings can be made in
postgresql.conf without restarting the server.
They can also be set for a particular session in the connection request
packet (for example, via libpq>'s PGOPTIONS>
environment variable); any user can make such a change for his session.
However, these settings never change in a session after it is started.
If you change them in postgresql.conf, send a
SIGHUP signal to the postmaster to cause it to
re-read postgresql.conf. The new values will only
affect subsequently-launched sessions.
superuser
These settings can be set from postgresql.conf,
or within a session via the SET> command; but only superusers
can change them via SET>. Changes in
postgresql.conf will affect existing sessions
only if no session-local value has been established with SET>.
user
These settings can be set from postgresql.conf,
or within a session via the SET> command. Any user is
allowed to change his session-local value. Changes in
postgresql.conf will affect existing sessions
only if no session-local value has been established with SET>.
See for more information about the various
ways to change these parameters.
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.
pg_file_settingspg_file_settings
The view pg_file_settings provides the file
name, line number and value of all parameters which are set through
configuration files.
In contrast to pg_settings, a row is provided for
each occurrence of the parameter across all configuration files. This is helpful
for discovering why one value may have been used in preference to another
when the parameters were loaded.
pg_file_settings> ColumnsNameTypeDescriptionsourcefiletextPath to and name of the configration filesourcelineinteger
Line number within the configuration file where the value was set
seqnointegerOrder in which the setting was loadednametextRun-time configuration parameter namesettingtextvalue of the parameter
See for more information about the various
ways to change these parameters.
The pg_file_settings view cannot be modified
directly as it represents information, as read in at server start or
reload time, about all parameter settings across all configuration files.
pg_shadowpg_shadow
The view pg_shadow exists for backwards
compatibility: it emulates a catalog that existed in
PostgreSQL before version 8.1.
It shows properties of all roles that are marked as
rolcanlogin> in
pg_authid.
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_shadow> ColumnsNameTypeReferencesDescriptionusenamenamepg_authid.rolnameUser nameusesysidoidpg_authid.oidID of this userusecreatedbboolUser can create databasesusesuperboolUser is a superuserusereplbool
User can initiate streaming replication and put the system in and
out of backup mode.
usebypassrlsbool
User can bypass row level security policies, see
for more information.
passwdtextPassword (possibly encrypted); null if none. See
pg_authid
for details of how encrypted passwords are stored.valuntilabstimePassword expiry time (only used for password authentication)useconfigtext[]Session defaults for run-time configuration variables
pg_statspg_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.
pg_stats> ColumnsNameTypeReferencesDescriptionschemanamenamepg_namespace.nspnameName of schema containing tabletablenamenamepg_class.relnameName of tableattnamenamepg_attribute.attnameName of the column described by this rowinheritedboolIf true, this row includes inheritance child columns, not just the
values in the specified tablenull_fracrealFraction of column entries that are nullavg_widthintegerAverage width in bytes of column's entriesn_distinctreal
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_valsanyarray
A list of the most common values in the column. (Null if
no values seem to be more common than any others.)
most_common_freqsreal[]
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_boundsanyarray
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.)
correlationreal
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.)
most_common_elemsanyarray
A list of non-null element values most often appearing within values of
the column. (Null for scalar types.)
most_common_elem_freqsreal[]
A list of the frequencies of the most common element values, i.e., the
fraction of rows containing at least one instance of the given value.
Two or three additional values follow the per-element frequencies;
these are the minimum and maximum of the preceding per-element
frequencies, and optionally the frequency of null elements.
(Null when most_common_elems is.)
elem_count_histogramreal[]
A histogram of the counts of distinct non-null element values within the
values of the column, followed by the average number of distinct
non-null elements. (Null for scalar types.)
The maximum number of entries in the array fields can be controlled on a
column-by-column basis using the ALTER TABLE SET STATISTICS>
command, or globally by setting the
run-time parameter.
pg_tablespg_tables
The view pg_tables provides access to
useful information about each table in the database.
pg_tables> ColumnsNameTypeReferencesDescriptionschemanamenamepg_namespace.nspnameName of schema containing tabletablenamenamepg_class.relnameName of tabletableownernamepg_authid.rolnameName of table's ownertablespacenamepg_tablespace.spcnameName of tablespace containing table (null if default for database)hasindexesbooleanpg_class.relhasindexTrue if table has (or recently had) any indexeshasrulesbooleanpg_class.relhasrulesTrue if table has (or once had) ruleshastriggersbooleanpg_class.relhastriggersTrue if table has (or once had) triggersrowsecuritybooleanpg_class.relrowsecurityTrue if row security is enabled on the table
pg_timezone_abbrevspg_timezone_abbrevs
The view pg_timezone_abbrevs provides a list
of time zone abbreviations that are currently recognized by the datetime
input routines. The contents of this view change when the
run-time parameter is modified.
pg_timezone_abbrevs> ColumnsNameTypeDescriptionabbrevtextTime zone abbreviationutc_offsetintervalOffset from UTC (positive means east of Greenwich)is_dstbooleanTrue if this is a daylight-savings abbreviation
pg_timezone_namespg_timezone_names
The view pg_timezone_names provides a list
of time zone names that are recognized by SET TIMEZONE>,
along with their associated abbreviations, UTC offsets,
and daylight-savings status. (Technically,
PostgreSQL uses UT1> rather
than UTC because leap seconds are not handled.)
Unlike the abbreviations shown in pg_timezone_abbrevs, many of these names imply a set of daylight-savings transition
date rules. Therefore, the associated information changes across local DST
boundaries. The displayed information is computed based on the current
value of CURRENT_TIMESTAMP>.
pg_timezone_names> ColumnsNameTypeDescriptionnametextTime zone nameabbrevtextTime zone abbreviationutc_offsetintervalOffset from UTC (positive means east of Greenwich)is_dstbooleanTrue if currently observing daylight savings
pg_userpg_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.
pg_user> ColumnsNameTypeDescriptionusenamenameUser nameusesysidoidID of this userusecreatedbboolUser can create databasesusesuperboolUser is a superuserusereplbool
User can initiate streaming replication and put the system in and
out of backup mode.
usebypassrlsbool
User can bypass row level security policies, see
for more information.
passwdtextNot the password (always reads as ********>)valuntilabstimePassword expiry time (only used for password authentication)useconfigtext[]Session defaults for run-time configuration variables
pg_user_mappingspg_user_mappings
The view pg_user_mappings provides access
to information about user mappings. This is essentially a publicly
readable view of
pg_user_mapping
that leaves out the options field if the user has no rights to use
it.
pg_user_mappings> ColumnsNameTypeReferencesDescriptionumidoidpg_user_mapping.oidOID of the user mappingsrvidoidpg_foreign_server.oid
The OID of the foreign server that contains this mapping
srvnamenamepg_foreign_server.srvname
Name of the foreign server
umuseroidpg_authid.oidOID of the local role being mapped, 0 if the user mapping is publicusenamenameName of the local user to be mappedumoptionstext[]
User mapping specific options, as keyword=value>
strings, if the current user is the owner of the foreign
server, else null
pg_viewspg_views
The view pg_views provides access to
useful information about each view in the database.
pg_views> ColumnsNameTypeReferencesDescriptionschemanamenamepg_namespace.nspnameName of schema containing viewviewnamenamepg_class.relnameName of viewviewownernamepg_authid.rolnameName of view's ownerdefinitiontextView definition (a reconstructed SELECT query)