System Catalogs The system catalogs are the place where a relational database management system stores schema metadata, such as information about tables and columns, and internal bookkeeping information. PostgreSQL's system catalogs are regular tables. You can drop and recreate the tables, add columns, insert and update values, and severely mess up your system that way. Normally, one should not change the system catalogs by hand, there are always SQL commands to do that. (For example, CREATE DATABASE inserts a row into the pg_database catalog — and actually creates the database on disk.) There are some exceptions for particularly esoteric operations, such as adding index access methods. Overview lists the system catalogs. More detailed documentation of each catalog follows below. Most system catalogs are copied from the template database during database creation and are thereafter database-specific. A few catalogs are physically shared across all databases in a cluster; these are noted in the descriptions of the individual catalogs. System Catalogs Catalog Name Purpose pg_aggregate aggregate functions pg_am index access methods pg_amop access method operators pg_amproc access method support procedures pg_attrdef column default values pg_attribute table columns (attributes) pg_authid authorization identifiers (roles) pg_auth_members authorization identifier membership relationships pg_autovacuum per-relation autovacuum configuration parameters pg_cast casts (data type conversions) pg_class tables, indexes, sequences, views (relations) pg_constraint check constraints, unique constraints, primary key constraints, foreign key constraints pg_conversion encoding conversion information pg_database databases within this database cluster pg_depend dependencies between database objects pg_description descriptions or comments on database objects pg_index additional index information pg_inherits table inheritance hierarchy pg_language languages for writing functions pg_largeobject large objects pg_listener asynchronous notification support pg_namespace schemas pg_opclass index access method operator classes pg_operator operators pg_pltemplate template data for procedural languages pg_proc functions and procedures pg_rewrite query rewrite rules pg_shdepend dependencies on shared objects pg_shdescription comments on shared objects pg_statistic planner statistics pg_tablespace tablespaces within this database cluster pg_trigger triggers pg_type data types
<structname>pg_aggregate</structname> 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. <structname>pg_aggregate</> Columns Name Type References Description aggfnoid regproc pg_proc.oid pg_proc OID of the aggregate function aggtransfn regproc pg_proc.oid Transition function aggfinalfn regproc pg_proc.oid Final function (zero if none) aggsortop oid pg_operator.oid Associated sort operator (zero if none) aggtranstype oid pg_type.oid Data type of the aggregate function's internal transition (state) data agginitval text 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
New aggregate functions are registered with the command. See for more information about writing aggregate functions and the meaning of the transition functions, etc.
<structname>pg_am</structname> 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. The contents of this catalog are discussed in detail in . <structname>pg_am</> Columns Name Type References Description amname name Name of the access method amstrategies int2 Number of operator strategies for this access method amsupport int2 Number of support routines for this access method amorderstrategy int2 Zero if the index offers no sort order, otherwise the strategy number of the strategy operator that describes the sort order amcanunique bool Does the access method support unique indexes? amcanmulticol bool Does the access method support multicolumn indexes? amoptionalkey bool Does the access method support a scan without any constraint for the first index column? amindexnulls bool Does the access method support null index entries? amstorage bool Can index storage data type differ from column data type? amclusterable bool Can an index of this type be clustered on? aminsert regproc pg_proc.oid Insert this tuple function ambeginscan regproc pg_proc.oid Start new scan function amgettuple regproc pg_proc.oid Next valid tuple function amgetmulti regproc pg_proc.oid Fetch multiple tuples function amrescan regproc pg_proc.oid Restart this scan function amendscan regproc pg_proc.oid End this scan function ammarkpos regproc pg_proc.oid Mark current scan position function amrestrpos regproc pg_proc.oid Restore marked scan position function ambuild regproc pg_proc.oid Build new index function ambulkdelete regproc pg_proc.oid Bulk-delete function amvacuumcleanup regproc pg_proc.oid Post-VACUUM cleanup function amcostestimate regproc pg_proc.oid Function to estimate cost of an index scan amoptions regproc pg_proc.oid Function to parse and validate reloptions for an index
<structname>pg_amop</structname> 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. <structname>pg_amop</> Columns Name Type References Description amopclaid oid pg_opclass.oid The index operator class this entry is for amopsubtype oid pg_type.oid Subtype to distinguish multiple entries for one strategy; zero for default amopstrategy int2 Operator strategy number amopreqcheck bool Index hit must be rechecked amopopr oid pg_operator.oid OID of the operator
<structname>pg_amproc</structname> 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. <structname>pg_amproc</structname> Columns Name Type References Description amopclaid oid pg_opclass.oid The index operator class this entry is for amprocsubtype oid pg_type.oid Subtype, if cross-type routine, else zero amprocnum int2 Support procedure number amproc regproc pg_proc.oid OID of the procedure
<structname>pg_attrdef</structname> 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. <structname>pg_attrdef</> Columns Name Type References Description adrelid oid pg_class.oid The table this column belongs to adnum int2 pg_attribute.attnum The number of the column adbin text The internal representation of the column default value adsrc text A human-readable representation of the default value
The adsrc field is historical, and is best not used, because it does not track outside changes that might affect the representation of the default value. Reverse-compiling the adbin field (with pg_get_expr for example) is a better way to display the default value.
<structname>pg_attribute</structname> 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 indeed all objects that have pg_class entries.) The term attribute is equivalent to column and is used for historical reasons. <structname>pg_attribute</> Columns Name Type References Description attrelid oid pg_class.oid The table this column belongs to attname name The column name atttypid oid pg_type.oid The data type of this column attstattarget int4 attstattarget 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 attlen int2 A copy of pg_type.typlen of this column's type attnum int2 The number of the column. Ordinary columns are numbered from 1 up. System columns, such as oid, have (arbitrary) negative numbers attndims int4 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) attcacheoff int4 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 atttypmod int4 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 attbyval bool A copy of pg_type.typbyval of this column's type attstorage char 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 attalign char A copy of pg_type.typalign of this column's type attnotnull bool This represents a not-null constraint. It is possible to change this column to enable or disable the constraint atthasdef bool 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 attisdropped bool 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 attislocal bool This column is defined locally in the relation. Note that a column may be locally defined and inherited simultaneously attinhcount int4 The number of direct ancestors this column has. A column with a nonzero number of ancestors cannot be dropped nor renamed
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.
<structname>pg_authid</structname> pg_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) may 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. <structname>pg_authid</> Columns Name Type Description rolname name Role name rolsuper bool Role has superuser privileges rolinherit bool Role automatically inherits privileges of roles it is a member of rolcreaterole bool Role may create more roles rolcreatedb bool Role may create databases rolcatupdate bool Role may update system catalogs directly. (Even a superuser may not do this unless this column is true) rolcanlogin bool Role may log in. That is, this role can be given as the initial session authorization identifier rolconnlimit int4 For roles that can log in, this sets maximum number of concurrent connections this role can make. -1 means no limit rolpassword text Password (possibly encrypted); NULL if none rolvaliduntil timestamptz Password expiry time (only used for password authentication); NULL if no expiration rolconfig text[] Session defaults for run-time configuration variables
<structname>pg_auth_members</structname> pg_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. <structname>pg_auth_members</> Columns Name Type References Description roleid oid pg_authid.oid ID of a role that has a member member oid pg_authid.oid ID of a role that is a member of roleid grantor oid pg_authid.oid ID of the role that granted this membership admin_option bool True if member may grant membership in roleid to others
<structname>pg_autovacuum</structname> pg_autovacuum autovacuum table-specific configuration The catalog pg_autovacuum stores optional per-relation configuration parameters for the autovacuum daemon. If there is an entry here for a particular relation, the given parameters will be used for autovacuuming that table. If no entry is present, the system-wide defaults will be used. For more information about the autovacuum daemon, see . It is likely that pg_autovacuum will disappear in a future release, with the information instead being kept in pg_class.reloptions entries. <structname>pg_autovacuum</> Columns Name Type References Description vacrelid oid pg_class.oid The table this entry is for enabled bool If false, this table will not be autovacuumed, except to prevent transaction ID wraparound vac_base_thresh integer Minimum number of modified tuples before vacuum vac_scale_factor float4 Multiplier for reltuples to add to vac_base_thresh anl_base_thresh integer Minimum number of modified tuples before analyze anl_scale_factor float4 Multiplier for reltuples to add to anl_base_thresh vac_cost_delay integer Custom vacuum_cost_delay parameter vac_cost_limit integer Custom vacuum_cost_limit parameter freeze_min_age integer Custom vacuum_freeze_min_age parameter freeze_max_age integer Custom autovacuum_freeze_max_age parameter
The autovacuum daemon will initiate a VACUUM operation on a particular table when the number of updated or deleted tuples exceeds vac_base_thresh plus vac_scale_factor times the number of live tuples currently estimated to be in the relation. Similarly, it will initiate an ANALYZE operation when the number of inserted, updated or deleted tuples exceeds anl_base_thresh plus anl_scale_factor times the number of live tuples currently estimated to be in the relation. Also, the autovacuum daemon will perform a VACUUM operation to prevent transaction ID wraparound if the table's pg_class.relfrozenxid field attains an age of more than freeze_max_age transactions, whether the table has been changed or not, even if pg_autovacuum.enabled is set to false for it. The system will launch autovacuum to perform such VACUUMs even if autovacuum is otherwise disabled. See for more about wraparound prevention. Any of the numerical fields can contain -1 (or indeed any negative value) to indicate that the system-wide default should be used for this particular value. Observe that the vac_cost_delay variable inherits its default value from the configuration parameter, or from if the former is set to a negative value. The same applies to vac_cost_limit. Also, autovacuum will ignore attempts to set a per-table freeze_max_age larger than the system-wide setting (it can only be set smaller), and the freeze_min_age value will be limited to half the system-wide setting. Note that while you can set freeze_max_age very small, or even zero, this is usually unwise since it will force frequent vacuuming.
<structname>pg_cast</structname> pg_cast The catalog pg_cast stores data type conversion paths, both built-in paths and those defined with . <structfield>pg_cast</> Columns Name Type References Description castsource oid pg_type.oid OID of the source data type casttarget oid pg_type.oid OID of the target data type castfunc oid pg_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) castcontext char 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 data types and a second to apply the modifier.
<structname>pg_class</structname> 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 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. <structname>pg_class</> Columns Name Type References Description relname name Name of the table, index, view, etc. relnamespace oid pg_namespace.oid The OID of the namespace that contains this relation reltype oid 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) relowner oid pg_authid.oid Owner of the relation relam oid pg_am.oid If this is an index, the access method used (B-tree, hash, etc.) relfilenode oid Name of the on-disk file of this relation; 0 if none reltablespace oid 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.) relpages int4 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 reltuples float4 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 reltoastrelid oid 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 reltoastidxid oid pg_class.oid For a TOAST table, the OID of its index. 0 if not a TOAST table relhasindex bool 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 relisshared bool True if this table is shared across all databases in the cluster. Only certain system catalogs (such as pg_database) are shared relkind char r = ordinary table, i = index, S = sequence, v = view, c = composite type, t = TOAST table relnatts int2 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 relchecks int2 Number of check constraints on the table; see pg_constraint catalog reltriggers int2 Number of triggers on the table; see pg_trigger catalog relukeys int2 Unused (not the number of unique keys) relfkeys int2 Unused (not the number of foreign keys on the table) relrefs int2 Unused relhasoids bool True if we generate an OID for each row of the relation relhaspkey bool True if the table has (or once had) a primary key relhasrules bool True if table has rules; see pg_rewrite catalog relhassubclass bool True if table has (or once had) any inheritance children relfrozenxid xid All transaction IDs before this one have been replaced with a permanent (frozen) transaction ID in this table. This is used to track whether the table needs to be vacuumed in order to prevent transaction ID wraparound or to allow pg_clog to be shrunk. Zero (InvalidTransactionId) if the relation is not a table relacl aclitem[] Access privileges; see and for details reloptions text[] Access-method-specific options, as keyword=value strings
<structname>pg_constraint</structname> 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. <structname>pg_constraint</> Columns Name Type References Description conname name Constraint name (not necessarily unique!) connamespace oid pg_namespace.oid The OID of the namespace that contains this constraint contype char c = check constraint, f = foreign key constraint, p = primary key constraint, u = unique constraint condeferrable bool Is the constraint deferrable? condeferred bool Is the constraint deferred by default? conrelid oid pg_class.oid The table this constraint is on; 0 if not a table constraint contypid oid pg_type.oid The domain this constraint is on; 0 if not a domain constraint confrelid oid pg_class.oid If a foreign key, the referenced table; else 0 confupdtype char Foreign key update action code confdeltype char Foreign key deletion action code confmatchtype char Foreign key match type conkey int2[] pg_attribute.attnum If a table constraint, list of columns which the constraint constrains confkey int2[] pg_attribute.attnum If a foreign key, list of the referenced columns conbin text If a check constraint, an internal representation of the expression consrc text If a check constraint, a human-readable representation of the expression
consrc is not updated when referenced objects change; for example, it won't track renaming of columns. Rather than relying on this field, it's best to use pg_get_constraintdef() to extract the definition of a check constraint. pg_class.relchecks needs to agree with the number of check-constraint entries found in this table for the given relation.
<structname>pg_conversion</structname> pg_conversion The catalog pg_conversion describes the available encoding conversion procedures. See for more information. <structname>pg_conversion</> Columns Name Type References Description conname name Conversion name (unique within a namespace) connamespace oid pg_namespace.oid The OID of the namespace that contains this conversion conowner oid pg_authid.oid Owner of the conversion conforencoding int4 Source encoding ID contoencoding int4 Destination encoding ID conproc regproc pg_proc.oid Conversion procedure condefault bool True if this is the default conversion
<structname>pg_database</structname> pg_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. <structname>pg_database</> Columns Name Type References Description datname name Database name datdba oid pg_authid.oid Owner of the database, usually the user who created it encoding int4 Character encoding for this database (pg_encoding_to_char() can translate this number to the encoding name) datistemplate bool 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 datallowconn bool If false then no one can connect to this database. This is used to protect the template0 database from being altered datconnlimit int4 Sets maximum number of concurrent connections that can be made to this database. -1 means no limit datlastsysoid oid Last system OID in the database; useful particularly to pg_dump datfrozenxid xid All transaction IDs before this one have been replaced with a permanent (frozen) transaction ID in this database. This is used to track whether the database needs to be vacuumed in order to prevent transaction ID wraparound or to allow pg_clog to be shrunk. It is the minimum of the per-table pg_class.relfrozenxid values dattablespace oid 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 datconfig text[] Session defaults for run-time configuration variables datacl aclitem[] Access privileges; see and for details
<structname>pg_depend</structname> 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. See also pg_shdepend, which performs a similar function for dependencies involving objects that are shared across a database cluster. <structname>pg_depend</> Columns Name Type References Description classid oid pg_class.oid The OID of the system catalog the dependent object is in objid oid any OID column The OID of the specific dependent object objsubid int4 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 refclassid oid pg_class.oid The OID of the system catalog the referenced object is in refobjid oid any OID column The OID of the specific referenced object refobjsubid int4 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 deptype char 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.
<structname>pg_description</structname> pg_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. <structname>pg_description</> Columns Name Type References Description objoid oid any OID column The OID of the object this description pertains to classoid oid pg_class.oid The OID of the system catalog this object appears in objsubid int4 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 description text Arbitrary text that serves as the description of this object
<structname>pg_index</structname> pg_index The catalog pg_index contains part of the information about indexes. The rest is mostly in pg_class. <structname>pg_index</> Columns Name Type References Description indexrelid oid pg_class.oid The OID of the pg_class entry for this index indrelid oid pg_class.oid The OID of the pg_class entry for the table this index is for indnatts int2 The number of columns in the index (duplicates pg_class.relnatts) indisunique bool If true, this is a unique index indisprimary bool If true, this index represents the primary key of the table. (indisunique should always be true when this is true.) indisclustered bool If true, the table was last clustered on this index indisvalid bool 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 true either indkey int2vector 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 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. indclass oidvector pg_opclass.oid For each column in the index key this contains the OID of the operator class to use. See pg_opclass for details indexprs text 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 indpred text Expression tree (in nodeToString() representation) for partial index predicate. NULL if not a partial index
<structname>pg_inherits</structname> pg_inherits The catalog pg_inherits records information about table inheritance hierarchies. There is one entry for each direct child table in the database. (Indirect inheritance can be determined by following chains of entries.) <structname>pg_inherits</> Columns Name Type References Description inhrelid oid pg_class.oid The OID of the child table inhparent oid pg_class.oid The OID of the parent table inhseqno int4 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
<structname>pg_language</structname> pg_language The catalog pg_language registers languages in which you can write functions or stored procedures. See and for more information about language handlers. <structname>pg_language</> Columns Name Type References Description lanname name Name of the language lanispl bool 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 in the future lanpltrusted bool 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 may create functions in untrusted languages lanplcallfoid oid 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 lanvalidator oid 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 lanacl aclitem[] Access privileges; see and for details
<structname>pg_largeobject</structname> 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). <structname>pg_largeobject</> Columns Name Type Description loid oid Identifier of the large object that includes this page pageno int4 Page number of this page within its large object (counting from zero) data bytea 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.
<structname>pg_listener</structname> pg_listener The catalog pg_listener supports the and 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. <structname>pg_listener</> Columns Name Type References Description relname name Notify condition name. (The name need not match any actual relation in the database; the name relname is historical.) listenerpid int4 PID of the server process that created this entry notification int4 Zero if no event is pending for this listener. If an event is pending, the PID of the server process that sent the notification
<structname>pg_namespace</structname> 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. <structname>pg_namespace</> Columns Name Type References Description nspname name Name of the namespace nspowner oid pg_authid.oid Owner of the namespace nspacl aclitem[] Access privileges; see and for details
<structname>pg_opclass</structname> 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. Operator classes are described at length in . <structname>pg_opclass</> Columns Name Type References Description opcamid oid pg_am.oid Index access method operator class is for opcname name Name of this operator class opcnamespace oid pg_namespace.oid Namespace of this operator class opcowner oid pg_authid.oid Owner of the operator class opcintype oid pg_type.oid Data type that the operator class indexes opcdefault bool True if this operator class is the default for opcintype opckeytype oid pg_type.oid Type 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.
<structname>pg_operator</structname> pg_operator The catalog pg_operator stores information about operators. See and for more information. <structname>pg_operator</> Columns Name Type References Description oprname name Name of the operator oprnamespace oid pg_namespace.oid The OID of the namespace that contains this operator oprowner oid pg_authid.oid Owner of the operator oprkind char b = infix (both), l = prefix (left), r = postfix (right) oprcanhash bool This operator supports hash joins oprleft oid pg_type.oid Type of the left operand oprright oid pg_type.oid Type of the right operand oprresult oid pg_type.oid Type of the result oprcom oid pg_operator.oid Commutator of this operator, if any oprnegate oid pg_operator.oid Negator of this operator, if any oprlsortop oid pg_operator.oid If this operator supports merge joins, the operator that sorts the type of the left-hand operand (L<L) oprrsortop oid pg_operator.oid If this operator supports merge joins, the operator that sorts the type of the right-hand operand (R<R) oprltcmpop oid pg_operator.oid If this operator supports merge joins, the less-than operator that compares the left and right operand types (L<R) oprgtcmpop oid pg_operator.oid If this operator supports merge joins, the greater-than operator that compares the left and right operand types (L>R) oprcode regproc pg_proc.oid Function that implements this operator oprrest regproc pg_proc.oid Restriction selectivity estimation function for this operator oprjoin regproc pg_proc.oid Join selectivity estimation function for this operator
Unused column contain zeroes. For example, oprleft is zero for a prefix operator.
<structname>pg_pltemplate</structname> pg_pltemplate The catalog pg_pltemplate stores template information for procedural languages. A template for a language allows the language to be created in a particular database by a simple CREATE LANGUAGE command, with no need to specify implementation details. Unlike most system catalogs, pg_pltemplate is shared across all databases of a cluster: there is only one copy of pg_pltemplate per cluster, not one per database. This allows the information to be accessible in each database as it is needed. <structname>pg_pltemplate</> Columns Name Type Description tmplname name Name of the language this template is for tmpltrusted boolean True if language is considered trusted tmplhandler text Name of call handler function tmplvalidator text Name of validator function, or NULL if none tmpllibrary text Path of shared library that implements language tmplacl aclitem[] Access privileges for template (not yet used)
There are not currently any commands that manipulate procedural language templates; to change the built-in information, a superuser must modify the table using ordinary INSERT, DELETE, or UPDATE commands. It is likely that a future release of PostgreSQL will offer commands to change the entries in a cleaner fashion. When implemented, the tmplacl field will provide access control for the template itself (i.e., the right to create a language using it), not for the languages created from the template.
<structname>pg_proc</structname> pg_proc The catalog pg_proc stores information about functions (or procedures). See and for more information. The table contains data for aggregate functions as well as plain functions. If proisagg is true, there should be a matching row in pg_aggregate. <structname>pg_proc</> Columns Name Type References Description proname name Name of the function pronamespace oid pg_namespace.oid The OID of the namespace that contains this function proowner oid pg_authid.oid Owner of the function prolang oid pg_language.oid Implementation language or call interface of this function proisagg bool Function is an aggregate function prosecdef bool Function is a security definer (i.e., a setuid function) proisstrict bool 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 proretset bool Function returns a set (i.e., multiple values of the specified data type) provolatile char 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.) pronargs int2 Number of arguments prorettype oid pg_type.oid Data type of the return value proargtypes oidvector pg_type.oid An array with the data types of the function arguments. This includes only input arguments (including INOUT arguments), and thus represents the call signature of the function proallargtypes oid[] pg_type.oid An array with the data types of the function arguments. This includes all arguments (including OUT and INOUT arguments); however, if all the arguments are IN arguments, this field will be null. Note that subscripting is 1-based, whereas for historical reasons proargtypes is subscripted from 0 proargmodes char[] An array with the modes of the function arguments, encoded as i for IN arguments, o for OUT arguments, b for INOUT arguments. If all the arguments are IN arguments, this field will be null. Note that subscripts correspond to positions of proallargtypes not proargtypes proargnames text[] An array with the names of the function arguments. Arguments without a name are set to empty strings in the array. If none of the arguments have a name, this field will be null. Note that subscripts correspond to positions of proallargtypes not proargtypes prosrc text 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 probin bytea Additional information about how to invoke the function. Again, the interpretation is language-specific proacl aclitem[] Access privileges; see and for details
For compiled functions, both built-in and dynamically loaded, prosrc contains the function's C-language name (link symbol). For all other currently-known language types, prosrc contains the function's source text. probin is unused except for dynamically-loaded C functions, for which it gives the name of the shared library file containing the function.
<structname>pg_rewrite</structname> pg_rewrite The catalog pg_rewrite stores rewrite rules for tables and views. <structname>pg_rewrite</> Columns Name Type References Description rulename name Rule name ev_class oid pg_class.oid The table this rule is for ev_attr int2 The column this rule is for (currently, always zero to indicate the whole table) ev_type char Event type that the rule is for: 1 = SELECT, 2 = UPDATE, 3 = INSERT, 4 = DELETE is_instead bool True if the rule is an INSTEAD rule ev_qual text Expression tree (in the form of a nodeToString() representation) for the rule's qualifying condition ev_action text 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.
<structname>pg_shdepend</structname> pg_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. <structname>pg_shdepend</> Columns Name Type References Description dbid oid pg_database.oid The OID of the database the dependent object is in, or zero for a shared object classid oid pg_class.oid The OID of the system catalog the dependent object is in objid oid any OID column The OID of the specific dependent object refclassid oid pg_class.oid The OID of the system catalog the referenced object is in (must be a shared catalog) refobjid oid any OID column The OID of the specific referenced object deptype char A code defining the specific semantics of this dependency relationship; see text
In all cases, a pg_shdepend entry indicates that the referenced object may not be dropped without also dropping the dependent object. However, there are several subflavors identified by deptype: SHARED_DEPENDENCY_OWNER (o) The referenced object (which must be a role) is the owner of the dependent object. SHARED_DEPENDENCY_ACL (a) The referenced object (which must be a role) is mentioned in the ACL (access control list, i.e., privileges list) of the dependent object. (A SHARED_DEPENDENCY_ACL entry is not made for the owner of the object, since the owner will have a SHARED_DEPENDENCY_OWNER entry anyway.) SHARED_DEPENDENCY_PIN (p) There is no dependent object; this type of entry is a signal that the system itself depends on the referenced object, and so that object must never be deleted. Entries of this type are created only by initdb. The columns for the dependent object contain zeroes. Other dependency flavors may be needed in future. Note in particular that the current definition only supports roles as referenced objects.
<structname>pg_shdescription</structname> pg_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. <structname>pg_shdescription</> Columns Name Type References Description objoid oid any OID column The OID of the object this description pertains to classoid oid pg_class.oid The OID of the system catalog this object appears in description text Arbitrary text that serves as the description of this object
<structname>pg_statistic</structname> 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. <structname>pg_statistic</> Columns Name Type References Description starelid oid pg_class.oid The table or index that the described column belongs to staattnum int2 pg_attribute.attnum The number of the described column stanullfrac float4 The fraction of the column's entries that are null stawidth int4 The average stored width, in bytes, of nonnull entries stadistinct float4 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 stakindN int2 A code number indicating the kind of statistics stored in the Nth slot of the pg_statistic row staopN oid 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 stanumbersN float4[] Numerical statistics of the appropriate kind for the Nth slot, or NULL if the slot kind does not involve numerical values stavaluesN anyarray 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
<structname>pg_tablespace</structname> 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. <structname>pg_tablespace</> Columns Name Type References Description spcname name Tablespace name spcowner oid pg_authid.oid Owner of the tablespace, usually the user who created it spclocation text Location (directory path) of the tablespace spcacl aclitem[] Access privileges; see and for details
<structname>pg_trigger</structname> pg_trigger The catalog pg_trigger stores triggers on tables. See for more information. <structname>pg_trigger</> Columns Name Type References Description tgrelid oid pg_class.oid The table this trigger is on tgname name Trigger name (must be unique among triggers of same table) tgfoid oid pg_proc.oid The function to be called tgtype int2 Bit mask identifying trigger conditions tgenabled bool True if trigger is enabled tgisconstraint bool True if trigger implements a referential integrity constraint tgconstrname name Referential integrity constraint name tgconstrrelid oid pg_class.oid The table referenced by an referential integrity constraint tgdeferrable bool True if deferrable tginitdeferred bool True if initially deferred tgnargs int2 Number of argument strings passed to trigger function tgattr int2vector Currently unused tgargs bytea Argument strings to pass to trigger, each NULL-terminated
pg_class.reltriggers needs to agree with the number of triggers found in this table for the given relation.
<structname>pg_type</structname> pg_type The catalog pg_type stores information about data types. Base 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. <structname>pg_type</> Columns Name Type References Description typname name Data type name typnamespace oid pg_namespace.oid The OID of the namespace that contains this type typowner oid pg_authid.oid Owner of the type typlen int2 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. typbyval bool 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 typtype char 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 typisdefined bool 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 typdelim char 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 typrelid oid 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 typelem oid 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 typinput regproc pg_proc.oid Input conversion function (text format) typoutput regproc pg_proc.oid Output conversion function (text format) typreceive regproc pg_proc.oid Input conversion function (binary format), or 0 if none typsend regproc pg_proc.oid Output conversion function (binary format), or 0 if none typanalyze regproc pg_proc.oid Custom ANALYZE function, or 0 to use the standard function typalign char 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 PostgreSQL. When multiple values are stored consecutively, such as in the representation of a complete row on disk, padding is inserted before a datum of this type so that it begins on the specified boundary. The alignment reference is the beginning of the first datum in the sequence. Possible values are: c = char alignment, i.e., no alignment needed. s = short alignment (2 bytes on most machines). i = int alignment (4 bytes on most machines). d = double alignment (8 bytes on many machines, but by no means all). For types used in system tables, it is critical that the size and alignment defined in pg_type agree with the way that the compiler will lay out the column in a structure representing a table row. typstorage char 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). typnotnull bool typnotnull represents a not-null constraint on a type. Used for domains only typbasetype oid 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 typtypmod int4 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 typndims int4 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 typdefaultbin text If typdefaultbin is not null, it is the nodeToString() representation of a default expression for the type. This is only used for domains typdefault text 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, 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 Views View Name Purpose pg_cursors open cursors pg_group groups of database users pg_indexes indexes pg_locks currently held locks pg_prepared_statements prepared statements pg_prepared_xacts prepared transactions pg_roles database roles pg_rules rules pg_settings parameter settings pg_shadow database users pg_stats planner statistics pg_tables tables pg_timezone_abbrevs time zone abbreviations pg_timezone_names time zone names pg_user database users pg_views views
<structname>pg_cursors</structname> pg_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 may include cursors that have not been explicitly created by the user. <structname>pg_cursors</> Columns Name Type Description name text The name of the cursor statement text The verbatim query string submitted to declare this cursor is_holdable boolean true if the cursor is holdable (that is, it can be accessed after the transaction that declared the cursor has committed); false otherwise is_binary boolean true if the cursor was declared BINARY; false otherwise is_scrollable boolean true if the cursor is scrollable (that is, it allows rows to be retrieved in a nonsequential manner); false otherwise creation_time timestamptz The time at which the cursor was declared
The pg_cursors view is read only.
<structname>pg_group</structname> pg_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. <structname>pg_group</> Columns Name Type References Description groname name pg_authid.rolname Name of the group grosysid oid pg_authid.oid ID of this group grolist oid[] pg_authid.oid An array containing the IDs of the roles in this group
<structname>pg_indexes</structname> pg_indexes The view pg_indexes provides access to useful information about each index in the database. <structname>pg_indexes</> Columns Name Type References Description schemaname name pg_namespace.nspname Name of schema containing table and index tablename name pg_class.relname Name of table the index is for indexname name pg_class.relname Name of index tablespace name pg_tablespace.spcname Name of tablespace containing index (NULL if default for database) indexdef text Index definition (a reconstructed CREATE INDEX command)
<structname>pg_locks</structname> pg_locks The view pg_locks provides access to information about the locks held by open transactions within the database server. See for more discussion of locking. pg_locks contains one row per active lockable object, requested lock mode, and relevant transaction. Thus, the same lockable object may appear many times, if multiple transactions are holding or waiting for locks on it. However, an object that currently has no locks on it will not appear at all. There are several distinct types of lockable objects: whole relations (e.g., tables), individual pages of relations, individual tuples of relations, transaction 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. <structname>pg_locks</> Columns Name Type References Description locktype text type of the lockable object: relation, extend, page, tuple, transactionid, object, userlock, or advisory database oid pg_database.oid OID of the database in which the object exists, or zero if the object is a shared object, or NULL if the object is a transaction ID relation oid pg_class.oid OID of the relation, or NULL if the object is not a relation or part of a relation page integer Page number within the relation, or NULL if the object is not a tuple or relation page tuple smallint Tuple number within the page, or NULL if the object is not a tuple transactionid xid ID of a transaction, or NULL if the object is not a transaction ID classid oid pg_class.oid OID of the system catalog containing the object, or NULL if the object is not a general database object objid oid any OID column OID of the object within its system catalog, or NULL if the object is not a general database object objsubid smallint For a table column, this is the column number (the classid and objid refer to the table itself). For all other object types, this column is zero. NULL if the object is not a general database object transaction xid ID of the transaction that is holding or awaiting this lock pid integer Process ID of the server process holding or awaiting this lock. NULL if the lock is held by a prepared transaction mode text Name of the lock mode held or desired by this process (see ) granted boolean True if lock is held, false if lock is awaited
granted is true in a row representing a lock held by the indicated transaction. False indicates that this transaction is currently waiting to acquire this lock, which implies that some other transaction is holding a conflicting lock mode on the same lockable object. The waiting transaction will sleep until the other lock is released (or a deadlock situation is detected). A single transaction can be waiting to acquire at most one lock at a time. Every transaction holds an exclusive lock on its 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. Although tuples are a lockable type of object, information about row-level locks is stored on disk, not in memory, and therefore row-level locks normally do not appear in this view. If a transaction is waiting for a row-level lock, it will usually appear in the view as waiting for the 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. 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. 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 frequently accessed. 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. Also, if you are using prepared transactions, the transaction 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.)
<structname>pg_prepared_statements</structname> pg_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). <structname>pg_prepared_statements</> Columns Name Type Description name text The identifier of the prepared statement statement text 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_time timestamptz The time at which the prepared statement was created parameter_types regtype[] 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_sql boolean true if the prepared statement was created via the PREPARE SQL statement; false if the statement was prepared via the frontend/backend protocol
The pg_prepared_statements view is read only.
<structname>pg_prepared_xacts</structname> pg_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. <structname>pg_prepared_xacts</> Columns Name Type References Description transaction xid Numeric transaction identifier of the prepared transaction gid text Global transaction identifier that was assigned to the transaction prepared timestamp with time zone Time at which the transaction was prepared for commit owner name pg_authid.rolname Name of the user that executed the transaction database name 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.
<structname>pg_roles</structname> pg_roles The view pg_roles provides access to information about database roles. This is simply a publicly readable view of pg_authid that blanks out the password field. This view explicitly exposes the OID column of the underlying table, since that is needed to do joins to other catalogs. <structname>pg_roles</> Columns Name Type References Description rolname name Role name rolsuper bool Role has superuser privileges rolinherit bool Role automatically inherits privileges of roles it is a member of rolcreaterole bool Role may create more roles rolcreatedb bool Role may create databases rolcatupdate bool Role may update system catalogs directly. (Even a superuser may not do this unless this column is true.) rolcanlogin bool Role may log in. That is, this role can be given as the initial session authorization identifier rolconnlimit int4 For roles that can log in, this sets maximum number of concurrent connections this role can make. -1 means no limit rolpassword text Not the password (always reads as ********) rolvaliduntil timestamptz Password expiry time (only used for password authentication); NULL if no expiration rolconfig text[] Session defaults for run-time configuration variables oid oid pg_authid.oid ID of role
<structname>pg_rules</structname> pg_rules The view pg_rules provides access to useful information about query rewrite rules. <structname>pg_rules</> Columns Name Type References Description schemaname name pg_namespace.nspname Name of schema containing table tablename name pg_class.relname Name of table the rule is for rulename name pg_rewrite.rulename Name of rule definition text Rule definition (a reconstructed creation command)
The pg_rules view excludes the ON SELECT rules of views; those can be seen in pg_views.
<structname>pg_settings</structname> pg_settings The view pg_settings provides access to run-time parameters of the server. It is essentially an alternative interface to the SHOW and SET commands. It also provides access to some facts about each parameter that are not directly available from SHOW, such as minimum and maximum values. <structname>pg_settings</> Columns Name Type Description name text Run-time configuration parameter name setting text Current value of the parameter unit text Implicit unit of the parameter category text Logical group of the parameter short_desc text A brief description of the parameter extra_desc text Additional, more detailed, information about the parameter context text Context required to set the parameter's value vartype text Parameter type (bool, integer, real, or string) source text Source of the current parameter value min_val text Minimum allowed value of the parameter (NULL for non-numeric values) max_val text Maximum allowed value of the parameter (NULL for non-numeric values)
The pg_settings view cannot be inserted into or deleted from, but it can be updated. An UPDATE applied to a row of pg_settings is equivalent to executing the command on that named parameter. The change only affects the value used by the current session. If an UPDATE is issued within a transaction that is later aborted, the effects of the UPDATE command disappear when the transaction is rolled back. Once the surrounding transaction is committed, the effects will persist until the end of the session, unless overridden by another UPDATE or SET.
<structname>pg_shadow</structname> pg_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. 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. <structname>pg_shadow</> Columns Name Type References Description usename name pg_authid.rolname User name usesysid oid pg_authid.oid ID of this user usecreatedb bool User may create databases usesuper bool User is a superuser usecatupd bool User may update system catalogs. (Even a superuser may not do this unless this column is true.) passwd text Password (possibly encrypted) valuntil abstime Password expiry time (only used for password authentication) useconfig text[] Session defaults for run-time configuration variables
<structname>pg_stats</structname> pg_stats The view pg_stats provides access to the information stored in the pg_statistic catalog. This view allows access only to rows of pg_statistic that correspond to tables the user has permission to read, and therefore it is safe to allow public read access to this view. pg_stats is also designed to present the information in a more readable format than the underlying catalog — at the cost that its schema must be extended whenever new slot types are defined for pg_statistic. <structname>pg_stats</> Columns Name Type References Description schemaname name pg_namespace.nspname Name of schema containing table tablename name pg_class.relname Name of table attname name pg_attribute.attname Name of the column described by this row null_frac real Fraction of column entries that are null avg_width integer Average width in bytes of column's entries n_distinct real If greater than zero, the estimated number of distinct values in the column. If less than zero, the negative of the number of distinct values divided by the number of rows. (The negated form is used when ANALYZE believes that the number of distinct values is likely to increase as the table grows; the positive form is used when the column seems to have a fixed number of possible values.) For example, -1 indicates a unique column in which the number of distinct values is the same as the number of rows most_common_vals anyarray A list of the most common values in the column. (NULL if no values seem to be more common than any others.) most_common_freqs real[] A list of the frequencies of the most common values, i.e., number of occurrences of each divided by total number of rows. (NULL when most_common_vals is.) histogram_bounds anyarray A list of values that divide the column's values into groups of approximately equal population. The values in most_common_vals, if present, are omitted from this histogram calculation. (This column is NULL if the column data type does not have a < operator or if the most_common_vals list accounts for the entire population.) correlation real Statistical correlation between physical row ordering and logical ordering of the column values. This ranges from -1 to +1. When the value is near -1 or +1, an index scan on the column will be estimated to be cheaper than when it is near zero, due to reduction of random access to the disk. (This column is NULL if the column data type does not have a < operator.)
The maximum number of entries in the most_common_vals and histogram_bounds arrays can be set on a column-by-column basis using the ALTER TABLE SET STATISTICS command, or globally by setting the run-time parameter.
<structname>pg_tables</structname> pg_tables The view pg_tables provides access to useful information about each table in the database. <structname>pg_tables</> Columns Name Type References Description schemaname name pg_namespace.nspname Name of schema containing table tablename name pg_class.relname Name of table tableowner name pg_authid.rolname Name of table's owner tablespace name pg_tablespace.spcname Name of tablespace containing table (NULL if default for database) hasindexes boolean pg_class.relhasindex true if table has (or recently had) any indexes hasrules boolean pg_class.relhasrules true if table has rules hastriggers boolean pg_class.reltriggers true if table has triggers
<structname>pg_timezone_abbrevs</structname> pg_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. <structname>pg_timezone_abbrevs</> Columns Name Type Description abbrev text Time zone abbreviation utc_offset interval Offset from UTC (positive means east of Greenwich) is_dst boolean True if this is a daylight-savings abbreviation
<structname>pg_timezone_names</structname> pg_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. 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. <structname>pg_timezone_names</> Columns Name Type Description name text Time zone name abbrev text Time zone abbreviation utc_offset interval Offset from UTC (positive means east of Greenwich) is_dst boolean True if currently observing daylight savings
<structname>pg_user</structname> pg_user The view pg_user provides access to information about database users. This is simply a publicly readable view of pg_shadow that blanks out the password field. <structname>pg_user</> Columns Name Type Description usename name User name usesysid int4 User ID (arbitrary number used to reference this user) usecreatedb bool User may create databases usesuper bool User is a superuser usecatupd bool User may update system catalogs. (Even a superuser may not do this unless this column is true.) passwd text Not the password (always reads as ********) valuntil abstime Password expiry time (only used for password authentication) useconfig text[] Session defaults for run-time configuration variables
<structname>pg_views</structname> pg_views The view pg_views provides access to useful information about each view in the database. <structname>pg_views</> Columns Name Type References Description schemaname name pg_namespace.nspname Name of schema containing view viewname name pg_class.relname Name of view viewowner name pg_authid.rolname Name of view's owner definition text View definition (a reconstructed SELECT query)