System Catalogs

Name

The System Catalogs -- The System catalogs are where a relational database management system stores schema metadata, such as information about tables and columns, and internal bookkeeping information.

Overview

Table 1 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 marked in the descriptions of the individual catalogs.

Table 1. The System Catalogs

Catalog NamePurpose
pg_aggregateaggregate functions
pg_amindex access methods
pg_amopaccess method operators
pg_amprocaccess method support procedures
pg_attrdefcolumn default values
pg_attributetable columns ("attributes")
pg_castcasts (data type conversions)
pg_classtables, indexes, sequences ("relations")
pg_constraintcheck constraints, unique constraints, primary key constraints, foreign key constraints
pg_conversionencoding conversion information
pg_databasedatabases within this database cluster
pg_dependdependencies between database objects
pg_descriptiondescriptions or comments on database objects
pg_groupgroups of database users
pg_indexadditional index information
pg_inheritstable inheritance hierarchy
pg_languagelanguages for writing functions
pg_largeobjectlarge objects
pg_listenerasynchronous notification support
pg_namespaceschemas
pg_opclassindex access method operator classes
pg_operatoroperators
pg_procfunctions and procedures
pg_rewritequery rewrite rules
pg_shadowdatabase users
pg_statisticplanner statistics
pg_tablespacetablespaces within this database cluster
pg_triggertriggers
pg_typedata types

pg_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.

Table 2. pg_aggregate Columns

NameTypeReferencesDescription
aggfnoidregprocpg_proc.oidpg_proc OID of the aggregate function
aggtransfnregprocpg_proc.oidTransition function
aggfinalfnregprocpg_proc.oidFinal function (zero if none)
aggtranstypeoidpg_type.oidThe type of the aggregate function's internal transition (state) data
agginitvaltext  The initial value of the transition state. This is a text field containing the initial value in its external string representation. If the value is null, the transition state value starts out null.

New aggregate functions are registered with the CREATE AGGREGATE command.

pg_am

The catalog pg_am stores information about index access methods. There is one row for each index access method supported by the system.

Table 3. pg_am Columns

NameTypeReferencesDescription
amnamename Name of the access method
amownerint4pg_shadow.usesysidUser ID of the owner (currently not used)
amstrategiesint2 Number of operator strategies for this access method
amsupportint2 Number of support routines for this access method
amorderstrategyint2 Zero if the index offers no sort order, otherwise the strategy number of the strategy operator that describes the sort order
amcanuniquebool Does the access method support unique indexes?
amcanmulticolbool Does the access method support multicolumn indexes?
amindexnullsbool Does the access method support null index entries?
amconcurrentbool Does the access method support concurrent updates?
amgettupleregprocpg_proc.oid"Next valid tuple" function
aminsertregprocpg_proc.oid"Insert this tuple" function
ambeginscanregprocpg_proc.oid"Start new scan" function
amrescanregprocpg_proc.oid"Restart this scan" function
amendscanregprocpg_proc.oid"End this scan" function
ammarkposregprocpg_proc.oid"Mark current scan position" function
amrestrposregprocpg_proc.oid"Restore marked scan position" function
ambuildregprocpg_proc.oid"Build new index" function
ambulkdeleteregprocpg_proc.oidBulk-delete function
amvacuumcleanupregprocpg_proc.oidPost-VACUUM cleanup function
amcostestimateregprocpg_proc.oidFunction to estimate cost of an index scan

An index access method that supports multiple columns (has amcanmulticol true) must support indexing null values in columns after the first, because the planner will assume the index can be used for queries on just the first column(s). For example, consider an index on (a,b) and a query with WHERE a = 4. The system will assume the index can be used to scan for rows with a = 4, which is wrong if the index omits rows where b is null. It is, however, OK to omit rows where the first indexed column is null. (GiST currently does so.) amindexnulls should be set true only if the index access method indexes all rows, including arbitrary combinations of null values.

pg_amop

The catalog pg_amop stores information about operators associated with index access method operator classes. There is one row for each operator that is a member of an operator class.

Table 4. pg_amop Columns

NameTypeReferencesDescription
amopclaidoidpg_opclass.oidThe index operator class this entry is for
amopsubtypeoidpg_type.oidSubtype to distinguish multiple entries for one strategy; zero for default
amopstrategyint2 Operator strategy number
amopreqcheckbool Index hit must be rechecked
amopoproidpg_operator.oidOID of the operator

pg_amproc

The catalog pg_amproc stores information about support procedures associated with index access method operator classes. There is one row for each support procedure belonging to an operator class.

Table 5. pg_amproc Columns

NameTypeReferencesDescription
amopclaidoidpg_opclass.oidThe index operator class this entry is for
amprocsubtypeoidpg_type.oidSubtype, if cross-type routine, else zero
amprocnumint2 Support procedure number
amprocregprocpg_proc.oidOID of the procedure

pg_attrdef

The catalog pg_attrdef stores column default values. The main information about columns is stored in pg_attribute (see below). Only columns that explicitly specify a default value (when the table is created or the column is added) will have an entry here.

Table 6. pg_attrdef Columns

NameTypeReferencesDescription
adrelidoidpg_class.oidThe table this column belongs to
adnumint2pg_attribute.attnumThe number of the column
adbintext The internal representation of the column default value
adsrctext A human-readable representation of the default value

pg_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 other objects. See pg_class.)

The term attribute is equivalent to column and is used for historical reasons.

Table 7. pg_attribute Columns

NameTypeReferencesDescription
attrelidoidpg_class.oidThe table this column belongs to
attnamename The column name
atttypidoidpg_type.oidThe data type of this column
attstattargetint4  attstattarget controls the level of detail of statistics accumulated for this column by ANALYZE. A zero value indicates that no statistics should be collected. A negative value says to use the system default statistics target. The exact meaning of positive values is data type-dependent. For scalar data types, attstattarget is both the target number of "most common values" to collect, and the target number of histogram bins to create.
attlenint2  A copy of pg_type.typlen of this column's type
attnumint2  The number of the column. Ordinary columns are numbered from 1 up. System columns, such as oid, have (arbitrary) negative numbers.
attndimsint4  Number of dimensions, if the column is an array type; otherwise 0. (Presently, the number of dimensions of an array is not enforced, so any nonzero value effectively means "it's an array".)
attcacheoffint4  Always -1 in storage, but when loaded into a row descriptor in memory this may be updated to cache the offset of the attribute within the row.
atttypmodint4  atttypmod 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. It is possible to change this column to enable or disable the constraint.
atthasdefbool  This column has a default value, in which case there will be a corresponding entry in the pg_attrdef catalog that actually defines the value.
attisdroppedbool  This column has been dropped and is no longer valid. A dropped column is still physically present in the table, but is ignored by the parser and so cannot be accessed via SQL.
attislocalbool  This column is defined locally in the relation. Note that a column may 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.

pg_cast

The catalog pg_cast stores data type conversion paths, both built-in paths and those defined with CREATE CAST.

Table 8. pg_cast Columns

NameTypeReferencesDescription
castsourceoidpg_type.oidOID of the source data type
casttargetoidpg_type.oidOID of the target data type
castfuncoidpg_proc.oid The OID of the function to use to perform this cast. Zero is stored if the data types are binary compatible (that is, no run-time operation is needed to perform the cast).
castcontextchar  Indicates what contexts the cast may 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.

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. Note however that at present there is no support for associating non-default type modifiers with user-created data types, and so this facility is only of use for the small number of built-in types that have type modifier syntax built into the grammar.

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 datatypes and a second to apply the modifier.

pg_class

The catalog pg_class catalogs tables and most everything else that has columns or is otherwise similar to a table. This includes indexes (but see also pg_index), sequences, views, composite types, and some kinds of special relation; 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.

Table 9. pg_class Columns

NameTypeReferencesDescription
relnamename Name of the table, index, view, etc.
relnamespaceoidpg_namespace.oid The OID of the namespace that contains this relation
reltypeoidpg_type.oid The OID of the data type that corresponds to this table's rowtype, if any (zero for indexes, which have no pg_type entry)
relownerint4pg_shadow.usesysidOwner of the relation
relamoidpg_am.oidIf this is an index, the access method used (B-tree, hash, etc.)
relfilenodeoid Name of the on-disk file of this relation; 0 if none
reltablespaceoidpg_tablespace.oid The tablespace in which this relation is stored. If zero, the database's default tablespace is implied. (Not meaningful if the relation has no on-disk file.)
relpagesint4  Size of the on-disk representation of this table in pages (of size BLCKSZ). This is only an estimate used by the planner. It is updated by VACUUM, ANALYZE, and a few DDL commands such as CREATE INDEX.
reltuplesfloat4  Number of rows in the table. This is only an estimate used by the planner. It is updated by VACUUM, ANALYZE, and a few DDL commands such as CREATE INDEX.
reltoastrelidoidpg_class.oid OID of the TOAST table associated with this table, 0 if none. The TOAST table stores large attributes "out of line" in a secondary table.
reltoastidxidoidpg_class.oid For a TOAST table, the OID of its index. 0 if not a TOAST table.
relhasindexbool  True if this is a table and it has (or recently had) any indexes. This is set by CREATE INDEX, but not cleared immediately by DROP INDEX. VACUUM clears relhasindex if it finds the table has no indexes.
relissharedbool True if this table is shared across all databases in the cluster. Only certain system catalogs (such as pg_database) are shared.
relkindchar  r = ordinary table, i = index, S = sequence, v = view, c = composite type, s = special, t = TOAST table
relnattsint2  Number of user columns in the relation (system columns not counted). There must be this many corresponding entries in pg_attribute. See also pg_attribute.attnum.
relchecksint2  Number of check constraints on the table; see pg_constraint catalog
reltriggersint2  Number of triggers on the table; see pg_trigger catalog
relukeysint2 unused (not the number of unique keys)
relfkeysint2 unused (not the number of foreign keys on the table)
relrefsint2 unused
relhasoidsbool  True if we generate an OID for each row of the relation.
relhaspkeybool  True if the table has (or once had) a primary key.
relhasrulesbool Table has rules; see pg_rewrite catalog
relhassubclassbool At least one table inherits from this one
relaclaclitem[]  Access privileges; see the descriptions of GRANT and REVOKE for details.

pg_constraint

The catalog pg_constraint stores check, primary key, unique, and foreign key 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.

Check constraints on domains are stored here, too.

Table 10. pg_constraint Columns

NameTypeReferencesDescription
connamename Constraint name (not necessarily unique!)
connamespaceoidpg_namespace.oid The OID of the namespace that contains this constraint
contypechar  c = check constraint, f = foreign key constraint, p = primary key constraint, u = unique constraint
condeferrablebool Is the constraint deferrable?
condeferredbool Is the constraint deferred by default?
conrelidoidpg_class.oidThe table this constraint is on; 0 if not a table constraint
contypidoidpg_type.oidThe domain this constraint is on; 0 if not a domain constraint
confrelidoidpg_class.oidIf a foreign key, the referenced table; else 0
confupdtypechar Foreign key update action code
confdeltypechar Foreign key deletion action code
confmatchtypechar Foreign key match type
conkeyint2[]pg_attribute.attnumIf a table constraint, list of columns which the constraint constrains
confkeyint2[]pg_attribute.attnumIf a foreign key, list of the referenced columns
conbintext If a check constraint, an internal representation of the expression
consrctext If a check constraint, a human-readable representation of the expression

Note: consrc is not updated when referenced objects change; for example, it won't track renaming of columns. Rather than relying on this field, it's best to use pg_get_constraintdef() to extract the definition of a check constraint.

Note: pg_class.relchecks needs to agree with the number of check-constraint entries found in this table for the given relation.

pg_conversion

The catalog pg_conversion stores encoding conversion information. See CREATE CONVERSION for more information.

Table 11. pg_conversion Columns

NameTypeReferencesDescription
connamename Conversion name (unique within a namespace)
connamespaceoidpg_namespace.oid The OID of the namespace that contains this conversion
conownerint4pg_shadow.usesysidOwner of the conversion
conforencodingint4 Source encoding ID
contoencodingint4 Destination encoding ID
conprocregprocpg_proc.oidConversion procedure
condefaultbool True if this is the default conversion

pg_database

The catalog pg_database stores information about the available databases. Databases are created with the CREATE DATABASE command. Consult Chapter 23 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.

Table 12. pg_database Columns

NameTypeReferencesDescription
datnamename Database name
datdbaint4pg_shadow.usesysidOwner of the database, usually the user who created it
encodingint4 Character encoding for this database
datistemplatebool  If true then this database can be used in the TEMPLATE clause of CREATE DATABASE to create a new database as a clone of this one.
datallowconnbool  If false then no one can connect to this database. This is used to protect the template0 database from being altered.
datlastsysoidoid  Last system OID in the database; useful particularly to pg_dump
datvacuumxidxid  All rows inserted or deleted by transaction IDs before this one have been marked as known committed or known aborted in this database. This is used to determine when commit-log space can be recycled.
datfrozenxidxid  All rows inserted by transaction IDs before this one have been relabeled with a permanent ("frozen") transaction ID in this database. This is useful to check whether a database must be vacuumed soon to avoid transaction ID wrap-around problems.
dattablespaceoidpg_tablespace.oid The default tablespace for the database. Within this database, all tables for which pg_class.reltablespace is zero will be stored in this tablespace; in particular, all the non-shared system catalogs will be there.
datconfigtext[] Session defaults for run-time configuration variables
dataclaclitem[] Access privileges

pg_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.

Table 13. pg_depend Columns

NameTypeReferencesDescription
classidoidpg_class.oidThe OID of the system catalog the dependent object is in
objidoidany OID columnThe 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.
refclassidoidpg_class.oidThe OID of the system catalog the referenced object is in
refobjidoidany OID columnThe 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 may not 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 may be dropped without affecting the referenced object. The referenced object may only be dropped by specifying CASCADE, in which case the dependent object is dropped, too. Example: a table column has a normal dependency on its data type.

DEPENDENCY_AUTO (a)

The dependent object can be dropped separately from the referenced object, and should be automatically dropped (regardless of RESTRICT or CASCADE mode) if the referenced object is dropped. Example: a named constraint on a table is made autodependent on the table, so that it will go away if the table is dropped.

DEPENDENCY_INTERNAL (i)

The dependent object was created as part of creation of the referenced object, and is really just a part of its internal implementation. A DROP of the dependent object will be disallowed outright (we'll tell the user to issue a DROP against the referenced object, instead). A DROP of the referenced object will be propagated through to drop the dependent object whether CASCADE is specified or not. Example: a trigger that's created to enforce a foreign-key constraint is made internally dependent on the constraint's pg_constraint entry.

DEPENDENCY_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 may be needed in future.

pg_description

The catalog pg_description can store an optional description or comment for each database object. Descriptions can be manipulated with the COMMENT command and viewed with psql's \d commands. Descriptions of many built-in system objects are provided in the initial contents of pg_description.

Table 14. pg_description Columns

NameTypeReferencesDescription
objoidoidany OID columnThe OID of the object this description pertains to
classoidoidpg_class.oidThe 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_group

The catalog pg_group defines groups and stores what users belong to what groups. Groups are created with the CREATE GROUP command. Consult Chapter 22 for information about user privilege management.

Because user and group identities are cluster-wide, pg_group is shared across all databases of a cluster: there is only one copy of pg_group per cluster, not one per database.

Table 15. pg_group Columns

NameTypeReferencesDescription
gronamename Name of the group
grosysidint4 An arbitrary number to identify this group
grolistint4[]pg_shadow.usesysidAn array containing the IDs of the users in this group

pg_index

The catalog pg_index contains part of the information about indexes. The rest is mostly in pg_class.

Table 16. pg_index Columns

NameTypeReferencesDescription
indexrelidoidpg_class.oidThe OID of the pg_class entry for this index
indrelidoidpg_class.oidThe OID of the pg_class entry for the table this index is for
indkeyint2vectorpg_attribute.attnum This is an array of indnatts (up to INDEX_MAX_KEYS) values that indicate which table columns this index indexes. For example a value of 1 3 would mean that the first and the third table columns make up the index key. A zero in this array indicates that the corresponding index attribute is an expression over the table columns, rather than a simple column reference.
indclassoidvectorpg_opclass.oid For each column in the index key this contains the OID of the operator class to use. See pg_opclass for details.
indnattsint2 The number of columns in the index (duplicates pg_class.relnatts)
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.)
indisclusteredbool If true, the table was last clustered on this index.
indexprstext 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.
indpredtext Expression tree (in nodeToString() representation) for partial index predicate. Null if not a partial index.

pg_inherits

The catalog pg_inherits records information about table inheritance hierarchies.

Table 17. pg_inherits Columns

NameTypeReferencesDescription
inhrelidoidpg_class.oid The OID of the child table.
inhparentoidpg_class.oid The OID of the parent table.
inhseqnoint4  If there is more than one parent for a child table (multiple inheritance), this number tells the order in which the inherited columns are to be arranged. The count starts at 1.

pg_language

The catalog pg_language registers call interfaces or languages in which you can write functions or stored procedures.

Table 18. pg_language Columns

NameTypeReferencesDescription
lannamename Name of the language (to be specified when creating a function)
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 may be replaced by a different mechanism sometime.
lanpltrustedbool  This is a trusted language. See under CREATE LANGUAGE what this means. If this is an internal language (lanispl is false) then this column is meaningless.
lanplcallfoidoidpg_proc.oid For noninternal languages this references the language handler, which is a special function that is responsible for executing all functions that are written in the particular language.
lanvalidatoroidpg_proc.oid This references a language validator function that is responsible for checking the syntax and validity of new functions when they are created. See under CREATE LANGUAGE for further information about validators.
lanaclaclitem[] Access privileges

pg_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).

Table 19. pg_largeobject Columns

NameTypeReferencesDescription
loidoid 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 may 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 may be missing, and may 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_listener

The catalog pg_listener supports the LISTEN and NOTIFY commands. A listener creates an entry in pg_listener for each notification name it is listening for. A notifier scans pg_listener and updates each matching entry to show that a notification has occurred. The notifier also sends a signal (using the PID recorded in the table) to awaken the listener from sleep.

Table 20. pg_listener Columns

NameTypeReferencesDescription
relnamename Notify condition name. (The name need not match any actual relation in the database; the name relname is historical.)
listenerpidint4 PID of the server process that created this entry.
notificationint4  Zero if no event is pending for this listener. If an event is pending, the PID of the server process that sent the notification.

pg_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.

Table 21. pg_namespace Columns

NameTypeReferencesDescription
nspnamename Name of the namespace
nspownerint4pg_shadow.usesysidOwner of the namespace
nspaclaclitem[] Access privileges

pg_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. Note that there can be multiple operator classes for a given data type/access method combination, thus supporting multiple behaviors.

Table 22. pg_opclass Columns

NameTypeReferencesDescription
opcamidoidpg_am.oidIndex access method operator class is for
opcnamename Name of this operator class
opcnamespaceoidpg_namespace.oidNamespace of this operator class
opcownerint4pg_shadow.usesysidOperator class owner
opcintypeoidpg_type.oidData type that the operator class indexes
opcdefaultbool True if this operator class is the default for opcintype
opckeytypeoidpg_type.oidType of data stored in index, or zero if same as opcintype

The majority of the information defining an operator class is actually not in its pg_opclass row, but in the associated rows in pg_amop and pg_amproc. Those rows are considered to be part of the operator class definition — this is not unlike the way that a relation is defined by a single pg_class row plus associated rows in pg_attribute and other tables.

pg_operator

The catalog pg_operator stores information about operators. See CREATE OPERATOR for details on these operator parameters.

Table 23. pg_operator Columns

NameTypeReferencesDescription
oprnamename Name of the operator
oprnamespaceoidpg_namespace.oid The OID of the namespace that contains this operator
oprownerint4pg_shadow.usesysidOwner of the operator
oprkindchar  b = infix ("both"), l = prefix ("left"), r = postfix ("right")
oprcanhashbool This operator supports hash joins
oprleftoidpg_type.oidType of the left operand
oprrightoidpg_type.oidType of the right operand
oprresultoidpg_type.oidType of the result
oprcomoidpg_operator.oidCommutator of this operator, if any
oprnegateoidpg_operator.oidNegator of this operator, if any
oprlsortopoidpg_operator.oid If this operator supports merge joins, the operator that sorts the type of the left-hand operand (L<L)
oprrsortopoidpg_operator.oid If this operator supports merge joins, the operator that sorts the type of the right-hand operand (R<R)
oprltcmpopoidpg_operator.oid If this operator supports merge joins, the less-than operator that compares the left and right operand types (L<R)
oprgtcmpopoidpg_operator.oid If this operator supports merge joins, the greater-than operator that compares the left and right operand types (L>R)
oprcoderegprocpg_proc.oidFunction that implements this operator
oprrestregprocpg_proc.oidRestriction selectivity estimation function for this operator
oprjoinregprocpg_proc.oidJoin selectivity estimation function for this operator

Unused column contain zeroes, for example oprleft is zero for a prefix operator.

pg_proc

The catalog pg_proc stores information about functions (or procedures). The description of CREATE FUNCTION contains more information about the meaning of some columns.

The table contains data for aggregate functions as well as plain functions. If proisagg is true, there should be a matching row in pg_aggregate.

Table 24. pg_proc Columns

NameTypeReferencesDescription
pronamename Name of the function
pronamespaceoidpg_namespace.oid The OID of the namespace that contains this function
proownerint4pg_shadow.usesysidOwner of the function
prolangoidpg_language.oidImplementation language or call interface of this function
proisaggbool Function is an aggregate function
prosecdefbool Function is a security definer (i.e., a "setuid" function)
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)
provolatilechar  provolatile 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 may change at any time. (Use v also for functions with side-effects, so that calls to them cannot get optimized away.)
pronargsint2 Number of arguments
prorettypeoidpg_type.oidData type of the return value
proargtypesoidvectorpg_type.oidAn array with the data types of the function arguments
proargnamestext[]  An array with the names of the function arguments. Arguments without a name are set to empty strings in the array. If none of the arguments have a name, this field may be null.
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.
probinbytea Additional information about how to invoke the function. Again, the interpretation is language-specific.
proaclaclitem[] Access privileges

prosrc contains the function's C-language name (link symbol) for compiled functions, both built-in and dynamically loaded. For all other 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_rewrite

The catalog pg_rewrite stores rewrite rules for tables and views.

Table 25. pg_rewrite Columns

NameTypeReferencesDescription
rulenamename Rule name
ev_classoidpg_class.oidThe table this rule is for
ev_attrint2 The column this rule is for (currently, always zero to indicate the whole table)
ev_typechar  Event type that the rule is for: 1 = SELECT, 2 = UPDATE, 3 = INSERT, 4 = DELETE
is_insteadbool True if the rule is an INSTEAD rule
ev_qualtext  Expression tree (in the form of a nodeToString() representation) for the rule's qualifying condition
ev_actiontext  Query tree (in the form of a nodeToString() representation) for the rule's action

Note: pg_class.relhasrules must be true if a table has any rules in this catalog.

pg_shadow

The catalog pg_shadow contains information about database users. The name stems from the fact that this table should not be readable by the public since it contains passwords. pg_user is a publicly readable view on pg_shadow that blanks out the password field.

Chapter 22 contains detailed information about user and privilege management.

Because user identities are cluster-wide, pg_shadow is shared across all databases of a cluster: there is only one copy of pg_shadow per cluster, not one per database.

Table 26. pg_shadow Columns

NameTypeReferencesDescription
usenamename User name
usesysidint4 User id (arbitrary number used to reference this user)
usecreatedbbool User may create databases
usesuperbool User is a superuser
usecatupdbool  User may update system catalogs. (Even a superuser may not do this unless this column is true.)
passwdtext Password
valuntilabstime Account expiry time (only used for password authentication)
useconfigtext[] Session defaults for run-time configuration variables

pg_statistic

The catalog pg_statistic stores statistical data about the contents of the database. Entries are created by ANALYZE and subsequently used by the query planner. There is one entry for each table column that has been analyzed. Note that all the statistical data is inherently approximate, even assuming that it is up-to-date.

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.

Since different kinds of statistics may 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 may be considered sensitive. (Example: minimum and maximum values of a salary column might be quite interesting.) pg_stats is a publicly readable view on pg_statistic that only exposes information about those tables that are readable by the current user.

Table 27. pg_statistic Columns

NameTypeReferencesDescription
starelidoidpg_class.oidThe table or index that the described column belongs to
staattnumint2pg_attribute.attnumThe number of the described column
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 fraction of the number of rows in the table (for example, a column in which values appear about twice on the average could be represented by stadistinct = -0.5). A zero value means the number of distinct values is unknown.
stakindNint2  A code number indicating the kind of statistics stored in the Nth "slot" of the pg_statistic row.
staopNoidpg_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.
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, so there is no way to define these columns' type more specifically than anyarray.

pg_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.

Table 28. pg_tablespace Columns

NameTypeReferencesDescription
spcnamename Tablespace name
spcownerint4pg_shadow.usesysidOwner of the tablespace, usually the user who created it
spclocationtext Location (directory path) of the tablespace
spcaclaclitem[] Access privileges

pg_trigger

The catalog pg_trigger stores triggers on tables. See under CREATE TRIGGER for more information.

Table 29. pg_trigger Columns

NameTypeReferencesDescription
tgrelidoidpg_class.oidThe table this trigger is on
tgnamename Trigger name (must be unique among triggers of same table)
tgfoidoidpg_proc.oidThe function to be called
tgtypeint2 Bit mask identifying trigger conditions
tgenabledbool True if trigger is enabled (not presently checked everywhere it should be, so disabling a trigger by setting this false does not work reliably)
tgisconstraintbool True if trigger implements a referential integrity constraint
tgconstrnamename Referential integrity constraint name
tgconstrrelidoidpg_class.oidThe table referenced by an referential integrity constraint
tgdeferrablebool True if deferrable
tginitdeferredbool True if initially deferred
tgnargsint2 Number of argument strings passed to trigger function
tgattrint2vector Currently unused
tgargsbytea Argument strings to pass to trigger, each null-terminated

Note: pg_class.reltriggers needs to match up with the entries in this table.

pg_type

The catalog pg_type stores information about data types. Base types (scalar types) are created with CREATE TYPE. 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 and domains with CREATE DOMAIN.

Table 30. pg_type Columns

NameTypeReferencesDescription
typnamename Data type name
typnamespaceoidpg_namespace.oid The OID of the namespace that contains this type
typownerint4pg_shadow.usesysidOwner 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.
typbyvalbool  typbyval 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; this is currently true for type float4, for example.
typtypechar  typtype is b for a base type, c for a composite type (e.g., a table's row type), d for a domain, or p for a pseudo-type. See also typrelid and typbasetype.
typisdefinedbool  True if the type is defined, false if this is a placeholder entry for a not-yet-defined type. When typisdefined is false, nothing except the type name, namespace, and OID can be relied on.
typdelimchar Character that separates two values of this type when parsing array input. Note that the delimiter is associated with the array element data type, not the array data type.
typrelidoidpg_class.oid If this is a composite type (see typtype), then this column points to the pg_class entry that defines the corresponding table. (For a free-standing composite type, the pg_class entry doesn't really represent a table, but it is needed anyway for the type's pg_attribute entries to link to.) Zero for non-composite types.
typelemoidpg_type.oid If typelem is not 0 then it identifies another row in pg_type. The current type can then be subscripted like an array yielding values of type typelem. A "true" array type is variable length (typlen = -1), but some fixed-length (typlen > 0) types also have nonzero typelem, for example name and oidvector. 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.
typinputregprocpg_proc.oidInput conversion function (text format)
typoutputregprocpg_proc.oidOutput conversion function (text format)
typreceiveregprocpg_proc.oidInput conversion function (binary format), or 0 if none
typsendregprocpg_proc.oidOutput conversion function (binary format), or 0 if none
typanalyzeregprocpg_proc.oidCustom ANALYZE function, or 0 to use the standard function
typalignchar 

typalign 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 EnterpriseDB. 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).

Note: For types used in system tables, it is critical that the size and alignment defined in pg_type agree with the way that the compiler will lay out the column in a structure representing a table row.

typstoragechar 

typstorage tells for varlena types (those with typlen = -1) if the type is prepared for toasting and what the default strategy for attributes of this type should be. Possible values are

  • p: Value must always be stored plain.

  • e: Value can be stored in a "secondary" relation (if relation has one, see pg_class.reltoastrelid).

  • m: Value can be stored compressed inline.

  • x: Value can be stored compressed inline or stored in "secondary" storage.

Note that m columns can also be moved out to secondary storage, but only as a last resort (e and x columns are moved first).

typnotnullbool 

typnotnull represents a not-null constraint on a type. Used for domains only.

typbasetypeoidpg_type.oid

If this is a domain (see typtype), then typbasetype identifies the type that this one is based on. Zero if 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.

typndimsint4 

typndims is the number of array dimensions for a domain that is an array (that is, typbasetype is an array type; the domain's typelem will match the base type's typelem). Zero for types other than array domains.

typdefaultbintext 

If typdefaultbin is not null, it is the nodeToString() representation of a default expression for the type. This is only used for domains.

typdefaulttext 

typdefault 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 may be fed to the type's input converter to produce a constant.

System Views

In addition to the system catalogs, EnterpriseDB provides a number of built-in views. The system views provide convenient access to some commonly used queries on the system catalogs. Some of these views provide access to internal server state, as well.

Table 31 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 Table 28-1.

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 EnterpriseDB-specific, it's usually better to use the information schema if it provides all the information you need.

Except where noted, all the views described here are read-only.

Table 31. System Views

View NamePurpose
pg_indexesindexes
pg_lockscurrently held locks
pg_rulesrules
pg_settingsparameter settings
pg_statsplanner statistics
pg_tablestables
pg_userdatabase users
pg_viewsviews

pg_indexes

The view pg_indexes provides access to useful information about each index in the database.

Table 32. pg_indexes Columns

NameTypeReferencesDescription
schemanamenamepg_namespace.nspnamename of schema containing table and index
tablenamenamepg_class.relnamename of table the index is for
indexnamenamepg_class.relnamename of index
tablespacenamepg_tablespace.spcnamename of tablespace containing index (NULL if default for database)
indexdeftext index definition (a reconstructed creation command)

pg_locks

The view pg_locks provides access to information about the locks held by open transactions within the database server. See Chapter 11 for more discussion of locking.

pg_locks contains one row per active lockable object, requested lock mode, and relevant transaction. Thus, the same lockable object may appear many times, if multiple transactions are holding or waiting for locks on it. However, an object that currently has no locks on it will not appear at all. A lockable object is either a relation (e.g., a table) or a transaction ID.

Note that this view includes only table-level locks, not row-level ones. If a transaction is waiting for a row-level lock, it will appear in the view as waiting for the transaction ID of the current holder of that row lock.

Table 33. pg_locks Columns

NameTypeReferencesDescription
relationoidpg_class.oid OID of the locked relation, or NULL if the lockable object is a transaction ID
databaseoidpg_database.oid OID of the database in which the locked relation exists, or zero if the locked relation is a globally-shared table, or NULL if the lockable object is a transaction ID
transactionxid  ID of a transaction, or NULL if the lockable object is a relation
pidinteger process ID of a server process holding or awaiting this lock
modetext name of the lock mode held or desired by this process (see Section 11.3.1)
grantedboolean true if lock is held, false if lock is awaited

granted is true in a row representing a lock held by the indicated session. False indicates that this session is currently waiting to acquire this lock, which implies that some other session is holding a conflicting lock mode on the same lockable object. The waiting session will sleep until the other lock is released (or a deadlock situation is detected). A single session can be waiting to acquire at most one lock at a time.

Every transaction holds an exclusive lock on its transaction ID for its entire duration. If one transaction finds it necessary to wait specifically for another transaction, it does so by attempting to acquire share lock on the other transaction ID. That will succeed only when the other transaction terminates and releases its locks.

When the pg_locks view is accessed, the internal lock manager data structures are momentarily locked, and a copy is made for the view to display. This ensures that the view produces a consistent set of results, while not blocking normal lock manager operations longer than necessary. Nonetheless there could be some impact on database performance if this view is read often.

pg_locks provides a global view of all locks in the database cluster, not only those relevant to the current database. Although its relation column can be joined against pg_class.oid to identify locked relations, this will only work correctly for relations in the current database (those for which the database column is either the current database's OID or zero).

If you have enabled the statistics collector, the pid column can be joined to the procpid column of the pg_stat_activity view to get more information on the session holding or waiting to hold the lock.

pg_rules

The view pg_rules provides access to useful information about query rewrite rules.

Table 34. pg_rules Columns

NameTypeReferencesDescription
schemanamenamepg_namespace.nspnamename of schema containing table
tablenamenamepg_class.relnamename of table the rule is for
rulenamenamepg_rewrite.rulenamename of rule
definitiontext rule definition (a reconstructed creation command)

The pg_rules view excludes the ON SELECT rules of views; those can be seen in pg_views.

pg_settings

The view pg_settings provides access to run-time parameters of the server. It is essentially an alternative interface to the SHOW and SET commands. It also provides access to some facts about each parameter that are not directly available from SHOW, such as minimum and maximum values.

Table 35. pg_settings Columns

NameTypeReferencesDescription
nametext run-time configuration parameter name
settingtext current value of the parameter
categorytext logical group of the parameter
short_desctext a brief description of the parameter
extra_desctext additional, more detailed, information about the parameter
contexttext context required to set the parameter's value
vartypetext parameter type (bool, integer, real, or string)
sourcetext source of the current parameter value
min_valtext minimum allowed value of the parameter (NULL for nonnumeric values)
max_valtext maximum allowed value of the parameter (NULL for nonnumeric values)

The pg_settings view cannot be inserted into or deleted from, but it can be updated. An UPDATE applied to a row of pg_settings is equivalent to executing the SET command on that named parameter. The change only affects the value used by the current session. If an UPDATE is issued within a transaction that is later aborted, the effects of the UPDATE command disappear when the transaction is rolled back. Once the surrounding transaction is committed, the effects will persist until the end of the session, unless overridden by another UPDATE or SET.

pg_stats

The view pg_stats provides access to the information stored in the pg_statistic catalog. This view allows access only to rows of pg_statistic that correspond to tables the user has permission to read, and therefore it is safe to allow public read access to this view.

pg_stats is also designed to present the information in a more readable format than the underlying catalog — at the cost that its schema must be extended whenever new slot types are defined for pg_statistic.

Table 36. pg_stats Columns

NameTypeReferencesDescription
schemanamenamepg_namespace.nspnamename of schema containing table
tablenamenamepg_class.relnamename of table
attnamenamepg_attribute.attnamename of the column described by this row
null_fracreal fraction of column entries that are null
avg_widthinteger average width in bytes of column's entries
n_distinctreal If greater than zero, the estimated number of distinct values in the column. If less than zero, the negative of the number of distinct values divided by the number of rows. (The negated form is used when ANALYZE believes that the number of distinct values is likely to increase as the table grows; the positive form is used when the column seems to have a fixed number of possible values.) For example, -1 indicates a unique column in which the number of distinct values is the same as the number of rows.
most_common_valsanyarray A list of the most common values in the column. (NULL if no values seem to be more common than any others.)
most_common_freqsreal[] A list of the frequencies of the most common values, i.e., number of occurrences of each divided by total number of rows. (NULL when most_common_vals is.)
histogram_boundsanyarray A list of values that divide the column's values into groups of approximately equal population. The values in most_common_vals, if present, are omitted from this histogram calculation. (This column is NULL if the column data type does not have a < operator or if the most_common_vals list accounts for the entire population.)
correlationreal Statistical correlation between physical row ordering and logical ordering of the column values. This ranges from -1 to +1. When the value is near -1 or +1, an index scan on the column will be estimated to be cheaper than when it is near zero, due to reduction of random access to the disk. (This column is NULL if the column data type does not have a < operator.)

The maximum number of entries in the most_common_vals and histogram_bounds arrays can be set on a column-by-column basis using the ALTER TABLE SET STATISTICS command, or globally by setting the default_statistics_target runtime parameter.

pg_tables

The view pg_tables provides access to useful information about each table in the database.

Table 37. pg_tables Columns

NameTypeReferencesDescription
schemanamenamepg_namespace.nspnamename of schema containing table
tablenamenamepg_class.relnamename of table
tableownernamepg_shadow.usenamename of table's owner
tablespacenamepg_tablespace.spcnamename of tablespace containing table (NULL if default for database)
hasindexesbooleanpg_class.relhasindextrue if table has (or recently had) any indexes
hasrulesbooleanpg_class.relhasrulestrue if table has rules
hastriggersbooleanpg_class.reltriggerstrue if table has triggers

pg_user

The view pg_user provides access to information about database users. This is simply a publicly readable view of pg_shadow that blanks out the password field.

Table 38. pg_user Columns

NameTypeReferencesDescription
usenamename User name
usesysidint4 User id (arbitrary number used to reference this user)
usecreatedbbool User may create databases
usesuperbool User is a superuser
usecatupdbool  User may update system catalogs. (Even a superuser may not do this unless this column is true.)
passwdtext Not the password (always reads as ********)
valuntilabstime Account expiry time (only used for password authentication)
useconfigtext[] Session defaults for run-time configuration variables

pg_views

The view pg_views provides access to useful information about each view in the database.

Table 39. pg_views Columns

NameTypeReferencesDescription
schemanamenamepg_namespace.nspnamename of schema containing view
viewnamenamepg_class.relnamename of view
viewownernamepg_shadow.usenamename of view's owner
definitiontext view definition (a reconstructed SELECT query)