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 normally 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, but many of those have been made
available as SQL commands over time, and so the need for direct manipulation
of the system catalogs is ever decreasing.
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_amrelation access methodspg_amopaccess method operatorspg_amprocaccess method support functionspg_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_init_privsobject initial privilegespg_languagelanguages for writing functionspg_largeobjectdata pages for large objectspg_largeobject_metadatametadata for large objectspg_namespaceschemaspg_opclassaccess method operator classespg_operatoroperatorspg_opfamilyaccess method operator familiespg_partitioned_tableinformation about partition key of tablespg_policyrow-security policiespg_procfunctions and procedurespg_publicationpublications for logical replicationpg_publication_relrelation to publication mappingpg_rangeinformation about range typespg_replication_originregistered replication originspg_rewritequery rewrite rulespg_seclabelsecurity labels on database objectspg_sequenceinformation about sequencespg_shdependdependencies on shared objectspg_shdescriptioncomments on shared objectspg_shseclabelsecurity labels on shared database objectspg_statisticplanner statisticspg_statistic_extextended planner statistics (definition)pg_statistic_ext_dataextended planner statistics (built statistics)pg_subscriptionlogical replication subscriptionspg_subscription_relrelation state for subscriptionspg_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 Columns
Column Type
Description
aggfnoidregproc
(references pg_proc.oid)
pg_proc OID of the aggregate function
aggkindchar
Aggregate kind:
n for normal aggregates,
o for ordered-set aggregates, or
h for hypothetical-set aggregates
aggnumdirectargsint2
Number 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.
aggtransfnregproc
(references pg_proc.oid)
Transition function
aggfinalfnregproc
(references pg_proc.oid)
Final function (zero if none)
aggcombinefnregproc
(references pg_proc.oid)
Combine function (zero if none)
aggserialfnregproc
(references pg_proc.oid)
Serialization function (zero if none)
aggdeserialfnregproc
(references pg_proc.oid)
Deserialization function (zero if none)
aggmtransfnregproc
(references pg_proc.oid)
Forward transition function for moving-aggregate mode (zero if none)
aggminvtransfnregproc
(references pg_proc.oid)
Inverse transition function for moving-aggregate mode (zero if none)
aggmfinalfnregproc
(references pg_proc.oid)
Final function for moving-aggregate mode (zero if none)
aggfinalextrabool
True to pass extra dummy arguments to aggfinalfnaggmfinalextrabool
True to pass extra dummy arguments to aggmfinalfnaggfinalmodifychar
Whether aggfinalfn modifies the
transition state value:
r if it is read-only,
s if the aggtransfn
cannot be applied after the aggfinalfn, or
w if it writes on the value
aggmfinalmodifychar
Like aggfinalmodify, but for
the aggmfinalfnaggsortopoid
(references pg_operator.oid)
Associated sort operator (zero if none)
aggtranstypeoid
(references pg_type.oid)
Data type of the aggregate function's internal transition (state) data
aggtransspaceint4
Approximate average size (in bytes) of the transition state
data, or zero to use a default estimate
aggmtranstypeoid
(references pg_type.oid)
Data type of the aggregate function's internal transition (state)
data for moving-aggregate mode (zero if none)
aggmtransspaceint4
Approximate average size (in bytes) of the transition state data
for moving-aggregate mode, or zero to use a default estimate
agginitvaltext
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
relation access methods. There is one row for each access method supported
by the system.
Currently, only tables and indexes have access methods. The requirements for table
and index access methods are discussed in detail in and
respectively.
pg_am Columns
Column Type
Description
oidoid
Row identifier
amnamename
Name of the access method
amhandlerregproc
(references pg_proc.oid)
OID of a handler function that is responsible for supplying information
about the access method
amtypechart = table (including materialized views),
i = index.
Before PostgreSQL 9.6, pg_am
contained many additional columns representing properties of index access
methods. That data is now only directly visible at the C code level.
However, pg_index_column_has_property() and related
functions have been added to allow SQL queries to inspect index access
method properties; see .
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 Columns
Column Type
Description
oidoid
Row identifier
amopfamilyoid
(references pg_opfamily.oid)
The operator family this entry is for
amoplefttypeoid
(references pg_type.oid)
Left-hand input data type of operator
amoprighttypeoid
(references pg_type.oid)
Right-hand input data type of operator
amopstrategyint2
Operator strategy number
amoppurposechar
Operator purpose, either s for search or
o for ordering
amopoproid
(references pg_operator.oid)
OID of the operator
amopmethodoid
(references pg_am.oid)
Index access method operator family is for
amopsortfamilyoid
(references pg_opfamily.oid)
The 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
WHEREindexed_columnoperatorconstant.
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 BYindexed_columnoperatorconstant.
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 functions associated with access method operator families. There
is one row for each support function belonging to an operator family.
pg_amproc Columns
Column Type
Description
oidoid
Row identifier
amprocfamilyoid
(references pg_opfamily.oid)
The operator family this entry is for
amproclefttypeoid
(references pg_type.oid)
Left-hand input data type of associated operator
amprocrighttypeoid
(references pg_type.oid)
Right-hand input data type of associated operator
amprocnumint2
Support function number
amprocregproc
(references pg_proc.oid)
OID of the function
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 function supports. For some access methods
these match the input data type(s) of the support function itself, for
others not. There is a notion of default support functions 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.
Only columns for which a default value has been explicitly set will have
an entry here.
pg_attrdef Columns
Column Type
Description
oidoid
Row identifier
adrelidoid
(references pg_class.oid)
The table this column belongs to
adnumint2
(references pg_attribute.attnum)
The number of the column
adbinpg_node_tree
The column default value, in nodeToString()
representation. Use pg_get_expr(adbin, adrelid) to
convert it to an SQL expression.
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 Columns
Column Type
Description
attrelidoid
(references pg_class.oid)
The table this column belongs to
attnamename
The column name
atttypidoid
(references pg_type.oid)
The data type of this column
attstattargetint4attstattarget 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 ctid,
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 expression or generation expression, in which
case there will be a corresponding entry in the
pg_attrdef catalog that actually defines the
expression. (Check attgenerated to
determine whether this is a default or a generation expression.)
atthasmissingbool
This column has a value which is used where the column is entirely
missing from the row, as happens when a column is added with a
non-volatile DEFAULT value after the row is created.
The actual value used is stored in the
attmissingval column.
attidentitychar
If a zero byte (''), then not an identity column.
Otherwise, a = generated
always, d = generated by default.
attgeneratedchar
If a zero byte (''), then not a generated column.
Otherwise, s = stored. (Other values might be added
in the future.)
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.
attcollationoid
(references pg_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
attmissingvalanyarray
This column has a one element array containing the value used when the
column is entirely missing from the row, as happens when the column is
added with a non-volatile DEFAULT value after the
row is created. The value is only used when
atthasmissing is true. If there is no value
the column is null.
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 Columns
Column Type
Description
oidoid
Row identifier
rolnamename
Role name
rolsuperbool
Role has superuser privileges
rolinheritbool
Role automatically inherits privileges of roles it is a
member of
rolcreaterolebool
Role can create more roles
rolcreatedbbool
Role can create databases
rolcanloginbool
Role can log in. That is, this role can be given as the initial
session authorization identifier.
rolreplicationbool
Role is a replication role. A replication role can initiate replication
connections and create and drop replication slots.
rolbypassrlsbool
Role bypasses every row level security policy, 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. The format depends
on the form of encryption used.
rolvaliduntiltimestamptz
Password expiry time (only used for password authentication);
null if no expiration
For an MD5 encrypted password, rolpassword
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.
If the password is encrypted with SCRAM-SHA-256, it has the format:
SCRAM-SHA-256$<iteration count>:<salt>$<StoredKey>:<ServerKey>
where salt, StoredKey and
ServerKey are in Base64 encoded format. This format is
the same as that specified by RFC 5803.
A password that does not follow either of those formats is assumed to be
unencrypted.
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 Columns
Column Type
Description
roleidoid
(references pg_authid.oid)
ID of a role that has a member
memberoid
(references pg_authid.oid)
ID of a role that is a member of roleidgrantoroid
(references pg_authid.oid)
ID of the role that granted this membership
admin_optionbool
True 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 Columns
Column Type
Description
oidoid
Row identifier
castsourceoid
(references pg_type.oid)
OID of the source data type
casttargetoid
(references pg_type.oid)
OID of the target data type
castfuncoid
(references pg_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 (but see also
pg_sequence), 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 Columns
Column Type
Description
oidoid
Row identifier
relnamename
Name of the table, index, view, etc.
relnamespaceoid
(references pg_namespace.oid)
The OID of the namespace that contains this relation
reltypeoid
(references pg_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)
reloftypeoid
(references pg_type.oid)
For typed tables, the OID of the underlying composite type,
zero for all other relations
relowneroid
(references pg_authid.oid)
Owner of the relation
relamoid
(references pg_am.oid)
If this is a table or an index, the access method used (heap,
B-tree, hash, etc.)
relfilenodeoid
Name of the on-disk file of this relation; zero means this
is a mapped relation whose disk file name is determined
by low-level state
reltablespaceoid
(references pg_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 live 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.
reltoastrelidoid
(references pg_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,
t = TOAST table,
v = view,
m = materialized view,
c = composite type,
f = foreign table,
p = partitioned table,
I = partitioned index
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
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
relhassubclassbool
True if table or index has (or once had) any inheritance children
relrowsecuritybool
True if table has row level security enabled; see
pg_policy catalog
relforcerowsecuritybool
True if row level security (when enabled) will also apply to table owner; see
pg_policy catalog
relispopulatedbool
True 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 (same as nothing if the
index used has been dropped)
relispartitionbool
True if table or index is a partition
relrewriteoid
(references pg_class.oid)
For new relations being written during a DDL operation that requires a
table rewrite, this contains the OID of the original relation;
otherwise 0. That state is only visible internally; this field should
never contain anything other than 0 for a user-visible relation.
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_xact to be shrunk. Zero
(InvalidTransactionId) if the relation is not a table.
relminmxidxid
All multixact 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 multixact ID
wraparound or to allow pg_multixact to be shrunk. Zero
(InvalidMultiXactId) if the relation is not a table.
relaclaclitem[]
Access privileges; see for details
reloptionstext[]
Access-method-specific options, as keyword=value strings
relpartboundpg_node_tree
If table is a partition (see relispartition),
internal representation of the partition bound
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 Columns
Column Type
Description
oidoid
Row identifier
collnamename
Collation name (unique per namespace and encoding)
collnamespaceoid
(references pg_namespace.oid)
The OID of the namespace that contains this collation
collowneroid
(references pg_authid.oid)
Owner of the collation
collproviderchar
Provider of the collation: d = database
default, c = libc, i = icu
collisdeterministicbool
Is the collation deterministic?
collencodingint4
Encoding in which the collation is applicable, or -1 if it
works for any encoding
collcollatenameLC_COLLATE for this collation object
collctypenameLC_CTYPE for this collation object
collversiontext
Provider-specific version of the collation. This is recorded when the
collation is created and then checked when it is used, to detect
changes in the collation definition that could lead to data corruption.
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 Columns
Column Type
Description
oidoid
Row identifier
connamename
Constraint name (not necessarily unique!)
connamespaceoid
(references pg_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
condeferrablebool
Is the constraint deferrable?
condeferredbool
Is the constraint deferred by default?
convalidatedbool
Has the constraint been validated?
Currently, can only be false for foreign keys and CHECK constraints
conrelidoid
(references pg_class.oid)
The table this constraint is on; 0 if not a table constraint
contypidoid
(references pg_type.oid)
The domain this constraint is on; 0 if not a domain constraint
conindidoid
(references pg_class.oid)
The index supporting this constraint, if it's a unique, primary
key, foreign key, or exclusion constraint; else 0
conparentidoid
(references pg_constraint.oid)
The corresponding constraint in the parent partitioned table,
if this is a constraint in a partition; else 0
confrelidoid
(references pg_class.oid)
If a foreign key, the referenced table; else 0
confupdtypechar
Foreign key update action code:
a = no action,
r = restrict,
c = cascade,
n = set null,
d = set default
confdeltypechar
Foreign key deletion action code:
a = no action,
r = restrict,
c = cascade,
n = set null,
d = set default
confmatchtypechar
Foreign 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[]
(references pg_attribute.attnum)
If a table constraint (including foreign keys, but not constraint
triggers), list of the constrained columns
confkeyint2[]
(references pg_attribute.attnum)
If a foreign key, list of the referenced columns
conpfeqopoid[]
(references pg_operator.oid)
If a foreign key, list of the equality operators for PK = FK comparisons
conppeqopoid[]
(references pg_operator.oid)
If a foreign key, list of the equality operators for PK = PK comparisons
conffeqopoid[]
(references pg_operator.oid)
If a foreign key, list of the equality operators for FK = FK comparisons
conexclopoid[]
(references pg_operator.oid)
If an exclusion constraint, list of the per-column exclusion operators
conbinpg_node_tree
If a check constraint, an internal representation of the
expression. (It's recommended to use
pg_get_constraintdef() to extract the definition of
a check constraint.)
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.)
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 functions. See
for more information.
pg_conversion Columns
Column Type
Description
oidoid
Row identifier
connamename
Conversion name (unique within a namespace)
connamespaceoid
(references pg_namespace.oid)
The OID of the namespace that contains this conversion
conowneroid
(references pg_authid.oid)
Owner of the conversion
conforencodingint4
Source encoding ID
contoencodingint4
Destination encoding ID
conprocregproc
(references pg_proc.oid)
Conversion function
condefaultbool
True 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 Columns
Column Type
Description
oidoid
Row identifier
datnamename
Database name
datdbaoid
(references pg_authid.oid)
Owner of the database, usually the user who created it
encodingint4
Character encoding for this database
(pg_encoding_to_char() can translate
this number to the encoding name)
datcollatename
LC_COLLATE for this database
datctypename
LC_CTYPE for this database
datistemplatebool
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_xact to be shrunk.
It is the minimum of the per-table
pg_class.relfrozenxid values.
datminmxidxid
All multixact 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
multixact ID wraparound or to allow pg_multixact to be shrunk.
It is the minimum of the per-table
pg_class.relminmxid values.
dattablespaceoid
(references pg_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 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 Columns
Column Type
Description
setdatabaseoid
(references pg_database.oid)
The OID of the database the setting is applicable to, or zero if not database-specific
setroleoid
(references pg_authid.oid)
The OID of the role the setting is applicable to, or zero if not role-specific
setconfigtext[]
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 Columns
Column Type
Description
oidoid
Row identifier
defaclroleoid
(references pg_authid.oid)
The OID of the role associated with this entry
defaclnamespaceoid
(references pg_namespace.oid)
The OID of the namespace associated with this entry,
or 0 if none
defaclobjtypechar
Type of object this entry is for:
r = relation (table, view),
S = sequence,
f = function,
T = type,
n = schema
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 Columns
Column Type
Description
classidoid
(references pg_class.oid)
The OID of the system catalog the dependent object is in
objidoid
(references any OID column)
The OID of the specific dependent object
objsubidint4
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.
refclassidoid
(references pg_class.oid)
The OID of the system catalog the referenced object is in
refobjidoid
(references any OID column)
The OID of the specific referenced object
refobjsubidint4
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 auto-dependent 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 direct 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 result in
automatically dropping the dependent object
whether CASCADE is specified or not. If the
dependent object has to be dropped due to a dependency on some other
object being removed, its drop is converted to a drop of the referenced
object, so that NORMAL and AUTO
dependencies of the dependent object behave much like they were
dependencies of the referenced object.
Example: a view's ON SELECT rule is made
internally dependent on the view, preventing it from being dropped
while the view remains. Dependencies of the rule (such as tables it
refers to) act as if they were dependencies of the view.
DEPENDENCY_PARTITION_PRI (P)DEPENDENCY_PARTITION_SEC (S)
The dependent object was created as part of creation of the
referenced object, and is really just a part of its internal
implementation; however, unlike INTERNAL,
there is more than one such referenced object. The dependent object
must not be dropped unless at least one of these referenced objects
is dropped; if any one is, the dependent object should be dropped
whether or not CASCADE is specified. Also
unlike INTERNAL, a drop of some other object
that the dependent object depends on does not result in automatic
deletion of any partition-referenced object. Hence, if the drop
does not cascade to at least one of these objects via some other
path, it will be refused. (In most cases, the dependent object
shares all its non-partition dependencies with at least one
partition-referenced object, so that this restriction does not
result in blocking any cascaded delete.)
Primary and secondary partition dependencies behave identically
except that the primary dependency is preferred for use in error
messages; hence, a partition-dependent object should have one
primary partition dependency and one or more secondary partition
dependencies.
Note that partition dependencies are made in addition to, not
instead of, any dependencies the object would normally have. This
simplifies ATTACH/DETACH PARTITION operations:
the partition dependencies need only be added or removed.
Example: a child partitioned index is made partition-dependent
on both the partition table it is on and the parent partitioned
index, so that it goes away if either of those is dropped, but
not otherwise. The dependency on the parent index is primary,
so that if the user tries to drop the child partitioned index,
the error message will suggest dropping the parent index instead
(not the table).
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_AUTO_EXTENSION (x)
The dependent object is not a member of the extension that is the
referenced object (and so it should not be ignored
by pg_dump), but it cannot function
without the extension and should be auto-dropped if the extension is.
The dependent object may be dropped on its own as well.
Functionally this dependency type acts the same as
an AUTO 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.
Note that it's quite possible for two objects to be linked by more than
one pg_depend entry. For example, a child
partitioned index would have both a partition-type dependency on its
associated partition table, and an auto dependency on each column of
that table that it indexes. This sort of situation expresses the union
of multiple dependency semantics. A dependent object can be dropped
without CASCADE if any of its dependencies satisfies
its condition for automatic dropping. Conversely, all the
dependencies' restrictions about which objects must be dropped together
must be satisfied.
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 Columns
Column Type
Description
objoidoid
(references any OID column)
The OID of the object this description pertains to
classoidoid
(references pg_class.oid)
The OID of the system catalog this object appears in
objsubidint4
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.
descriptiontext
Arbitrary 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 Columns
Column Type
Description
oidoid
Row identifier
enumtypidoid
(references pg_type.oid)
The OID of the pg_type entry owning this enum value
enumsortorderfloat4
The sort position of this enum value within its enum type
enumlabelname
The 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 Columns
Column Type
Description
oidoid
Row identifier
evtnamename
Trigger name (must be unique)
evteventname
Identifies the event for which this trigger fires
evtowneroid
(references pg_authid.oid)
Owner of the event trigger
evtfoidoid
(references pg_proc.oid)
The function to be called
evtenabledchar
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 Columns
Column Type
Description
oidoid
Row identifier
extnamename
Name of the extension
extowneroid
(references pg_authid.oid)
Owner of the extension
extnamespaceoid
(references pg_namespace.oid)
Schema containing the extension's exported objects
extrelocatablebool
True if extension can be relocated to another schema
extversiontext
Version name for the extension
extconfigoid[]
(references pg_class.oid)
Array of regclass OIDs for the extension's configuration
table(s), or NULL if none
extconditiontext[]
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 Columns
Column Type
Description
oidoid
Row identifier
fdwnamename
Name of the foreign-data wrapper
fdwowneroid
(references pg_authid.oid)
Owner of the foreign-data wrapper
fdwhandleroid
(references pg_proc.oid)
References a handler function that is responsible for
supplying execution routines for the foreign-data wrapper.
Zero if no handler is provided
fdwvalidatoroid
(references pg_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 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 Columns
Column Type
Description
oidoid
Row identifier
srvnamename
Name of the foreign server
srvowneroid
(references pg_authid.oid)
Owner of the foreign server
srvfdwoid
(references pg_foreign_data_wrapper.oid)
OID of the foreign-data wrapper of this foreign server
srvtypetext
Type of the server (optional)
srvversiontext
Version of the server (optional)
srvaclaclitem[]
Access privileges; see 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 Columns
Column Type
Description
ftrelidoid
(references pg_class.oid)
OID of the pg_class entry for this foreign table
ftserveroid
(references pg_foreign_server.oid)
OID of the foreign server for this foreign table
ftoptionstext[]
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 Columns
Column Type
Description
indexrelidoid
(references pg_class.oid)
The OID of the pg_class entry for this index
indrelidoid
(references pg_class.oid)
The OID of the pg_class entry for the table this index is for
indnattsint2
The total number of columns in the index (duplicates
pg_class.relnatts); this number includes both key and included attributes
indnkeyattsint2
The number of key columns in the index,
not counting any included columns, which are
merely stored and do not participate in the index semantics
indisuniquebool
If true, this is a unique index
indisprimarybool
If true, this index represents the primary key of the table
(indisunique should always be true when this is true)
indisexclusionbool
If true, this index supports an exclusion constraint
indimmediatebool
If true, the uniqueness check is enforced immediately on
insertion
(irrelevant if indisunique is not true)
indisclusteredbool
If true, the table was last clustered on this index
indisvalidbool
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
...indkeyint2vector
(references pg_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 entries. Key columns come before non-key
(included) columns. A zero in this array indicates that the
corresponding index attribute is an expression over the table columns,
rather than a simple column reference.
indcollationoidvector
(references pg_collation.oid)
For each column in the index key
(indnkeyatts values), this contains the OID
of the collation to use for the index, or zero if the column is not of
a collatable data type.
indclassoidvector
(references pg_opclass.oid)
For each column in the index key
(indnkeyatts values), this contains the OID
of the operator class to use. See
pg_opclass for details.
indoptionint2vector
This is an array of indnkeyatts 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 and index inheritance hierarchies. There is one entry for each direct
parent-child table or index relationship in the database. (Indirect
inheritance can be determined by following chains of entries.)
pg_inherits Columns
Column Type
Description
inhrelidoid
(references pg_class.oid)
The OID of the child table or index
inhparentoid
(references pg_class.oid)
The OID of the parent table or index
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.
Indexes cannot have multiple inheritance, since they can only inherit
when using declarative partitioning.
pg_init_privspg_init_privs
The catalog pg_init_privs records information about
the initial privileges of objects in the system. There is one entry
for each object in the database which has a non-default (non-NULL)
initial set of privileges.
Objects can have initial privileges either by having those privileges set
when the system is initialized (by initdb) or when the
object is created during a CREATE EXTENSION and the
extension script sets initial privileges using the GRANT
system. Note that the system will automatically handle recording of the
privileges during the extension script and that extension authors need
only use the GRANT and REVOKE
statements in their script to have the privileges recorded. The
privtype column indicates if the initial privilege was
set by initdb or during a
CREATE EXTENSION command.
Objects which have initial privileges set by initdb will
have entries where privtype is
'i', while objects which have initial privileges set
by CREATE EXTENSION will have entries where
privtype is 'e'.
pg_init_privs Columns
Column Type
Description
objoidoid
(references any OID column)
The OID of the specific object
classoidoid
(references pg_class.oid)
The OID of the system catalog the object is in
objsubidint4
For 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.
privtypechar
A code defining the type of initial privilege of this object; see text
initprivsaclitem[]
The initial access privileges; see
for details
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 Columns
Column Type
Description
oidoid
Row identifier
lannamename
Name of the language
lanowneroid
(references pg_authid.oid)
Owner of the language
lanisplbool
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.
lanplcallfoidoid
(references pg_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
laninlineoid
(references pg_proc.oid)
This references a function that is responsible for executing
inline anonymous code blocks
( blocks).
Zero if inline blocks are not supported.
lanvalidatoroid
(references pg_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 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 Columns
Column Type
Description
loidoid
(references pg_largeobject_metadata.oid)
Identifier of the large object that includes this page
pagenoint4
Page 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 Columns
Column Type
Description
oidoid
Row identifier
lomowneroid
(references pg_authid.oid)
Owner of the large object
lomaclaclitem[]
Access privileges; see 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 Columns
Column Type
Description
oidoid
Row identifier
nspnamename
Name of the namespace
nspowneroid
(references pg_authid.oid)
Owner of the namespace
nspaclaclitem[]
Access privileges; see 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 Columns
Column Type
Description
oidoid
Row identifier
opcmethodoid
(references pg_am.oid)
Index access method operator class is for
opcnamename
Name of this operator class
opcnamespaceoid
(references pg_namespace.oid)
Namespace of this operator class
opcowneroid
(references pg_authid.oid)
Owner of the operator class
opcfamilyoid
(references pg_opfamily.oid)
Operator family containing the operator class
opcintypeoid
(references pg_type.oid)
Data type that the operator class indexes
opcdefaultbool
True if this operator class is the default for opcintypeopckeytypeoid
(references pg_type.oid)
Type 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 Columns
Column Type
Description
oidoid
Row identifier
oprnamename
Name of the operator
oprnamespaceoid
(references pg_namespace.oid)
The OID of the namespace that contains this operator
oprowneroid
(references pg_authid.oid)
Owner of the operator
oprkindcharb = infix (both), l = prefix
(left), r = postfix (right)
oprcanmergebool
This operator supports merge joins
oprcanhashbool
This operator supports hash joins
oprleftoid
(references pg_type.oid)
Type of the left operand
oprrightoid
(references pg_type.oid)
Type of the right operand
oprresultoid
(references pg_type.oid)
Type of the result
oprcomoid
(references pg_operator.oid)
Commutator of this operator, if any
oprnegateoid
(references pg_operator.oid)
Negator of this operator, if any
oprcoderegproc
(references pg_proc.oid)
Function that implements this operator
oprrestregproc
(references pg_proc.oid)
Restriction selectivity estimation function for this operator
oprjoinregproc
(references pg_proc.oid)
Join 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 Columns
Column Type
Description
oidoid
Row identifier
opfmethodoid
(references pg_am.oid)
Index access method operator family is for
opfnamename
Name of this operator family
opfnamespaceoid
(references pg_namespace.oid)
Namespace of this operator family
opfowneroid
(references pg_authid.oid)
Owner 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_partitioned_tablepg_partitioned_table
The catalog pg_partitioned_table stores
information about how tables are partitioned.
pg_partitioned_table Columns
Column Type
Description
partrelidoid
(references pg_class.oid)
The OID of the pg_class entry for this partitioned table
partstratchar
Partitioning strategy; h = hash partitioned table,
l = list partitioned table, r = range partitioned table
partnattsint2
The number of columns in partition key
partdefidoid
(references pg_class.oid)
The OID of the pg_class entry for the default partition
of this partitioned table, or zero if this partitioned table does not
have a default partition.
partattrsint2vector
(references pg_attribute.attnum)
This is an array of partnatts values that
indicate which table columns are part of the partition key. For
example, a value of 1 3 would mean that the first
and the third table columns make up the partition key. A zero in this
array indicates that the corresponding partition key column is an
expression, rather than a simple column reference.
partclassoidvector
(references pg_opclass.oid)
For each column in the partition key, this contains the OID of the
operator class to use. See
pg_opclass for details.
partcollationoidvector
(references pg_collation.oid)
For each column in the partition key, this contains the OID of the
collation to use for partitioning, or zero if the column is not
of a collatable data type.
partexprspg_node_tree
Expression trees (in nodeToString()
representation) for partition key columns that are not simple column
references. This is a list with one element for each zero
entry in partattrs. Null if all partition key columns
are simple references.
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 Columns
Column Type
Description
oidoid
Row identifier
polnamename
The name of the policy
polrelidoid
(references pg_class.oid)
The table to which the policy applies
polcmdchar
The command type to which the policy is applied:
r for SELECT,
a for INSERT,
w for UPDATE,
d for DELETE,
or * for all
polpermissivebool
Is the policy permissive or restrictive?
polrolesoid[]
(references pg_authid.oid)
The roles to which the policy is applied
polqualpg_node_tree
The expression tree to be added to the security barrier qualifications for queries that use the table
polwithcheckpg_node_tree
The 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, procedures, aggregate functions, and window functions
(collectively also known as routines). See , , and
for more information.
If prokind indicates that the entry is for an
aggregate function, there should be a matching row in
pg_aggregate.
pg_proc Columns
Column Type
Description
oidoid
Row identifier
pronamename
Name of the function
pronamespaceoid
(references pg_namespace.oid)
The OID of the namespace that contains this function
proowneroid
(references pg_authid.oid)
Owner of the function
prolangoid
(references pg_language.oid)
Implementation language or call interface of this function
procostfloat4
Estimated execution cost (in units of
); if proretset,
this is cost per row returned
prorowsfloat4
Estimated number of result rows (zero if not proretset)
provariadicoid
(references pg_type.oid)
Data type of the variadic array parameter's elements,
or zero if the function does not have a variadic parameter
prosupportregproc
(references pg_proc.oid)
Optional planner support function for this function
(see )
prokindcharf for a normal function, p
for a procedure, a for an aggregate function, or
w for a window function
prosecdefbool
Function 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.
proretsetbool
Function 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.)
proparallelcharproparallel tells whether the function
can be safely run in parallel mode.
It is s for functions which are safe to run in
parallel mode without restriction.
It is r for functions which can be run in parallel
mode, but their execution is restricted to the parallel group leader;
parallel worker processes cannot invoke these functions.
It is u for functions which are unsafe in parallel
mode; the presence of such a function forces a serial execution plan.
pronargsint2
Number of input arguments
pronargdefaultsint2
Number of arguments that have defaults
prorettypeoid
(references pg_type.oid)
Data type of the return value
proargtypesoidvector
(references pg_type.oid)
An array of 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[]
(references pg_type.oid)
An array of 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 of 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 of 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
Ninput arguments (i.e., the last
Nproargtypes positions).
If none of the arguments have defaults, this field will be null.
protrftypesoid[]
(references pg_type.oid)
An array of the argument/result data type(s) for which to apply
transforms (from the function's TRANSFORM
clause). Null if none.
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 variables
proaclaclitem[]
Access privileges; see 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_publicationpg_publication
The catalog pg_publication contains all
publications created in the database. For more on publications see
.
pg_publication Columns
Column Type
Description
oidoid
Row identifier
pubnamename
Name of the publication
pubowneroid
(references pg_authid.oid)
Owner of the publication
puballtablesbool
If true, this publication automatically includes all tables
in the database, including any that will be created in the future.
pubinsertbool
If true, INSERT operations are replicated for
tables in the publication.
pubupdatebool
If true, UPDATE operations are replicated for
tables in the publication.
pubdeletebool
If true, DELETE operations are replicated for
tables in the publication.
pubtruncatebool
If true, TRUNCATE operations are replicated for
tables in the publication.
pubviarootbool
If true, operations on a leaf partition are replicated using the
identity and schema of its topmost partitioned ancestor mentioned in the
publication instead of its own.
pg_publication_relpg_publication_rel
The catalog pg_publication_rel contains the
mapping between relations and publications in the database. This is a
many-to-many mapping. See also
for a more user-friendly view of this information.
pg_publication_rel Columns
Column Type
Description
oidoid
Row identifier
prpubidoid
(references pg_publication.oid)
Reference to publication
prrelidoid
(references pg_class.oid)
Reference to relation
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 Columns
Column Type
Description
rngtypidoid
(references pg_type.oid)
OID of the range type
rngsubtypeoid
(references pg_type.oid)
OID of the element type (subtype) of this range type
rngcollationoid
(references pg_collation.oid)
OID of the collation used for range comparisons, or 0 if none
rngsubopcoid
(references pg_opclass.oid)
OID of the subtype's operator class used for range comparisons
rngcanonicalregproc
(references pg_proc.oid)
OID of the function to convert a range value into canonical form,
or 0 if none
rngsubdiffregproc
(references pg_proc.oid)
OID 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_replication_originpg_replication_origin
The pg_replication_origin catalog contains
all replication origins created. For more on replication origins
see .
Unlike most system catalogs, pg_replication_origin
is shared across all databases of a cluster: there is only one copy
of pg_replication_origin per cluster, not one per
database.
pg_replication_origin Columns
Column Type
Description
roidentoid
A unique, cluster-wide identifier for the replication
origin. Should never leave the system.
ronametext
The external, user defined, name of a replication
origin.
pg_rewritepg_rewrite
The catalog pg_rewrite stores rewrite rules for tables and views.
pg_rewrite Columns
Column Type
Description
oidoid
Row identifier
rulenamename
Rule name
ev_classoid
(references pg_class.oid)
The table this rule is for
ev_typechar
Event type that the rule is for: 1 = SELECT, 2 =
UPDATE, 3 = INSERT, 4 =
DELETEev_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_insteadbool
True if the rule is an INSTEAD rule
ev_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_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 Columns
Column Type
Description
objoidoid
(references any OID column)
The OID of the object this security label pertains to
classoidoid
(references pg_class.oid)
The OID of the system catalog this object appears in
objsubidint4
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.
providertext
The label provider associated with this label.
labeltext
The security label applied to this object.
pg_sequencepg_sequence
The catalog pg_sequence contains information about
sequences. Some of the information about sequences, such as the name and
the schema, is in pg_class.
pg_sequence Columns
Column Type
Description
seqrelidoid
(references pg_class.oid)
The OID of the pg_class entry for this sequence
seqtypidoid
(references pg_type.oid)
Data type of the sequence
seqstartint8
Start value of the sequence
seqincrementint8
Increment value of the sequence
seqmaxint8
Maximum value of the sequence
seqminint8
Minimum value of the sequence
seqcacheint8
Cache size of the sequence
seqcyclebool
Whether the sequence cycles
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 Columns
Column Type
Description
dbidoid
(references pg_database.oid)
The OID of the database the dependent object is in,
or zero for a shared object
classidoid
(references pg_class.oid)
The OID of the system catalog the dependent object is in
objidoid
(references any OID column)
The OID of the specific dependent object
objsubidint4
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.
refclassidoid
(references pg_class.oid)
The OID of the system catalog the referenced object is in
(must be a shared catalog)
refobjidoid
(references any OID column)
The OID of the specific referenced object
deptypechar
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_POLICY (r)
The referenced object (which must be a role) is mentioned as the
target of a dependent policy object.
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.
SHARED_DEPENDENCY_TABLESPACE (t)
The referenced object (which must be a tablespace) is mentioned as
the tablespace for a relation that doesn't have storage.
Other dependency flavors might be needed in future. Note in particular
that the current definition only supports roles and tablespaces 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 Columns
Column Type
Description
objoidoid
(references any OID column)
The OID of the object this description pertains to
classoidoid
(references pg_class.oid)
The OID of the system catalog this object appears in
descriptiontext
Arbitrary 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 Columns
Column Type
Description
objoidoid
(references any OID column)
The OID of the object this security label pertains to
classoidoid
(references pg_class.oid)
The OID of the system catalog this object appears in
providertext
The label provider associated with this label.
labeltext
The 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 Columns
Column Type
Description
starelidoid
(references pg_class.oid)
The table or index that the described column belongs to
staattnumint2
(references pg_attribute.attnum)
The number of the described column
stainheritbool
If true, the stats include inheritance child columns, not just the
values in the specified relation
stanullfracfloat4
The fraction of the column's entries that are null
stawidthint4
The average stored width, in bytes, of nonnull entries
stadistinctfloat4
The 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 about 80% of the
values are nonnull and each nonnull value appears about twice on
average could be represented by stadistinct = -0.4.
A zero value means the number of distinct values is unknown.
stakindNint2
A code number indicating the kind of statistics stored in the
Nth slot of the
pg_statistic row.
staopNoid
(references pg_operator.oid)
An operator used to derive the statistics stored in the
Nth slot. For example, a
histogram slot would show the < operator
that defines the sort order of the data.
stacollNoid
(references pg_collation.oid)
The collation used to derive the statistics stored in the
Nth slot. For example, a
histogram slot for a collatable column would show the collation that
defines the sort order of the data. Zero for noncollatable data.
stanumbersNfloat4[]
Numerical statistics of the appropriate kind for the
Nth slot, or null if the slot
kind does not involve numerical values
stavaluesNanyarray
Column data values of the appropriate kind for the
Nth 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_statistic_extpg_statistic_ext
The catalog pg_statistic_ext
holds definitions of extended planner statistics.
Each row in this catalog corresponds to a statistics object
created with .
pg_statistic_ext Columns
Column Type
Description
oidoid
Row identifier
stxrelidoid
(references pg_class.oid)
Table containing the columns described by this object
stxnamename
Name of the statistics object
stxnamespaceoid
(references pg_namespace.oid)
The OID of the namespace that contains this statistics object
stxowneroid
(references pg_authid.oid)
Owner of the statistics object
stxstattargetint4stxstattarget controls the level of detail
of statistics accumulated for this statistics object by
.
A zero value indicates that no statistics should be collected.
A negative value says to use the maximum of the statistics targets of
the referenced columns, if set, or the system default statistics target.
Positive values of stxstattarget
determine the target number of most common values
to collect.
stxkeysint2vector
(references pg_attribute.attnum)
An array of attribute numbers, indicating which table columns are
covered by this statistics object;
for example a value of 1 3 would
mean that the first and the third table columns are covered
stxkindchar[]
An array containing codes for the enabled statistics kinds;
valid values are:
d for n-distinct statistics,
f for functional dependency statistics, and
m for most common values (MCV) list statistics
The pg_statistic_ext entry is filled in
completely during CREATE STATISTICS, but the actual
statistical values are not computed then.
Subsequent ANALYZE commands compute the desired values
and populate an entry in the
pg_statistic_ext_data
catalog.
pg_statistic_ext_datapg_statistic_ext_data
The catalog pg_statistic_ext_data
holds data for extended planner statistics defined in pg_statistic_ext.
Each row in this catalog corresponds to a statistics object
created with .
Like pg_statistic,
pg_statistic_ext_data should not be
readable by the public, since the contents might be considered sensitive.
(Example: most common combinations of values in columns might be quite
interesting.)
pg_stats_ext
is a publicly readable view
on pg_statistic_ext_data (after joining
with pg_statistic_ext) that only exposes
information about those tables and columns that are readable by the
current user.
pg_statistic_ext_data Columns
Column Type
Description
stxoidoid
(references pg_statistic_ext.oid)
Extended statistic object containing the definition for this data
stxdndistinctpg_ndistinct
N-distinct counts, serialized as pg_ndistinct type
stxddependenciespg_dependencies
Functional dependency statistics, serialized
as pg_dependencies type
stxdmcvpg_mcv_list
MCV (most-common values) list statistics, serialized as
pg_mcv_list type
pg_subscriptionpg_subscription
The catalog pg_subscription contains all existing
logical replication subscriptions. For more information about logical
replication see .
Unlike most system catalogs, pg_subscription is
shared across all databases of a cluster: there is only one copy
of pg_subscription per cluster, not one per
database.
Access to the column subconninfo is revoked from
normal users, because it could contain plain-text passwords.
pg_subscription Columns
Column Type
Description
oidoid
Row identifier
subdbidoid
(references pg_database.oid)
OID of the database which the subscription resides in
subnamename
Name of the subscription
subowneroid
(references pg_authid.oid)
Owner of the subscription
subenabledbool
If true, the subscription is enabled and should be replicating.
subconninfotext
Connection string to the upstream database
subslotnamename
Name of the replication slot in the upstream database (also used
for the local replication origin name);
null represents NONEsubsynccommittext
Contains the value of the synchronous_commit
setting for the subscription workers.
subpublicationstext[]
Array of subscribed publication names. These reference the
publications on the publisher server. For more on publications
see .
pg_subscription_relpg_subscription_rel
The catalog pg_subscription_rel contains the
state for each replicated relation in each subscription. This is a
many-to-many mapping.
This catalog only contains tables known to the subscription after running
either CREATE SUBSCRIPTION or
ALTER SUBSCRIPTION ... REFRESH PUBLICATION.
pg_subscription_rel Columns
Column Type
Description
srsubidoid
(references pg_subscription.oid)
Reference to subscription
srrelidoid
(references pg_class.oid)
Reference to relation
srsubstatechar
State code:
i = initialize,
d = data is being copied,
s = synchronized,
r = ready (normal replication)
srsublsnpg_lsn
Remote LSN of the state change used for synchronization coordination
when in s or r states,
otherwise null
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 Columns
Column Type
Description
oidoid
Row identifier
spcnamename
Tablespace name
spcowneroid
(references pg_authid.oid)
Owner of the tablespace, usually the user who created it
spcaclaclitem[]
Access privileges; see 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 Columns
Column Type
Description
oidoid
Row identifier
trftypeoid
(references pg_type.oid)
OID of the data type this transform is for
trflangoid
(references pg_language.oid)
OID of the language this transform is for
trffromsqlregproc
(references pg_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.
trftosqlregproc
(references pg_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 Columns
Column Type
Description
oidoid
Row identifier
tgrelidoid
(references pg_class.oid)
The table this trigger is on
tgparentidoid
(references pg_trigger.oid)
Parent trigger that this trigger is cloned from, zero if not a clone;
this happens when partitions are created or attached to a partitioned
table.
tgnamename
Trigger name (must be unique among triggers of same table)
tgfoidoid
(references pg_proc.oid)
The function to be called
tgtypeint2
Bit mask identifying trigger firing conditions
tgenabledchar
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.
tgisinternalbool
True if trigger is internally generated (usually, to enforce
the constraint identified by tgconstraint)
tgconstrrelidoid
(references pg_class.oid)
The table referenced by a referential integrity constraint
tgconstrindidoid
(references pg_class.oid)
The index supporting a unique, primary key, referential integrity,
or exclusion constraint
tgconstraintoid
(references pg_constraint.oid)
The pg_constraint entry associated with the trigger, if any
tgdeferrablebool
True if constraint trigger is deferrable
tginitdeferredbool
True if constraint trigger is initially deferred
tgnargsint2
Number of argument strings passed to trigger function
tgattrint2vector
(references pg_attribute.attnum)
Column numbers, if trigger is column-specific; otherwise an
empty array
tgargsbytea
Argument strings to pass to trigger, each NULL-terminated
tgqualpg_node_tree
Expression tree (in nodeToString()
representation) for the trigger's WHEN condition, or null
if none
tgoldtablenameREFERENCING clause name for OLD TABLE,
or null if none
tgnewtablenameREFERENCING clause name for NEW TABLE,
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 Columns
Column Type
Description
oidoid
Row identifier
cfgnamename
Text search configuration name
cfgnamespaceoid
(references pg_namespace.oid)
The OID of the namespace that contains this configuration
cfgowneroid
(references pg_authid.oid)
Owner of the configuration
cfgparseroid
(references pg_ts_parser.oid)
The 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 Columns
Column Type
Description
mapcfgoid
(references pg_ts_config.oid)
The OID of the pg_ts_config entry owning this map entry
maptokentypeint4
A token type emitted by the configuration's parser
mapseqnoint4
Order in which to consult this entry (lower
mapseqnos first)
mapdictoid
(references pg_ts_dict.oid)
The 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 Columns
Column Type
Description
oidoid
Row identifier
dictnamename
Text search dictionary name
dictnamespaceoid
(references pg_namespace.oid)
The OID of the namespace that contains this dictionary
dictowneroid
(references pg_authid.oid)
Owner of the dictionary
dicttemplateoid
(references pg_ts_template.oid)
The OID of the text search template for this dictionary
dictinitoptiontext
Initialization 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 Columns
Column Type
Description
oidoid
Row identifier
prsnamename
Text search parser name
prsnamespaceoid
(references pg_namespace.oid)
The OID of the namespace that contains this parser
prsstartregproc
(references pg_proc.oid)
OID of the parser's startup function
prstokenregproc
(references pg_proc.oid)
OID of the parser's next-token function
prsendregproc
(references pg_proc.oid)
OID of the parser's shutdown function
prsheadlineregproc
(references pg_proc.oid)
OID of the parser's headline function
prslextyperegproc
(references pg_proc.oid)
OID 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 Columns
Column Type
Description
oidoid
Row identifier
tmplnamename
Text search template name
tmplnamespaceoid
(references pg_namespace.oid)
The OID of the namespace that contains this template
tmplinitregproc
(references pg_proc.oid)
OID of the template's initialization function
tmpllexizeregproc
(references pg_proc.oid)
OID 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 Columns
Column Type
Description
oidoid
Row identifier
typnamename
Data type name
typnamespaceoid
(references pg_namespace.oid)
The OID of the namespace that contains this type
typowneroid
(references pg_authid.oid)
Owner of the type
typlenint2
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.
typrelidoid
(references pg_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.
typelemoid
(references pg_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.
typarrayoid
(references pg_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
typinputregproc
(references pg_proc.oid)
Input conversion function (text format)
typoutputregproc
(references pg_proc.oid)
Output conversion function (text format)
typreceiveregproc
(references pg_proc.oid)
Input conversion function (binary format), or 0 if none
typsendregproc
(references pg_proc.oid)
Output conversion function (binary format), or 0 if none
typmodinregproc
(references pg_proc.oid)
Type modifier input function, or 0 if type does not support modifiers
typmodoutregproc
(references pg_proc.oid)
Type modifier output function, or 0 to use the standard format
typanalyzeregproc
(references pg_proc.oid)
Custom ANALYZE function, or 0 to use the standard function
typalignchartypalign 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).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 (plain): Values must always be stored plain
(non-varlena types always use this value).
e (external): Values can be stored in a
secondary TOAST relation (if relation has one, see
pg_class.reltoastrelid).
m (main): Values can be compressed and stored
inline.
x (extended): Values can be compressed and/or
moved to a secondary relation.
x is the usual choice for toast-able types.
Note that m values can also be moved out to
secondary storage, but only as a last resort (e
and x values are moved first).
typnotnullbooltypnotnull represents a not-null
constraint on a type. Used for domains only.
typbasetypeoid
(references pg_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.
typcollationoid
(references pg_collation.oid)
typcollation 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 a nonzero
value here, typically DEFAULT_COLLATION_OID.
A domain over a collatable type can have a collation OID different
from its base type's, 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 for details
For fixed-width 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.
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 Columns
Column Type
Description
oidoid
Row identifier
umuseroid
(references pg_authid.oid)
OID of the local role being mapped, 0 if the user mapping is public
umserveroid
(references pg_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_configcompile-time configuration parameterspg_cursorsopen cursorspg_file_settingssummary of configuration file contentspg_groupgroups of database userspg_hba_file_rulessummary of client authentication configuration file contentspg_indexesindexespg_lockslocks currently held or awaitedpg_matviewsmaterialized viewspg_policiespoliciespg_prepared_statementsprepared statementspg_prepared_xactsprepared transactionspg_publication_tablespublications and their associated tablespg_replication_origin_statusinformation about replication origins, including replication progresspg_replication_slotsreplication slot informationpg_rolesdatabase rolespg_rulesrulespg_seclabelssecurity labelspg_sequencessequencespg_settingsparameter settingspg_shadowdatabase userspg_shmem_allocationsshared memory allocationspg_statsplanner statisticspg_stats_extextended planner 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 Columns
Column Type
Description
namename
Extension name
default_versiontext
Name of default version, or NULL if none is
specified
installed_versiontext
Currently installed version of the extension,
or NULL if not installed
commenttext
Comment 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 Columns
Column Type
Description
namename
Extension name
versiontext
Version name
installedbool
True if this version of this extension is currently
installed
superuserbool
True if only superusers are allowed to install this extension
(but see trusted)
trustedbool
True if the extension can be installed by non-superusers
with appropriate privileges
relocatablebool
True if extension can be relocated to another schema
schemaname
Name of the schema that the extension must be installed into,
or NULL if partially or fully relocatable
requiresname[]
Names of prerequisite extensions,
or NULL if none
commenttext
Comment string from the extension's control file
The pg_available_extension_versions view is read
only.
pg_configpg_config
The view pg_config describes the
compile-time configuration parameters of the currently installed
version of PostgreSQL. It is intended, for example, to
be used by software packages that want to interface to
PostgreSQL to facilitate finding the required header
files and libraries. It provides the same basic information as the
PostgreSQL client
application.
By default, the pg_config view can be read
only by superusers.
pg_config Columns
Column Type
Description
nametext
The parameter name
settingtext
The parameter value
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 Columns
Column Type
Description
nametext
The name of the cursor
statementtext
The verbatim query string submitted to declare this cursor
is_holdablebooltrue if the cursor is holdable (that is, it
can be accessed after the transaction that declared the cursor
has committed); false otherwise
is_binarybooltrue if the cursor was declared
BINARY; false
otherwise
is_scrollablebooltrue if the cursor is scrollable (that is, it
allows rows to be retrieved in a nonsequential manner);
false otherwise
creation_timetimestamptz
The time at which the cursor was declared
The pg_cursors view is read only.
pg_file_settingspg_file_settings
The view pg_file_settings provides a summary of
the contents of the server's configuration file(s). A row appears in
this view for each name = value entry appearing in the files,
with annotations indicating whether the value could be applied
successfully. Additional row(s) may appear for problems not linked to
a name = value entry, such as syntax errors in the files.
This view is helpful for checking whether planned changes in the
configuration files will work, or for diagnosing a previous failure.
Note that this view reports on the current contents of the
files, not on what was last applied by the server. (The
pg_settings
view is usually sufficient to determine that.)
By default, the pg_file_settings view can be read
only by superusers.
pg_file_settings Columns
Column Type
Description
sourcefiletext
Full path name of the configuration file
sourcelineint4
Line number within the configuration file where the entry appears
seqnoint4
Order in which the entries are processed (1..n)
nametext
Configuration parameter name
settingtext
Value to be assigned to the parameter
appliedbool
True if the value can be applied successfully
errortext
If not null, an error message indicating why this entry could
not be applied
If the configuration file contains syntax errors or invalid parameter
names, the server will not attempt to apply any settings from it, and
therefore all the applied fields will read as false.
In such a case there will be one or more rows with
non-null error fields indicating the
problem(s). Otherwise, individual settings will be applied if possible.
If an individual setting cannot be applied (e.g., invalid value, or the
setting cannot be changed after server start) it will have an appropriate
message in the error field. Another way that
an entry might have applied = false is that it is
overridden by a later entry for the same parameter name; this case is not
considered an error so nothing appears in
the error field.
See for more information about the various
ways to change run-time parameters.
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 Columns
Column Type
Description
gronamename
(references pg_authid.rolname)
Name of the group
grosysidoid
(references pg_authid.oid)
ID of this group
grolistoid[]
(references pg_authid.oid)
An array containing the IDs of the roles in this group
pg_hba_file_rulespg_hba_file_rules
The view pg_hba_file_rules provides a summary of
the contents of the client authentication configuration
file, pg_hba.conf. A row appears in this view for each
non-empty, non-comment line in the file, with annotations indicating
whether the rule could be applied successfully.
This view can be helpful for checking whether planned changes in the
authentication configuration file will work, or for diagnosing a previous
failure. Note that this view reports on the current contents
of the file, not on what was last loaded by the server.
By default, the pg_hba_file_rules view can be read
only by superusers.
pg_hba_file_rules Columns
Column Type
Description
line_numberint4
Line number of this rule in pg_hba.conftypetext
Type of connection
databasetext[]
List of database name(s) to which this rule applies
user_nametext[]
List of user and group name(s) to which this rule applies
addresstext
Host name or IP address, or one
of all, samehost,
or samenet, or null for local connections
netmasktext
IP address mask, or null if not applicable
auth_methodtext
Authentication method
optionstext[]
Options specified for authentication method, if any
errortext
If not null, an error message indicating why this
line could not be processed
Usually, a row reflecting an incorrect entry will have values for only
the line_number and error fields.
See for more information about
client authentication configuration.
pg_indexespg_indexes
The view pg_indexes provides access to
useful information about each index in the database.
pg_indexes Columns
Column Type
Description
schemanamename
(references pg_namespace.nspname)
Name of schema containing table and index
tablenamename
(references pg_class.relname)
Name of table the index is for
indexnamename
(references pg_class.relname)
Name of index
tablespacename
(references pg_tablespace.spcname)
Name of tablespace containing index (null if default for database)
indexdeftext
Index definition (a reconstructed CREATE INDEX
command)
pg_lockspg_locks
The view pg_locks provides access to
information about the locks held by active processes within the
database server. See for more discussion
of locking.
pg_locks contains one row per active lockable
object, requested lock mode, and relevant process. Thus, the same
lockable object might
appear many times, if multiple processes 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, as is the right to
update pg_database.datfrozenxid.
Also, advisory locks can be taken on numbers that have
user-defined meanings.
pg_locks Columns
Column Type
Description
locktypetext
Type of the lockable object:
relation,
extend,
frozenid,
page,
tuple,
transactionid,
virtualxid,
spectoken,
object,
userlock, or
advisory.
(See also .)
databaseoid
(references pg_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
relationoid
(references pg_class.oid)
OID of the relation targeted by the lock, or null if the target is not
a relation or part of a relation
pageint4
Page number targeted by the lock within the relation,
or null if the target is not a relation page or tuple
tupleint2
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
classidoid
(references pg_class.oid)
OID of the system catalog containing the lock target, or null if the
target is not a general database object
objidoid
(references any OID column)
OID of the lock target within its system catalog, or null if the
target is not a general database object
objsubidint2
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
pidint4
Process ID of the server process holding or awaiting this
lock, or null if the lock is held by a prepared transaction
modetext
Name of the lock mode held or desired by this process (see and )
grantedbool
True if lock is held, false if lock is awaited
fastpathbool
True 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 process. False indicates that this process is
currently waiting to acquire this lock, which implies that at least one
other process is holding or waiting for a conflicting lock mode on the same
lockable object. The waiting process will sleep until the other lock is
released (or a deadlock situation is detected). A single process can be
waiting to acquire at most one lock at a time.
Throughout running a transaction, a server process holds an exclusive lock
on the transaction's virtual transaction ID. 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 the
transaction's permanent transaction ID until it ends. When a process finds
it necessary to wait specifically for another transaction to end, it does
so by attempting to acquire share lock on the other transaction's 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 process 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 awaiting 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;
While it is possible to obtain information about which processes block
which other processes by joining pg_locks against
itself, this is very difficult to get right in detail. Such a query would
have to encode knowledge about which lock modes conflict with which
others. Worse, the pg_locks view does not expose
information about which processes are ahead of which others in lock wait
queues, nor information about which processes are parallel workers running
on behalf of which other client sessions. It is better to use
the pg_blocking_pids() function
(see ) to identify which
process(es) a waiting process is blocked behind.
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 Columns
Column Type
Description
schemanamename
(references pg_namespace.nspname)
Name of schema containing materialized view
matviewnamename
(references pg_class.relname)
Name of materialized view
matviewownername
(references pg_authid.rolname)
Name of materialized view's owner
tablespacename
(references pg_tablespace.spcname)
Name of tablespace containing materialized view (null if default for database)
hasindexesbool
True if materialized view has (or recently had) any indexes
ispopulatedbool
True if materialized view is currently populated
definitiontext
Materialized 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 Columns
Column Type
Description
schemanamename
(references pg_namespace.nspname)
Name of schema containing table policy is on
tablenamename
(references pg_class.relname)
Name of table policy is on
policynamename
(references pg_policy.polname)
Name of policy
permissivetext
Is the policy permissive or restrictive?
rolesname[]
The roles to which this policy applies
cmdtext
The command type to which the policy is applied
qualtext
The expression added to the security barrier qualifications for
queries that this policy applies to
with_checktext
The 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 Columns
Column Type
Description
nametext
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_sqlbooltrue if the prepared statement was created
via the PREPARE SQL command;
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 Columns
Column Type
Description
transactionxid
Numeric transaction identifier of the prepared transaction
gidtext
Global transaction identifier that was assigned to the transaction
preparedtimestamptz
Time at which the transaction was prepared for commit
ownername
(references pg_authid.rolname)
Name of the user that executed the transaction
databasename
(references pg_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_publication_tablespg_publication_tables
The view pg_publication_tables provides
information about the mapping between publications and the tables they
contain. Unlike the underlying
catalog pg_publication_rel, this view expands
publications defined as FOR ALL TABLES, so for such
publications there will be a row for each eligible table.
pg_publication_tables Columns
Column Type
Description
pubnamename
(references pg_publication.pubname)
Name of publication
schemanamename
(references pg_namespace.nspname)
Name of schema containing table
tablenamename
(references pg_class.relname)
Name of table
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 Columns
Column Type
Description
local_idoid
(references pg_replication_origin.roident)
internal node identifier
external_idtext
(references pg_replication_origin.roname)
external node identifier
remote_lsnpg_lsn
The origin node's LSN up to which data has been replicated.
local_lsnpg_lsn
This node's LSN 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 Columns
Column Type
Description
slot_namename
A unique, cluster-wide identifier for the replication slot
pluginname
The base name of the shared object containing the output plugin this logical slot is using, or null for physical slots.
slot_typetext
The slot type: physical or logicaldatoidoid
(references pg_database.oid)
The OID of the database this slot is associated with, or
null. Only logical slots have an associated database.
databasename
(references pg_database.datname)
The name of the database this slot is associated with, or
null. Only logical slots have an associated database.
temporarybool
True if this is a temporary replication slot. Temporary slots are
not saved to disk and are automatically dropped on error or when
the session has finished.
activebool
True if this slot is currently actively being used
active_pidint4
The process ID of the session using this slot if the slot
is currently actively being used. NULL if
inactive.
xminxid
The oldest transaction that this slot needs the database to
retain. VACUUM cannot remove tuples deleted
by any later transaction.
catalog_xminxid
The 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_lsn
The 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 unless this LSN
gets behind more than
from the current LSN. NULL
if the LSN of this slot has never been reserved.
confirmed_flush_lsnpg_lsn
The address (LSN) up to which the logical
slot's consumer has confirmed receiving data. Data older than this is
not available anymore. NULL for physical slots.
wal_statustext
Availability of WAL files claimed by this slot.
Possible values are:
reserved means that the claimed files
are within max_wal_size.extended means
that max_wal_size is exceeded but the files are
still retained, either by the replication slot or
by wal_keep_size.
unreserved means that the slot no longer
retains the required WAL files and some of them are to be removed at
the next checkpoint. This state can return
to reserved or extended.
lost means that some required WAL files have
been removed and this slot is no longer usable.
The last two states are seen only when
is
non-negative. If restart_lsn is NULL, this
field is null.
safe_wal_sizeint8
The number of bytes that can be written to WAL such that this slot
is not in danger of getting in state "lost". It is NULL for lost
slots, as well as if max_slot_wal_keep_size
is -1.
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.
pg_roles Columns
Column Type
Description
rolnamename
Role name
rolsuperbool
Role has superuser privileges
rolinheritbool
Role automatically inherits privileges of roles it is a
member of
rolcreaterolebool
Role can create more roles
rolcreatedbbool
Role can create databases
rolcanloginbool
Role can log in. That is, this role can be given as the initial
session authorization identifier
rolreplicationbool
Role is a replication role. A replication role can initiate replication
connections and create and drop replication slots.
rolconnlimitint4
For roles that can log in, this sets maximum number of concurrent
connections this role can make. -1 means no limit.
rolpasswordtext
Not the password (always reads as ********)
rolvaliduntiltimestamptz
Password expiry time (only used for password authentication);
null if no expiration
rolbypassrlsbool
Role bypasses every row level security policy, see
for more information.
rolconfigtext[]
Role-specific defaults for run-time configuration variables
oidoid
(references pg_authid.oid)
ID of role
pg_rulespg_rules
The view pg_rules provides access to
useful information about query rewrite rules.
pg_rules Columns
Column Type
Description
schemanamename
(references pg_namespace.nspname)
Name of schema containing table
tablenamename
(references pg_class.relname)
Name of table the rule is for
rulenamename
(references pg_rewrite.rulename)
Name of rule
definitiontext
Rule 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 Columns
Column Type
Description
objoidoid
(references any OID column)
The OID of the object this security label pertains to
classoidoid
(references pg_class.oid)
The OID of the system catalog this object appears in
objsubidint4
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.
objnamespaceoid
(references pg_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.
providertext
(references pg_seclabel.provider)
The label provider associated with this label.
labeltext
(references pg_seclabel.label)
The security label applied to this object.
pg_sequencespg_sequences
The view pg_sequences provides access to
useful information about each sequence in the database.
pg_sequences Columns
Column Type
Description
schemanamename
(references pg_namespace.nspname)
Name of schema containing sequence
sequencenamename
(references pg_class.relname)
Name of sequence
sequenceownername
(references pg_authid.rolname)
Name of sequence's owner
data_typeregtype
(references pg_type.oid)
Data type of the sequence
start_valueint8
Start value of the sequence
min_valueint8
Minimum value of the sequence
max_valueint8
Maximum value of the sequence
increment_byint8
Increment value of the sequence
cyclebool
Whether the sequence cycles
cache_sizeint8
Cache size of the sequence
last_valueint8
The last sequence value written to disk. If caching is used,
this value can be greater than the last value handed out from the
sequence. Null if the sequence has not been read from yet. Also, if
the current user does not have USAGE
or SELECT privilege on the sequence, the value is
null.
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 Columns
Column Type
Description
nametext
Run-time configuration parameter name
settingtext
Current value of the parameter
unittext
Implicit unit of the parameter
categorytext
Logical group of the parameter
short_desctext
A brief description of the parameter
extra_desctext
Additional, more detailed, description of the parameter
contexttext
Context required to set the parameter's value (see below)
vartypetext
Parameter type (bool, enum,
integer, real, or string)
sourcetext
Source of the current parameter value
min_valtext
Minimum allowed value of the parameter (null for non-numeric
values)
max_valtext
Maximum allowed value of the parameter (null for non-numeric
values)
enumvalstext[]
Allowed values of an enum parameter (null for non-enum
values)
boot_valtext
Parameter value assumed at server startup if the parameter is
not otherwise set
reset_valtext
Value that RESET would reset the parameter to
in the current session
sourcefiletext
Configuration file the current value was set in (null for
values set from sources other than configuration files, or when
examined by a user who is neither a superuser or a member of
pg_read_all_settings); helpful when using
include directives in configuration files
sourcelineint4
Line 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 user who is neither a superuser or a member of
pg_read_all_settings).
pending_restartbooltrue 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 their 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 their 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_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 Columns
Column Type
Description
usenamename
(references pg_authid.rolname)
User name
usesysidoid
(references pg_authid.oid)
ID of this user
usecreatedbbool
User can create databases
usesuperbool
User is a superuser
usereplbool
User can initiate streaming replication and put the system in and
out of backup mode.
usebypassrlsbool
User bypasses every row level security policy, see
for more information.
passwdtext
Password (possibly encrypted); null if none. See
pg_authid
for details of how encrypted passwords are stored.
valuntiltimestamptz
Password expiry time (only used for password authentication)
useconfigtext[]
Session defaults for run-time configuration variables
pg_shmem_allocationspg_shmem_allocations
The pg_shmem_allocations view shows allocations
made from the server's main shared memory segment. This includes both
memory allocated by postgres itself and memory
allocated by extensions using the mechanisms detailed in
.
Note that this view does not include memory allocated using the dynamic
shared memory infrastructure.
pg_shmem_allocations Columns
Column Type
Description
nametext
The name of the shared memory allocation. NULL for unused memory
and <anonymous> for anonymous
allocations.
offint8
The offset at which the allocation starts. NULL for anonymous
allocations, since details related to them are not known.
sizeint8
Size of the allocation
allocated_sizeint8
Size of the allocation including padding. For anonymous
allocations, no information about padding is available, so the
size and allocated_size columns
will always be equal. Padding is not meaningful for free memory, so
the columns will be equal in that case also.
Anonymous allocations are allocations that have been made
with ShmemAlloc() directly, rather than via
ShmemInitStruct() or
ShmemInitHash().
By default, the pg_shmem_allocations view can be
read only by superusers.
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 Columns
Column Type
Description
schemanamename
(references pg_namespace.nspname)
Name of schema containing table
tablenamename
(references pg_class.relname)
Name of table
attnamename
(references pg_attribute.attname)
Name of the column described by this row
inheritedbool
If true, this row includes inheritance child columns, not just the
values in the specified table
null_fracfloat4
Fraction of column entries that are null
avg_widthint4
Average width in bytes of column's entries
n_distinctfloat4
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_freqsfloat4[]
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.)
correlationfloat4
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_freqsfloat4[]
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_histogramfloat4[]
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_stats_extpg_stats_ext
The view pg_stats_ext provides access to
the information stored in the pg_statistic_ext
and pg_statistic_ext_data
catalogs. This view allows access only to rows of
pg_statistic_ext and pg_statistic_ext_data
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_ext is also designed to present the
information in a more readable format than the underlying catalogs
— at the cost that its schema must be extended whenever new types
of extended statistics are added to pg_statistic_ext.
pg_stats_ext Columns
Column Type
Description
schemanamename
(references pg_namespace.nspname)
Name of schema containing table
tablenamename
(references pg_class.relname)
Name of table
statistics_schemanamename
(references pg_namespace.nspname)
Name of schema containing extended statistic
statistics_namename
(references pg_statistic_ext.stxname)
Name of extended statistics
statistics_ownername
(references pg_authid.rolname)
Owner of the extended statistics
attnamesname[]
(references pg_attribute.attname)
Names of the columns the extended statistics is defined on
kindschar[]
Types of extended statistics enabled for this record
n_distinctpg_ndistinct
N-distinct counts for combinations of column values. If greater
than zero, the estimated number of distinct values in the combination.
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 combination of
columns in which the number of distinct combinations is the same as the
number of rows.
dependenciespg_dependencies
Functional dependency statistics
most_common_valstext[]
A list of the most common combinations of values in the columns.
(Null if no combinations seem to be more common than any others.)
most_common_val_nullsbool[]
A list of NULL flags for the most common combinations of values.
(Null when most_common_vals is.)
most_common_freqsfloat8[]
A list of the frequencies of the most common combinations,
i.e., number of occurrences of each divided by total number of rows.
(Null when most_common_vals is.)
most_common_base_freqsfloat8[]
A list of the base frequencies of the most common combinations,
i.e., product of per-value frequencies.
(Null when most_common_vals is.)
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 Columns
Column Type
Description
schemanamename
(references pg_namespace.nspname)
Name of schema containing table
tablenamename
(references pg_class.relname)
Name of table
tableownername
(references pg_authid.rolname)
Name of table's owner
tablespacename
(references pg_tablespace.spcname)
Name of tablespace containing table (null if default for database)
hasindexesbool
(references pg_class.relhasindex)
True if table has (or recently had) any indexes
hasrulesbool
(references pg_class.relhasrules)
True if table has (or once had) rules
hastriggersbool
(references pg_class.relhastriggers)
True if table has (or once had) triggers
rowsecuritybool
(references pg_class.relrowsecurity)
True 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 Columns
Column Type
Description
abbrevtext
Time zone abbreviation
utc_offsetinterval
Offset from UTC (positive means east of Greenwich)
is_dstbool
True if this is a daylight-savings abbreviation
While most timezone abbreviations represent fixed offsets from UTC,
there are some that have historically varied in value
(see for more information).
In such cases this view presents their current meaning.
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 does not use 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 Columns
Column Type
Description
nametext
Time zone name
abbrevtext
Time zone abbreviation
utc_offsetinterval
Offset from UTC (positive means east of Greenwich)
is_dstbool
True 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 Columns
Column Type
Description
usenamename
User name
usesysidoid
ID of this user
usecreatedbbool
User can create databases
usesuperbool
User is a superuser
usereplbool
User can initiate streaming replication and put the system in and
out of backup mode.
usebypassrlsbool
User bypasses every row level security policy, see
for more information.
passwdtext
Not the password (always reads as ********)
valuntiltimestamptz
Password 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 Columns
Column Type
Description
umidoid
(references pg_user_mapping.oid)
OID of the user mapping
srvidoid
(references pg_foreign_server.oid)
The OID of the foreign server that contains this mapping
srvnamename
(references pg_foreign_server.srvname)
Name of the foreign server
umuseroid
(references pg_authid.oid)
OID of the local role being mapped, 0 if the user mapping is public
usenamename
Name of the local user to be mapped
umoptionstext[]
User mapping specific options, as keyword=value strings
To protect password information stored as a user mapping option,
the umoptions column will read as null
unless one of the following applies:
current user is the user being mapped, and owns the server or
holds USAGE privilege on it
current user is the server owner and mapping is for PUBLIC
current user is a superuser
pg_viewspg_views
The view pg_views provides access to
useful information about each view in the database.
pg_views Columns
Column Type
Description
schemanamename
(references pg_namespace.nspname)
Name of schema containing view
viewnamename
(references pg_class.relname)
Name of view
viewownername
(references pg_authid.rolname)
Name of view's owner
definitiontext
View definition (a reconstructed SELECT query)