System Catalogs
Overview 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 never has to 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 esoteric operations, such as adding index access methods. 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, fields) pg_class tables, indexes, sequences (relations) pg_database databases pg_description descriptions or comments on database objects pg_group user groups pg_index additional index information pg_inheritproc (not used) pg_inherits table inheritance hierarchy pg_ipl (not used) pg_language languages for writing functions pg_largeobject large objects pg_listener asynchronous notification pg_opclass index access method operator classes pg_operator operators pg_proc functions and procedures pg_relcheck check constraints pg_rewrite query rewriter rules pg_shadow database users pg_statistic optimizer statistics pg_trigger triggers pg_type data types
More detailed documentation of most catalogs follow below. The catalogs that relate to index access methods are explained in the Programmer's Guide. Some catalogs don't have any documentation, yet.
pg_aggregate 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 the row that matches a query condition) and returns a single value computed from all these values. Typical aggregate functions are sum, count, and max. pg_aggregate Columns Name Type References Description aggname name Name of the aggregate function aggowner int4 pg_shadow.usesysid Owner (creator) of the aggregate function aggtransfn regproc (function) Transition function aggfinalfn regproc (function) Final function aggbasetype oid pg_type.oid The type on which this function operates when invoked from SQL aggtranstype oid pg_type.oid The type of the aggregate function's internal transition (state) data aggfinaltype oid pg_type.oid The type of the result agginitval text The initial value of the transition state. This is a text field which will be cast to the type of aggtranstype.
New aggregate functions are registered with the CREATE AGGREGATE command. See the Programmer's Guide for more information about writing aggregate functions and the meaning of the transition functions, etc. An aggregate function is identified through name and argument type. Hence aggname and aggname are the composite primary key.
pg_attrdef This catalog stores column default values. The main information about columns is stored in pg_attribute (see below). Only columns that explicitly specify a default value (when the table is created or the column is added) will have an entry here. pg_attrdef Columns Name Type References Description adrelid oid pg_class.oid The table this column belongs to adnum int2 The number of the column; see pg_attribute.pg_attnum adbin text An internal representation of the column default value adsrc text A human-readable representation of the default value
pg_attribute 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. pg_attribute Columns Name Type References Description attrelid oid pg_class.oid The table this column belongs to attname name Column name atttypid oid pg_type.oid The data type of this column attdispersion float4 attdispersion is the dispersion statistic of the column (0.0 to 1.0), or zero if the statistic has not been calculated, or -1.0 if VACUUM found that the column contains no duplicate entries (in which case the dispersion should be taken as 1.0/numberOfRows for the current table size). The -1.0 hack is useful because the number of rows may be updated more often than attdispersion is. We assume that the column will retain its no-duplicate-entry property. attlen int2 This is a copy of the pg_type.typlen for 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. attnelems int4 Number of dimensions, if the column is an array attcacheoff int4 Always -1 in storage, but when loaded into a tuple descriptor in memory this may be updated cache the offset of the attribute within the tuple. 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 and output functions as the third argument. The value will generally be -1 for types that do not need typmod. attbyval bool A copy of pg_type.typbyval of this column's type attstorage char A copy of pg_type.typstorage of this column's type attisset bool If true, this attribute is a set. In that case, what is really stored in the attribute is the OID of a tuple in the pg_proc catalog. The pg_proc tuple contains the query string that defines this set - i.e., the query to run to get the set. So the atttypid (see above) refers to the type returned by this query, but the actual length of this attribute is the length (size) of an oid. --- At least this is the theory. All this is probably quite broken these days. 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 field 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.
pg_class pg_class catalogues tables and mostly everything else that has columns or is otherwise similar to a table. This includes indexes (but see pg_index), sequences, views, and some kinds of special relation kinds. Below, when we mean all of these kinds of objects we speak of relations. Not all fields are meaningful for all relation types. pg_class Columns Name Type References Description relname name Name of the table, index, view, etc. reltype oid pg_type.oid The data type that corresponds to this table (not functional, only set for system tables) relowner int4 pg_shadow.usesysid Owner of the relation relam oid pg_am.oid If this is an index, the access method used (btree, hash, etc.) relfilenode oid Name of the on-disk file of this relation relpages int4 Size of the on-disk representation of this table in pages (size BLCKSZ). This is only an approximate value which is calculated during vacuum. reltuples int4 Number of tuples in the table. This is only an estimate used by the planner, updated by VACUUM. 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 Oid of the index on the TOAST table for this table, 0 if none relhasindex bool True if this is a table and it has at least one index relisshared bool XXX (This is not what it seems to be.) relkind char 'r' = ordinary table, 'i' = index, 'S' = sequence, 'v' = view, 's' = special, 't' = secondary TOAST table relnatts int2 Number of columns in the relation, besides system columns. 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_relcheck catalog reltriggers int2 Number of triggers on the table; see pg_trigger catalog relukeys int2 unused (Not the number of unique keys or something.) relfkeys int2 Number foreign keys on the table relhaspkey bool unused (No, this does not say whether the table has a primary key. It's really unused.) relhasrules bool Table has rules relhassubclass bool At least one table inherits this one relacl aclitem[] Access permissions. See the descriptions of GRANT and REVOKE for details.
pg_database The pg_database catalog stores information about the available databases. The pg_database table is shared between all databases of a cluster. Databases are created with the CREATE DATABASE. Consult the Administrator's Guide for details about the meaning of some of the parameters. pg_database Columns Name Type References Description datname name Database name datdba int4 pg_shadow.usesysid Owner of the database, initially who created it encoding int4 Character/multibyte encoding for this database datistemplate bool If true then this database can be used in the TEMPLATE clause of CREATE DATABASE to create the 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. datlastsysoid oid Last oid in existence after the database was created; useful particularly to pg_dump datpath text If the database is stored at an alternative location then this records the location. It's either an environment variable name or an absolute path, depending how it was entered.
pg_description The pg_description table can store an optional description or comment for each database object. Descriptions can be manipulated with the COMMENT command. Client applications can view the descriptions by joining with this table. Many builtin system objects have comments associated with them that are shown by psql's \d commands. pg_description Columns Name Type References Description objoid oid any oid attribute The oid of the object this description pertains to description text Arbitrary text that serves as the description of this object.
pg_group This catalog defines groups and stores what users belong to what groups. Groups are created with the CREATE GROUP command. Consult the Administrator's Guide for information about user permission management. pg_group Columns Name Type References Description groname name Name of the group grosysid int4 An arbitrary number to identify this group grolist int4[] pg_shadow.usesysid An array containing the ids of the users in this group
pg_index pg_index contains part of the information about indexes. The rest is mostly in pg_class. 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 indproc oid pg_proc.oid The registered procedure if this is a functional index indkey int2vector pg_attribute.attnum This is an vector (array) of up to INDEX_MAX_KEYS values that indicate which table columns this index pertains to. For example a value of 1 3 would mean that the first and the third column make up the index key. indclass oidvector pg_opclass.oid For each column in the index key this contains a reference to the operator class to use. See pg_opclass for details. indisclustered bool unused indislossy bool ??? indisunique bool If true, this is a unique index. indisprimary bool If true, this index is a unique index that represents the primary key of the table. indreference oid unused indpred text Query plan for partial index predicate (not functional)
pg_inherits This catalog records information about table inheritance hierarchies. pg_inherits Columns Name Type References Description inhrelid oid pg_class.oid This is the reference to the subtable, that is, it records the fact that the identified table is inherited from some other table. inhparent oid pg_class.oid This is the reference to the parent table, from which the table referenced by inhrelid inherited from. inhseqno int4 If there is more than one subtable/parent pair (multiple inheritance), this number tells the order in which the inherited columns are to be arranged. The count starts at 1.
pg_language pg_language registers call interfaces or languages in which you can write functions or stored procedures. See under CREATE LANGUAGE and in the Programmer's Guide for more information about language handlers. pg_language Columns Name Type References Description lanname name Name of the language (to be specified when creating a function) lanispl bool This is false for internal languages (such as SQL) and true for dynamically loaded language handler modules. It essentially means that, if it is true, the language may be dropped. lanpltrusted bool This is a trusted language. See under CREATE LANGUAGE what this means. If this is an internal language (lanispl is false) then this field is meaningless. lanplcallfoid oid pg_proc.oid For non-internal 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. lancompiler text not useful
pg_operator See CREATE OPERATOR and the Programmer's Guide for details on these operator parameters. pg_operator Columns Name Type References Description oprname name Name of the operator oprowner int4 pg_shadow.usesysid Owner (creator) of the operator oprprec int2 unused oprkind char 'b' = infix (both), 'l' = prefix (left), 'r' = postfix (right) oprisleft bool unused 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 oprrsortop oid pg_operator.oid If this operator supports merge joins, the operator that sorts the type of the right-hand operand oprcode regproc Function that implements this operator oprrest regproc Restriction selectivity estimation function for this operator oprjoin regproc Join selectivity estimation function for this operator
pg_proc This catalog stores information about functions (or procedures). The description of CREATE FUNCTION and the Programmer's Guide contain more information about the meaning of some fields. pg_proc Columns Name Type References Description proname name Name of the function proowner int4 pg_shadow.usesysid Owner (creator) of the function prolang oid pg_language.oid Implementation language or call interface of this function proisinh bool unused proistrusted bool not functional proiscachable bool Function returns same result for same input values 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. pronargs int2 Number of arguments proretset bool Function returns a set (probably not functional) prorettype oid pg_type.oid Data type of the return value (0 if the function does not return a value) proargtypes oidvector pg_type.oid A vector with the data types of the function arguments probyte_pct int4 dead code properbyte_pct int4 dead code propercall_pct int4 dead code prooutin_ratio int4 dead code 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 the implementation language/call convention. probin bytea ?
pg_relcheck This system catalog stores CHECK constraints on tables. (Column constraints are not treated specially. Every column constraint is equivalent to some table constraint.) See under CREATE TABLE for more information. pg_relcheck Columns Name Type References Description rcrelid oid pg_class.oid The table this check constraint is on rcname name Constraint name rcbin text An internal representation of the constraint expression rcsrc text A human-readable representation of the consraint expression
pg_class.relchecks needs to match up with the entries in this table.
pg_shadow 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 view on pg_shadow that blanks out the password field. The Administrator's Guide contains detailed information about user and permission management. pg_shadow Columns Name Type References Description usename name User name usesysid int4 User id (arbitrary number used to reference this user) usecreatedb bool User may create databases usetrace bool not used usesuper bool User is a superuser usecatupd bool User may update system catalogs. (Even a superuser may not do this unless this attribute is true.) passwd text Password valuntil abstime Account expiry time (only used for password authentication)
pg_type pg_type Columns Name Type References Description typname name Data type name typowner int4 pg_shadow.usesysid Owner (creator) of the type typlen int2 Length of the storage representation of the type, -1 if variable length typprtlen int2 unused typbyval bool typbyval determines whether internal routines pass a value of this type by value or by reference. Only char, short, and int equivalent items can be passed by value, so if the type is not 1, 2, or 4 bytes long, Postgres does not have the option of passing by value and so typbyval had better be false. 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 basic type and c for a catalog type (i.e., a table). If typtype is c, typrelid is the OID of the type's entry in pg_class. typisdefined bool ??? typdelim char Character that separates two values of this type when parsing array input typrelid oid pg_class.oid If this is a catalog type (see typtype), then this field points to the pg_class entry that defines the corresponding table. A table could theoretically be used as a composite data type, but this is not fully functional. 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 non-zero typelem does not guarantee this type to be a real array type; some ordinary fixed-length types can also be subscripted (e.g., oidvector). Variable-length types can not be turned into pseudo-arrays like that. Hence, the way to determine whether a type is a true array type is typelem != 0 and typlen < 0. typinput regproc Input function typoutput regproc Output function typreceive regproc unused typsend regproc unused 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 Postgres. 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 field in a struct representing a table row. typstorage char typstorage tells for variable-length 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 in secondary. Note that 'm' fields can also be moved out to secondary storage, but only as a last resort ('e' and 'x' fields are moved first). typdefault text ???