2 9.27. System Information Functions and Operators #
4 9.27.1. Session Information Functions
5 9.27.2. Access Privilege Inquiry Functions
6 9.27.3. Schema Visibility Inquiry Functions
7 9.27.4. System Catalog Information Functions
8 9.27.5. Object Information and Addressing Functions
9 9.27.6. Comment Information Functions
10 9.27.7. Data Validity Checking Functions
11 9.27.8. Transaction ID and Snapshot Information Functions
12 9.27.9. Committed Transaction Information Functions
13 9.27.10. Control Data Functions
14 9.27.11. Version Information Functions
15 9.27.12. WAL Summarization Information Functions
17 The functions described in this section are used to obtain various
18 information about a PostgreSQL installation.
20 9.27.1. Session Information Functions #
22 Table 9.71 shows several functions that extract session and system
25 In addition to the functions listed in this section, there are a number
26 of functions related to the statistics system that also provide system
27 information. See Section 27.2.26 for more information.
29 Table 9.71. Session Information Functions
35 current_catalog → name
37 current_database () → name
39 Returns the name of the current database. (Databases are called
40 “catalogs” in the SQL standard, so current_catalog is the standard's
43 current_query () → text
45 Returns the text of the currently executing query, as submitted by the
46 client (which might contain more than one statement).
50 This is equivalent to current_user.
54 current_schema () → name
56 Returns the name of the schema that is first in the search path (or a
57 null value if the search path is empty). This is the schema that will
58 be used for any tables or other named objects that are created without
59 specifying a target schema.
61 current_schemas ( include_implicit boolean ) → name[]
63 Returns an array of the names of all schemas presently in the effective
64 search path, in their priority order. (Items in the current search_path
65 setting that do not correspond to existing, searchable schemas are
66 omitted.) If the Boolean argument is true, then implicitly-searched
67 system schemas such as pg_catalog are included in the result.
71 Returns the user name of the current execution context.
73 inet_client_addr () → inet
75 Returns the IP address of the current client, or NULL if the current
76 connection is via a Unix-domain socket.
78 inet_client_port () → integer
80 Returns the IP port number of the current client, or NULL if the
81 current connection is via a Unix-domain socket.
83 inet_server_addr () → inet
85 Returns the IP address on which the server accepted the current
86 connection, or NULL if the current connection is via a Unix-domain
89 inet_server_port () → integer
91 Returns the IP port number on which the server accepted the current
92 connection, or NULL if the current connection is via a Unix-domain
95 pg_backend_pid () → integer
97 Returns the process ID of the server process attached to the current
100 pg_blocking_pids ( integer ) → integer[]
102 Returns an array of the process ID(s) of the sessions that are blocking
103 the server process with the specified process ID from acquiring a lock,
104 or an empty array if there is no such server process or it is not
107 One server process blocks another if it either holds a lock that
108 conflicts with the blocked process's lock request (hard block), or is
109 waiting for a lock that would conflict with the blocked process's lock
110 request and is ahead of it in the wait queue (soft block). When using
111 parallel queries the result always lists client-visible process IDs
112 (that is, pg_backend_pid results) even if the actual lock is held or
113 awaited by a child worker process. As a result of that, there may be
114 duplicated PIDs in the result. Also note that when a prepared
115 transaction holds a conflicting lock, it will be represented by a zero
118 Frequent calls to this function could have some impact on database
119 performance, because it needs exclusive access to the lock manager's
120 shared state for a short time.
122 pg_conf_load_time () → timestamp with time zone
124 Returns the time when the server configuration files were last loaded.
125 If the current session was alive at the time, this will be the time
126 when the session itself re-read the configuration files (so the reading
127 will vary a little in different sessions). Otherwise it is the time
128 when the postmaster process re-read the configuration files.
130 pg_current_logfile ( [ text ] ) → text
132 Returns the path name of the log file currently in use by the logging
133 collector. The path includes the log_directory directory and the
134 individual log file name. The result is NULL if the logging collector
135 is disabled. When multiple log files exist, each in a different format,
136 pg_current_logfile without an argument returns the path of the file
137 having the first format found in the ordered list: stderr, csvlog,
138 jsonlog. NULL is returned if no log file has any of these formats. To
139 request information about a specific log file format, supply either
140 csvlog, jsonlog or stderr as the value of the optional parameter. The
141 result is NULL if the log format requested is not configured in
142 log_destination. The result reflects the contents of the
143 current_logfiles file.
145 This function is restricted to superusers and roles with privileges of
146 the pg_monitor role by default, but other users can be granted EXECUTE
149 pg_get_loaded_modules () → setof record ( module_name text, version
150 text, file_name text )
152 Returns a list of the loadable modules that are loaded into the current
153 server session. The module_name and version fields are NULL unless the
154 module author supplied values for them using the PG_MODULE_MAGIC_EXT
155 macro. The file_name field gives the file name of the module (shared
158 pg_my_temp_schema () → oid
160 Returns the OID of the current session's temporary schema, or zero if
161 it has none (because it has not created any temporary tables).
163 pg_is_other_temp_schema ( oid ) → boolean
165 Returns true if the given OID is the OID of another session's temporary
166 schema. (This can be useful, for example, to exclude other sessions'
167 temporary tables from a catalog display.)
169 pg_jit_available () → boolean
171 Returns true if a JIT compiler extension is available (see Chapter 30)
172 and the jit configuration parameter is set to on.
174 pg_numa_available () → boolean
176 Returns true if the server has been compiled with NUMA support.
178 pg_listening_channels () → setof text
180 Returns the set of names of asynchronous notification channels that the
181 current session is listening to.
183 pg_notification_queue_usage () → double precision
185 Returns the fraction (0–1) of the asynchronous notification queue's
186 maximum size that is currently occupied by notifications that are
187 waiting to be processed. See LISTEN and NOTIFY for more information.
189 pg_postmaster_start_time () → timestamp with time zone
191 Returns the time when the server started.
193 pg_safe_snapshot_blocking_pids ( integer ) → integer[]
195 Returns an array of the process ID(s) of the sessions that are blocking
196 the server process with the specified process ID from acquiring a safe
197 snapshot, or an empty array if there is no such server process or it is
200 A session running a SERIALIZABLE transaction blocks a SERIALIZABLE READ
201 ONLY DEFERRABLE transaction from acquiring a snapshot until the latter
202 determines that it is safe to avoid taking any predicate locks. See
203 Section 13.2.3 for more information about serializable and deferrable
206 Frequent calls to this function could have some impact on database
207 performance, because it needs access to the predicate lock manager's
208 shared state for a short time.
210 pg_trigger_depth () → integer
212 Returns the current nesting level of PostgreSQL triggers (0 if not
213 called, directly or indirectly, from inside a trigger).
217 Returns the session user's name.
221 Returns the authentication method and the identity (if any) that the
222 user presented during the authentication cycle before they were
223 assigned a database role. It is represented as auth_method:identity or
224 NULL if the user has not been authenticated (for example if Trust
225 authentication has been used).
229 This is equivalent to current_user.
233 current_catalog, current_role, current_schema, current_user,
234 session_user, and user have special syntactic status in SQL: they must
235 be called without trailing parentheses. In PostgreSQL, parentheses can
236 optionally be used with current_schema, but not with the others.
238 The session_user is normally the user who initiated the current
239 database connection; but superusers can change this setting with SET
240 SESSION AUTHORIZATION. The current_user is the user identifier that is
241 applicable for permission checking. Normally it is equal to the session
242 user, but it can be changed with SET ROLE. It also changes during the
243 execution of functions with the attribute SECURITY DEFINER. In Unix
244 parlance, the session user is the “real user” and the current user is
245 the “effective user”. current_role and user are synonyms for
246 current_user. (The SQL standard draws a distinction between
247 current_role and current_user, but PostgreSQL does not, since it
248 unifies users and roles into a single kind of entity.)
250 9.27.2. Access Privilege Inquiry Functions #
252 Table 9.72 lists functions that allow querying object access privileges
253 programmatically. (See Section 5.8 for more information about
254 privileges.) In these functions, the user whose privileges are being
255 inquired about can be specified by name or by OID (pg_authid.oid), or
256 if the name is given as public then the privileges of the PUBLIC
257 pseudo-role are checked. Also, the user argument can be omitted
258 entirely, in which case the current_user is assumed. The object that is
259 being inquired about can be specified either by name or by OID, too.
260 When specifying by name, a schema name can be included if relevant. The
261 access privilege of interest is specified by a text string, which must
262 evaluate to one of the appropriate privilege keywords for the object's
263 type (e.g., SELECT). Optionally, WITH GRANT OPTION can be added to a
264 privilege type to test whether the privilege is held with grant option.
265 Also, multiple privilege types can be listed separated by commas, in
266 which case the result will be true if any of the listed privileges is
267 held. (Case of the privilege string is not significant, and extra
268 whitespace is allowed between but not within privilege names.) Some
270 SELECT has_table_privilege('myschema.mytable', 'select');
271 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION')
274 Table 9.72. Access Privilege Inquiry Functions
280 has_any_column_privilege ( [ user name or oid, ] table text or oid,
281 privilege text ) → boolean
283 Does user have privilege for any column of table? This succeeds either
284 if the privilege is held for the whole table, or if there is a
285 column-level grant of the privilege for at least one column. Allowable
286 privilege types are SELECT, INSERT, UPDATE, and REFERENCES.
288 has_column_privilege ( [ user name or oid, ] table text or oid, column
289 text or smallint, privilege text ) → boolean
291 Does user have privilege for the specified table column? This succeeds
292 either if the privilege is held for the whole table, or if there is a
293 column-level grant of the privilege for the column. The column can be
294 specified by name or by attribute number (pg_attribute.attnum).
295 Allowable privilege types are SELECT, INSERT, UPDATE, and REFERENCES.
297 has_database_privilege ( [ user name or oid, ] database text or oid,
298 privilege text ) → boolean
300 Does user have privilege for database? Allowable privilege types are
301 CREATE, CONNECT, TEMPORARY, and TEMP (which is equivalent to
304 has_foreign_data_wrapper_privilege ( [ user name or oid, ] fdw text or
305 oid, privilege text ) → boolean
307 Does user have privilege for foreign-data wrapper? The only allowable
308 privilege type is USAGE.
310 has_function_privilege ( [ user name or oid, ] function text or oid,
311 privilege text ) → boolean
313 Does user have privilege for function? The only allowable privilege
316 When specifying a function by name rather than by OID, the allowed
317 input is the same as for the regprocedure data type (see Section 8.19).
319 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
321 has_language_privilege ( [ user name or oid, ] language text or oid,
322 privilege text ) → boolean
324 Does user have privilege for language? The only allowable privilege
327 has_largeobject_privilege ( [ user name or oid, ] largeobject oid,
328 privilege text ) → boolean
330 Does user have privilege for large object? Allowable privilege types
331 are SELECT and UPDATE.
333 has_parameter_privilege ( [ user name or oid, ] parameter text,
334 privilege text ) → boolean
336 Does user have privilege for configuration parameter? The parameter
337 name is case-insensitive. Allowable privilege types are SET and ALTER
340 has_schema_privilege ( [ user name or oid, ] schema text or oid,
341 privilege text ) → boolean
343 Does user have privilege for schema? Allowable privilege types are
346 has_sequence_privilege ( [ user name or oid, ] sequence text or oid,
347 privilege text ) → boolean
349 Does user have privilege for sequence? Allowable privilege types are
350 USAGE, SELECT, and UPDATE.
352 has_server_privilege ( [ user name or oid, ] server text or oid,
353 privilege text ) → boolean
355 Does user have privilege for foreign server? The only allowable
356 privilege type is USAGE.
358 has_table_privilege ( [ user name or oid, ] table text or oid,
359 privilege text ) → boolean
361 Does user have privilege for table? Allowable privilege types are
362 SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER, and
365 has_tablespace_privilege ( [ user name or oid, ] tablespace text or
366 oid, privilege text ) → boolean
368 Does user have privilege for tablespace? The only allowable privilege
371 has_type_privilege ( [ user name or oid, ] type text or oid, privilege
374 Does user have privilege for data type? The only allowable privilege
375 type is USAGE. When specifying a type by name rather than by OID, the
376 allowed input is the same as for the regtype data type (see
379 pg_has_role ( [ user name or oid, ] role text or oid, privilege text )
382 Does user have privilege for role? Allowable privilege types are
383 MEMBER, USAGE, and SET. MEMBER denotes direct or indirect membership in
384 the role without regard to what specific privileges may be conferred.
385 USAGE denotes whether the privileges of the role are immediately
386 available without doing SET ROLE, while SET denotes whether it is
387 possible to change to the role using the SET ROLE command. WITH ADMIN
388 OPTION or WITH GRANT OPTION can be added to any of these privilege
389 types to test whether the ADMIN privilege is held (all six spellings
390 test the same thing). This function does not allow the special case of
391 setting user to public, because the PUBLIC pseudo-role can never be a
392 member of real roles.
394 row_security_active ( table text or oid ) → boolean
396 Is row-level security active for the specified table in the context of
397 the current user and current environment?
399 Table 9.73 shows the operators available for the aclitem type, which is
400 the catalog representation of access privileges. See Section 5.8 for
401 information about how to read access privilege values.
403 Table 9.73. aclitem Operators
411 aclitem = aclitem → boolean
413 Are aclitems equal? (Notice that type aclitem lacks the usual set of
414 comparison operators; it has only equality. In turn, aclitem arrays can
415 only be compared for equality.)
417 'calvin=r*w/hobbes'::aclitem = 'calvin=r*w*/hobbes'::aclitem → f
419 aclitem[] @> aclitem → boolean
421 Does array contain the specified privileges? (This is true if there is
422 an array entry that matches the aclitem's grantee and grantor, and has
423 at least the specified set of privileges.)
425 '{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] @>
426 'calvin=r*/hobbes'::aclitem → t
428 aclitem[] ~ aclitem → boolean
430 This is a deprecated alias for @>.
432 '{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] ~
433 'calvin=r*/hobbes'::aclitem → t
435 Table 9.74 shows some additional functions to manage the aclitem type.
437 Table 9.74. aclitem Functions
443 acldefault ( type "char", ownerId oid ) → aclitem[]
445 Constructs an aclitem array holding the default access privileges for
446 an object of type type belonging to the role with OID ownerId. This
447 represents the access privileges that will be assumed when an object's
448 ACL entry is null. (The default access privileges are described in
449 Section 5.8.) The type parameter must be one of 'c' for COLUMN, 'r' for
450 TABLE and table-like objects, 's' for SEQUENCE, 'd' for DATABASE, 'f'
451 for FUNCTION or PROCEDURE, 'l' for LANGUAGE, 'L' for LARGE OBJECT, 'n'
452 for SCHEMA, 'p' for PARAMETER, 't' for TABLESPACE, 'F' for FOREIGN DATA
453 WRAPPER, 'S' for FOREIGN SERVER, or 'T' for TYPE or DOMAIN.
455 aclexplode ( aclitem[] ) → setof record ( grantor oid, grantee oid,
456 privilege_type text, is_grantable boolean )
458 Returns the aclitem array as a set of rows. If the grantee is the
459 pseudo-role PUBLIC, it is represented by zero in the grantee column.
460 Each granted privilege is represented as SELECT, INSERT, etc (see
461 Table 5.1 for a full list). Note that each privilege is broken out as a
462 separate row, so only one keyword appears in the privilege_type column.
464 makeaclitem ( grantee oid, grantor oid, privileges text, is_grantable
467 Constructs an aclitem with the given properties. privileges is a
468 comma-separated list of privilege names such as SELECT, INSERT, etc,
469 all of which are set in the result. (Case of the privilege string is
470 not significant, and extra whitespace is allowed between but not within
473 9.27.3. Schema Visibility Inquiry Functions #
475 Table 9.75 shows functions that determine whether a certain object is
476 visible in the current schema search path. For example, a table is said
477 to be visible if its containing schema is in the search path and no
478 table of the same name appears earlier in the search path. This is
479 equivalent to the statement that the table can be referenced by name
480 without explicit schema qualification. Thus, to list the names of all
482 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
484 For functions and operators, an object in the search path is said to be
485 visible if there is no object of the same name and argument data
486 type(s) earlier in the path. For operator classes and families, both
487 the name and the associated index access method are considered.
489 Table 9.75. Schema Visibility Inquiry Functions
495 pg_collation_is_visible ( collation oid ) → boolean
497 Is collation visible in search path?
499 pg_conversion_is_visible ( conversion oid ) → boolean
501 Is conversion visible in search path?
503 pg_function_is_visible ( function oid ) → boolean
505 Is function visible in search path? (This also works for procedures and
508 pg_opclass_is_visible ( opclass oid ) → boolean
510 Is operator class visible in search path?
512 pg_operator_is_visible ( operator oid ) → boolean
514 Is operator visible in search path?
516 pg_opfamily_is_visible ( opclass oid ) → boolean
518 Is operator family visible in search path?
520 pg_statistics_obj_is_visible ( stat oid ) → boolean
522 Is statistics object visible in search path?
524 pg_table_is_visible ( table oid ) → boolean
526 Is table visible in search path? (This works for all types of
527 relations, including views, materialized views, indexes, sequences and
530 pg_ts_config_is_visible ( config oid ) → boolean
532 Is text search configuration visible in search path?
534 pg_ts_dict_is_visible ( dict oid ) → boolean
536 Is text search dictionary visible in search path?
538 pg_ts_parser_is_visible ( parser oid ) → boolean
540 Is text search parser visible in search path?
542 pg_ts_template_is_visible ( template oid ) → boolean
544 Is text search template visible in search path?
546 pg_type_is_visible ( type oid ) → boolean
548 Is type (or domain) visible in search path?
550 All these functions require object OIDs to identify the object to be
551 checked. If you want to test an object by name, it is convenient to use
552 the OID alias types (regclass, regtype, regprocedure, regoperator,
553 regconfig, or regdictionary), for example:
554 SELECT pg_type_is_visible('myschema.widget'::regtype);
556 Note that it would not make much sense to test a non-schema-qualified
557 type name in this way — if the name can be recognized at all, it must
560 9.27.4. System Catalog Information Functions #
562 Table 9.76 lists functions that extract information from the system
565 Table 9.76. System Catalog Information Functions
571 format_type ( type oid, typemod integer ) → text
573 Returns the SQL name for a data type that is identified by its type OID
574 and possibly a type modifier. Pass NULL for the type modifier if no
575 specific modifier is known.
577 pg_basetype ( regtype ) → regtype
579 Returns the OID of the base type of a domain identified by its type
580 OID. If the argument is the OID of a non-domain type, returns the
581 argument as-is. Returns NULL if the argument is not a valid type OID.
582 If there's a chain of domain dependencies, it will recurse until
583 finding the base type.
585 Assuming CREATE DOMAIN mytext AS text:
587 pg_basetype('mytext'::regtype) → text
589 pg_char_to_encoding ( encoding name ) → integer
591 Converts the supplied encoding name into an integer representing the
592 internal identifier used in some system catalog tables. Returns -1 if
593 an unknown encoding name is provided.
595 pg_encoding_to_char ( encoding integer ) → name
597 Converts the integer used as the internal identifier of an encoding in
598 some system catalog tables into a human-readable string. Returns an
599 empty string if an invalid encoding number is provided.
601 pg_get_catalog_foreign_keys () → setof record ( fktable regclass,
602 fkcols text[], pktable regclass, pkcols text[], is_array boolean,
605 Returns a set of records describing the foreign key relationships that
606 exist within the PostgreSQL system catalogs. The fktable column
607 contains the name of the referencing catalog, and the fkcols column
608 contains the name(s) of the referencing column(s). Similarly, the
609 pktable column contains the name of the referenced catalog, and the
610 pkcols column contains the name(s) of the referenced column(s). If
611 is_array is true, the last referencing column is an array, each of
612 whose elements should match some entry in the referenced catalog. If
613 is_opt is true, the referencing column(s) are allowed to contain zeroes
614 instead of a valid reference.
616 pg_get_constraintdef ( constraint oid [, pretty boolean ] ) → text
618 Reconstructs the creating command for a constraint. (This is a
619 decompiled reconstruction, not the original text of the command.)
621 pg_get_expr ( expr pg_node_tree, relation oid [, pretty boolean ] ) →
624 Decompiles the internal form of an expression stored in the system
625 catalogs, such as the default value for a column. If the expression
626 might contain Vars, specify the OID of the relation they refer to as
627 the second parameter; if no Vars are expected, passing zero is
630 pg_get_functiondef ( func oid ) → text
632 Reconstructs the creating command for a function or procedure. (This is
633 a decompiled reconstruction, not the original text of the command.) The
634 result is a complete CREATE OR REPLACE FUNCTION or CREATE OR REPLACE
637 pg_get_function_arguments ( func oid ) → text
639 Reconstructs the argument list of a function or procedure, in the form
640 it would need to appear in within CREATE FUNCTION (including default
643 pg_get_function_identity_arguments ( func oid ) → text
645 Reconstructs the argument list necessary to identify a function or
646 procedure, in the form it would need to appear in within commands such
647 as ALTER FUNCTION. This form omits default values.
649 pg_get_function_result ( func oid ) → text
651 Reconstructs the RETURNS clause of a function, in the form it would
652 need to appear in within CREATE FUNCTION. Returns NULL for a procedure.
654 pg_get_indexdef ( index oid [, column integer, pretty boolean ] ) →
657 Reconstructs the creating command for an index. (This is a decompiled
658 reconstruction, not the original text of the command.) If column is
659 supplied and is not zero, only the definition of that column is
662 pg_get_keywords () → setof record ( word text, catcode "char",
663 barelabel boolean, catdesc text, baredesc text )
665 Returns a set of records describing the SQL keywords recognized by the
666 server. The word column contains the keyword. The catcode column
667 contains a category code: U for an unreserved keyword, C for a keyword
668 that can be a column name, T for a keyword that can be a type or
669 function name, or R for a fully reserved keyword. The barelabel column
670 contains true if the keyword can be used as a “bare” column label in
671 SELECT lists, or false if it can only be used after AS. The catdesc
672 column contains a possibly-localized string describing the keyword's
673 category. The baredesc column contains a possibly-localized string
674 describing the keyword's column label status.
676 pg_get_partkeydef ( table oid ) → text
678 Reconstructs the definition of a partitioned table's partition key, in
679 the form it would have in the PARTITION BY clause of CREATE TABLE.
680 (This is a decompiled reconstruction, not the original text of the
683 pg_get_ruledef ( rule oid [, pretty boolean ] ) → text
685 Reconstructs the creating command for a rule. (This is a decompiled
686 reconstruction, not the original text of the command.)
688 pg_get_serial_sequence ( table text, column text ) → text
690 Returns the name of the sequence associated with a column, or NULL if
691 no sequence is associated with the column. If the column is an identity
692 column, the associated sequence is the sequence internally created for
693 that column. For columns created using one of the serial types (serial,
694 smallserial, bigserial), it is the sequence created for that serial
695 column definition. In the latter case, the association can be modified
696 or removed with ALTER SEQUENCE OWNED BY. (This function probably should
697 have been called pg_get_owned_sequence; its current name reflects the
698 fact that it has historically been used with serial-type columns.) The
699 first parameter is a table name with optional schema, and the second
700 parameter is a column name. Because the first parameter potentially
701 contains both schema and table names, it is parsed per usual SQL rules,
702 meaning it is lower-cased by default. The second parameter, being just
703 a column name, is treated literally and so has its case preserved. The
704 result is suitably formatted for passing to the sequence functions (see
707 A typical use is in reading the current value of the sequence for an
708 identity or serial column, for example:
709 SELECT currval(pg_get_serial_sequence('sometable', 'id'));
711 pg_get_statisticsobjdef ( statobj oid ) → text
713 Reconstructs the creating command for an extended statistics object.
714 (This is a decompiled reconstruction, not the original text of the
717 pg_get_triggerdef ( trigger oid [, pretty boolean ] ) → text
719 Reconstructs the creating command for a trigger. (This is a decompiled
720 reconstruction, not the original text of the command.)
722 pg_get_userbyid ( role oid ) → name
724 Returns a role's name given its OID.
726 pg_get_viewdef ( view oid [, pretty boolean ] ) → text
728 Reconstructs the underlying SELECT command for a view or materialized
729 view. (This is a decompiled reconstruction, not the original text of
732 pg_get_viewdef ( view oid, wrap_column integer ) → text
734 Reconstructs the underlying SELECT command for a view or materialized
735 view. (This is a decompiled reconstruction, not the original text of
736 the command.) In this form of the function, pretty-printing is always
737 enabled, and long lines are wrapped to try to keep them shorter than
738 the specified number of columns.
740 pg_get_viewdef ( view text [, pretty boolean ] ) → text
742 Reconstructs the underlying SELECT command for a view or materialized
743 view, working from a textual name for the view rather than its OID.
744 (This is deprecated; use the OID variant instead.)
746 pg_index_column_has_property ( index regclass, column integer, property
749 Tests whether an index column has the named property. Common index
750 column properties are listed in Table 9.77. (Note that extension access
751 methods can define additional property names for their indexes.) NULL
752 is returned if the property name is not known or does not apply to the
753 particular object, or if the OID or column number does not identify a
756 pg_index_has_property ( index regclass, property text ) → boolean
758 Tests whether an index has the named property. Common index properties
759 are listed in Table 9.78. (Note that extension access methods can
760 define additional property names for their indexes.) NULL is returned
761 if the property name is not known or does not apply to the particular
762 object, or if the OID does not identify a valid object.
764 pg_indexam_has_property ( am oid, property text ) → boolean
766 Tests whether an index access method has the named property. Access
767 method properties are listed in Table 9.79. NULL is returned if the
768 property name is not known or does not apply to the particular object,
769 or if the OID does not identify a valid object.
771 pg_options_to_table ( options_array text[] ) → setof record (
772 option_name text, option_value text )
774 Returns the set of storage options represented by a value from
775 pg_class.reloptions or pg_attribute.attoptions.
777 pg_settings_get_flags ( guc text ) → text[]
779 Returns an array of the flags associated with the given GUC, or NULL if
780 it does not exist. The result is an empty array if the GUC exists but
781 there are no flags to show. Only the most useful flags listed in
782 Table 9.80 are exposed.
784 pg_tablespace_databases ( tablespace oid ) → setof oid
786 Returns the set of OIDs of databases that have objects stored in the
787 specified tablespace. If this function returns any rows, the tablespace
788 is not empty and cannot be dropped. To identify the specific objects
789 populating the tablespace, you will need to connect to the database(s)
790 identified by pg_tablespace_databases and query their pg_class
793 pg_tablespace_location ( tablespace oid ) → text
795 Returns the file system path that this tablespace is located in.
797 pg_typeof ( "any" ) → regtype
799 Returns the OID of the data type of the value that is passed to it.
800 This can be helpful for troubleshooting or dynamically constructing SQL
801 queries. The function is declared as returning regtype, which is an OID
802 alias type (see Section 8.19); this means that it is the same as an OID
803 for comparison purposes but displays as a type name.
805 pg_typeof(33) → integer
807 COLLATION FOR ( "any" ) → text
809 Returns the name of the collation of the value that is passed to it.
810 The value is quoted and schema-qualified if necessary. If no collation
811 was derived for the argument expression, then NULL is returned. If the
812 argument is not of a collatable data type, then an error is raised.
814 collation for ('foo'::text) → "default"
816 collation for ('foo' COLLATE "de_DE") → "de_DE"
818 to_regclass ( text ) → regclass
820 Translates a textual relation name to its OID. A similar result is
821 obtained by casting the string to type regclass (see Section 8.19);
822 however, this function will return NULL rather than throwing an error
823 if the name is not found.
825 to_regcollation ( text ) → regcollation
827 Translates a textual collation name to its OID. A similar result is
828 obtained by casting the string to type regcollation (see Section 8.19);
829 however, this function will return NULL rather than throwing an error
830 if the name is not found.
832 to_regnamespace ( text ) → regnamespace
834 Translates a textual schema name to its OID. A similar result is
835 obtained by casting the string to type regnamespace (see Section 8.19);
836 however, this function will return NULL rather than throwing an error
837 if the name is not found.
839 to_regoper ( text ) → regoper
841 Translates a textual operator name to its OID. A similar result is
842 obtained by casting the string to type regoper (see Section 8.19);
843 however, this function will return NULL rather than throwing an error
844 if the name is not found or is ambiguous.
846 to_regoperator ( text ) → regoperator
848 Translates a textual operator name (with parameter types) to its OID. A
849 similar result is obtained by casting the string to type regoperator
850 (see Section 8.19); however, this function will return NULL rather than
851 throwing an error if the name is not found.
853 to_regproc ( text ) → regproc
855 Translates a textual function or procedure name to its OID. A similar
856 result is obtained by casting the string to type regproc (see
857 Section 8.19); however, this function will return NULL rather than
858 throwing an error if the name is not found or is ambiguous.
860 to_regprocedure ( text ) → regprocedure
862 Translates a textual function or procedure name (with argument types)
863 to its OID. A similar result is obtained by casting the string to type
864 regprocedure (see Section 8.19); however, this function will return
865 NULL rather than throwing an error if the name is not found.
867 to_regrole ( text ) → regrole
869 Translates a textual role name to its OID. A similar result is obtained
870 by casting the string to type regrole (see Section 8.19); however, this
871 function will return NULL rather than throwing an error if the name is
874 to_regtype ( text ) → regtype
876 Parses a string of text, extracts a potential type name from it, and
877 translates that name into a type OID. A syntax error in the string will
878 result in an error; but if the string is a syntactically valid type
879 name that happens not to be found in the catalogs, the result is NULL.
880 A similar result is obtained by casting the string to type regtype (see
881 Section 8.19), except that that will throw error for name not found.
883 to_regtypemod ( text ) → integer
885 Parses a string of text, extracts a potential type name from it, and
886 translates its type modifier, if any. A syntax error in the string will
887 result in an error; but if the string is a syntactically valid type
888 name that happens not to be found in the catalogs, the result is NULL.
889 The result is -1 if no type modifier is present.
891 to_regtypemod can be combined with to_regtype to produce appropriate
892 inputs for format_type, allowing a string representing a type name to
895 format_type(to_regtype('varchar(32)'), to_regtypemod('varchar(32)')) →
896 character varying(32)
898 Most of the functions that reconstruct (decompile) database objects
899 have an optional pretty flag, which if true causes the result to be
900 “pretty-printed”. Pretty-printing suppresses unnecessary parentheses
901 and adds whitespace for legibility. The pretty-printed format is more
902 readable, but the default format is more likely to be interpreted the
903 same way by future versions of PostgreSQL; so avoid using
904 pretty-printed output for dump purposes. Passing false for the pretty
905 parameter yields the same result as omitting the parameter.
907 Table 9.77. Index Column Properties
909 asc Does the column sort in ascending order on a forward scan?
910 desc Does the column sort in descending order on a forward scan?
911 nulls_first Does the column sort with nulls first on a forward scan?
912 nulls_last Does the column sort with nulls last on a forward scan?
913 orderable Does the column possess any defined sort ordering?
914 distance_orderable Can the column be scanned in order by a “distance”
915 operator, for example ORDER BY col <-> constant ?
916 returnable Can the column value be returned by an index-only scan?
917 search_array Does the column natively support col = ANY(array)
919 search_nulls Does the column support IS NULL and IS NOT NULL searches?
921 Table 9.78. Index Properties
923 clusterable Can the index be used in a CLUSTER command?
924 index_scan Does the index support plain (non-bitmap) scans?
925 bitmap_scan Does the index support bitmap scans?
926 backward_scan Can the scan direction be changed in mid-scan (to support
927 FETCH BACKWARD on a cursor without needing materialization)?
929 Table 9.79. Index Access Method Properties
931 can_order Does the access method support ASC, DESC and related keywords
933 can_unique Does the access method support unique indexes?
934 can_multi_col Does the access method support indexes with multiple
936 can_exclude Does the access method support exclusion constraints?
937 can_include Does the access method support the INCLUDE clause of CREATE
940 Table 9.80. GUC Flags
942 EXPLAIN Parameters with this flag are included in EXPLAIN (SETTINGS)
944 NO_SHOW_ALL Parameters with this flag are excluded from SHOW ALL
946 NO_RESET Parameters with this flag do not support RESET commands.
947 NO_RESET_ALL Parameters with this flag are excluded from RESET ALL
949 NOT_IN_SAMPLE Parameters with this flag are not included in
950 postgresql.conf by default.
951 RUNTIME_COMPUTED Parameters with this flag are runtime-computed ones.
953 9.27.5. Object Information and Addressing Functions #
955 Table 9.81 lists functions related to database object identification
958 Table 9.81. Object Information and Addressing Functions
964 pg_get_acl ( classid oid, objid oid, objsubid integer ) → aclitem[]
966 Returns the ACL for a database object, specified by catalog OID, object
967 OID and sub-object ID. This function returns NULL values for undefined
970 pg_describe_object ( classid oid, objid oid, objsubid integer ) → text
972 Returns a textual description of a database object identified by
973 catalog OID, object OID, and sub-object ID (such as a column number
974 within a table; the sub-object ID is zero when referring to a whole
975 object). This description is intended to be human-readable, and might
976 be translated, depending on server configuration. This is especially
977 useful to determine the identity of an object referenced in the
978 pg_depend catalog. This function returns NULL values for undefined
981 pg_identify_object ( classid oid, objid oid, objsubid integer ) →
982 record ( type text, schema text, name text, identity text )
984 Returns a row containing enough information to uniquely identify the
985 database object specified by catalog OID, object OID and sub-object ID.
986 This information is intended to be machine-readable, and is never
987 translated. type identifies the type of database object; schema is the
988 schema name that the object belongs in, or NULL for object types that
989 do not belong to schemas; name is the name of the object, quoted if
990 necessary, if the name (along with schema name, if pertinent) is
991 sufficient to uniquely identify the object, otherwise NULL; identity is
992 the complete object identity, with the precise format depending on
993 object type, and each name within the format being schema-qualified and
994 quoted as necessary. Undefined objects are identified with NULL values.
996 pg_identify_object_as_address ( classid oid, objid oid, objsubid
997 integer ) → record ( type text, object_names text[], object_args text[]
1000 Returns a row containing enough information to uniquely identify the
1001 database object specified by catalog OID, object OID and sub-object ID.
1002 The returned information is independent of the current server, that is,
1003 it could be used to identify an identically named object in another
1004 server. type identifies the type of database object; object_names and
1005 object_args are text arrays that together form a reference to the
1006 object. These three values can be passed to pg_get_object_address to
1007 obtain the internal address of the object.
1009 pg_get_object_address ( type text, object_names text[], object_args
1010 text[] ) → record ( classid oid, objid oid, objsubid integer )
1012 Returns a row containing enough information to uniquely identify the
1013 database object specified by a type code and object name and argument
1014 arrays. The returned values are the ones that would be used in system
1015 catalogs such as pg_depend; they can be passed to other system
1016 functions such as pg_describe_object or pg_identify_object. classid is
1017 the OID of the system catalog containing the object; objid is the OID
1018 of the object itself, and objsubid is the sub-object ID, or zero if
1019 none. This function is the inverse of pg_identify_object_as_address.
1020 Undefined objects are identified with NULL values.
1022 pg_get_acl is useful for retrieving and inspecting the privileges
1023 associated with database objects without looking at specific catalogs.
1024 For example, to retrieve all the granted privileges on objects in the
1027 (pg_identify_object(s.classid,s.objid,s.objsubid)).*,
1028 pg_catalog.pg_get_acl(s.classid,s.objid,s.objsubid) AS acl
1029 FROM pg_catalog.pg_shdepend AS s
1030 JOIN pg_catalog.pg_database AS d
1031 ON d.datname = current_database() AND
1033 JOIN pg_catalog.pg_authid AS a
1034 ON a.oid = s.refobjid AND
1035 s.refclassid = 'pg_authid'::regclass
1036 WHERE s.deptype = 'a';
1037 -[ RECORD 1 ]-----------------------------------------
1041 identity | public.testtab
1042 acl | {postgres=arwdDxtm/postgres,foo=r/postgres}
1044 9.27.6. Comment Information Functions #
1046 The functions shown in Table 9.82 extract comments previously stored
1047 with the COMMENT command. A null value is returned if no comment could
1048 be found for the specified parameters.
1050 Table 9.82. Comment Information Functions
1056 col_description ( table oid, column integer ) → text
1058 Returns the comment for a table column, which is specified by the OID
1059 of its table and its column number. (obj_description cannot be used for
1060 table columns, since columns do not have OIDs of their own.)
1062 obj_description ( object oid, catalog name ) → text
1064 Returns the comment for a database object specified by its OID and the
1065 name of the containing system catalog. For example,
1066 obj_description(123456, 'pg_class') would retrieve the comment for the
1067 table with OID 123456.
1069 obj_description ( object oid ) → text
1071 Returns the comment for a database object specified by its OID alone.
1072 This is deprecated since there is no guarantee that OIDs are unique
1073 across different system catalogs; therefore, the wrong comment might be
1076 shobj_description ( object oid, catalog name ) → text
1078 Returns the comment for a shared database object specified by its OID
1079 and the name of the containing system catalog. This is just like
1080 obj_description except that it is used for retrieving comments on
1081 shared objects (that is, databases, roles, and tablespaces). Some
1082 system catalogs are global to all databases within each cluster, and
1083 the descriptions for objects in them are stored globally as well.
1085 9.27.7. Data Validity Checking Functions #
1087 The functions shown in Table 9.83 can be helpful for checking validity
1088 of proposed input data.
1090 Table 9.83. Data Validity Checking Functions
1098 pg_input_is_valid ( string text, type text ) → boolean
1100 Tests whether the given string is valid input for the specified data
1101 type, returning true or false.
1103 This function will only work as desired if the data type's input
1104 function has been updated to report invalid input as a “soft” error.
1105 Otherwise, invalid input will abort the transaction, just as if the
1106 string had been cast to the type directly.
1108 pg_input_is_valid('42', 'integer') → t
1110 pg_input_is_valid('42000000000', 'integer') → f
1112 pg_input_is_valid('1234.567', 'numeric(7,4)') → f
1114 pg_input_error_info ( string text, type text ) → record ( message text,
1115 detail text, hint text, sql_error_code text )
1117 Tests whether the given string is valid input for the specified data
1118 type; if not, return the details of the error that would have been
1119 thrown. If the input is valid, the results are NULL. The inputs are the
1120 same as for pg_input_is_valid.
1122 This function will only work as desired if the data type's input
1123 function has been updated to report invalid input as a “soft” error.
1124 Otherwise, invalid input will abort the transaction, just as if the
1125 string had been cast to the type directly.
1127 SELECT * FROM pg_input_error_info('42000000000', 'integer') →
1128 message | detail | hint | sql_erro
1130 ------------------------------------------------------+--------+------+---------
1132 value "42000000000" is out of range for type integer | | | 22003
1134 9.27.8. Transaction ID and Snapshot Information Functions #
1136 The functions shown in Table 9.84 provide server transaction
1137 information in an exportable form. The main use of these functions is
1138 to determine which transactions were committed between two snapshots.
1140 Table 9.84. Transaction ID and Snapshot Information Functions
1146 age ( xid ) → integer
1148 Returns the number of transactions between the supplied transaction id
1149 and the current transaction counter.
1151 mxid_age ( xid ) → integer
1153 Returns the number of multixacts IDs between the supplied multixact ID
1154 and the current multixacts counter.
1156 pg_current_xact_id () → xid8
1158 Returns the current transaction's ID. It will assign a new one if the
1159 current transaction does not have one already (because it has not
1160 performed any database updates); see Section 67.1 for details. If
1161 executed in a subtransaction, this will return the top-level
1162 transaction ID; see Section 67.3 for details.
1164 pg_current_xact_id_if_assigned () → xid8
1166 Returns the current transaction's ID, or NULL if no ID is assigned yet.
1167 (It's best to use this variant if the transaction might otherwise be
1168 read-only, to avoid unnecessary consumption of an XID.) If executed in
1169 a subtransaction, this will return the top-level transaction ID.
1171 pg_xact_status ( xid8 ) → text
1173 Reports the commit status of a recent transaction. The result is one of
1174 in progress, committed, or aborted, provided that the transaction is
1175 recent enough that the system retains the commit status of that
1176 transaction. If it is old enough that no references to the transaction
1177 survive in the system and the commit status information has been
1178 discarded, the result is NULL. Applications might use this function,
1179 for example, to determine whether their transaction committed or
1180 aborted after the application and database server become disconnected
1181 while a COMMIT is in progress. Note that prepared transactions are
1182 reported as in progress; applications must check pg_prepared_xacts if
1183 they need to determine whether a transaction ID belongs to a prepared
1186 pg_current_snapshot () → pg_snapshot
1188 Returns a current snapshot, a data structure showing which transaction
1189 IDs are now in-progress. Only top-level transaction IDs are included in
1190 the snapshot; subtransaction IDs are not shown; see Section 67.3 for
1193 pg_snapshot_xip ( pg_snapshot ) → setof xid8
1195 Returns the set of in-progress transaction IDs contained in a snapshot.
1197 pg_snapshot_xmax ( pg_snapshot ) → xid8
1199 Returns the xmax of a snapshot.
1201 pg_snapshot_xmin ( pg_snapshot ) → xid8
1203 Returns the xmin of a snapshot.
1205 pg_visible_in_snapshot ( xid8, pg_snapshot ) → boolean
1207 Is the given transaction ID visible according to this snapshot (that
1208 is, was it completed before the snapshot was taken)? Note that this
1209 function will not give the correct answer for a subtransaction ID
1210 (subxid); see Section 67.3 for details.
1212 pg_get_multixact_members ( multixid xid ) → setof record ( xid xid,
1215 Returns the transaction ID and lock mode for each member of the
1216 specified multixact ID. The lock modes forupd, fornokeyupd, sh, and
1217 keysh correspond to the row-level locks FOR UPDATE, FOR NO KEY UPDATE,
1218 FOR SHARE, and FOR KEY SHARE, respectively, as described in
1219 Section 13.3.2. Two additional modes are specific to multixacts:
1220 nokeyupd, used by updates that do not modify key columns, and upd, used
1221 by updates or deletes that modify key columns.
1223 The internal transaction ID type xid is 32 bits wide and wraps around
1224 every 4 billion transactions. However, the functions shown in
1225 Table 9.84, except age, mxid_age, and pg_get_multixact_members, use a
1226 64-bit type xid8 that does not wrap around during the life of an
1227 installation and can be converted to xid by casting if required; see
1228 Section 67.1 for details. The data type pg_snapshot stores information
1229 about transaction ID visibility at a particular moment in time. Its
1230 components are described in Table 9.85. pg_snapshot's textual
1231 representation is xmin:xmax:xip_list. For example 10:20:10,14,15 means
1232 xmin=10, xmax=20, xip_list=10, 14, 15.
1234 Table 9.85. Snapshot Components
1236 xmin Lowest transaction ID that was still active. All transaction IDs
1237 less than xmin are either committed and visible, or rolled back and
1239 xmax One past the highest completed transaction ID. All transaction IDs
1240 greater than or equal to xmax had not yet completed as of the time of
1241 the snapshot, and thus are invisible.
1242 xip_list Transactions in progress at the time of the snapshot. A
1243 transaction ID that is xmin <= X < xmax and not in this list was
1244 already completed at the time of the snapshot, and thus is either
1245 visible or dead according to its commit status. This list does not
1246 include the transaction IDs of subtransactions (subxids).
1248 In releases of PostgreSQL before 13 there was no xid8 type, so variants
1249 of these functions were provided that used bigint to represent a 64-bit
1250 XID, with a correspondingly distinct snapshot data type txid_snapshot.
1251 These older functions have txid in their names. They are still
1252 supported for backward compatibility, but may be removed from a future
1253 release. See Table 9.86.
1255 Table 9.86. Deprecated Transaction ID and Snapshot Information
1262 txid_current () → bigint
1264 See pg_current_xact_id().
1266 txid_current_if_assigned () → bigint
1268 See pg_current_xact_id_if_assigned().
1270 txid_current_snapshot () → txid_snapshot
1272 See pg_current_snapshot().
1274 txid_snapshot_xip ( txid_snapshot ) → setof bigint
1276 See pg_snapshot_xip().
1278 txid_snapshot_xmax ( txid_snapshot ) → bigint
1280 See pg_snapshot_xmax().
1282 txid_snapshot_xmin ( txid_snapshot ) → bigint
1284 See pg_snapshot_xmin().
1286 txid_visible_in_snapshot ( bigint, txid_snapshot ) → boolean
1288 See pg_visible_in_snapshot().
1290 txid_status ( bigint ) → text
1292 See pg_xact_status().
1294 9.27.9. Committed Transaction Information Functions #
1296 The functions shown in Table 9.87 provide information about when past
1297 transactions were committed. They only provide useful data when the
1298 track_commit_timestamp configuration option is enabled, and only for
1299 transactions that were committed after it was enabled. Commit timestamp
1300 information is routinely removed during vacuum.
1302 Table 9.87. Committed Transaction Information Functions
1308 pg_xact_commit_timestamp ( xid ) → timestamp with time zone
1310 Returns the commit timestamp of a transaction.
1312 pg_xact_commit_timestamp_origin ( xid ) → record ( timestamp timestamp
1313 with time zone, roident oid)
1315 Returns the commit timestamp and replication origin of a transaction.
1317 pg_last_committed_xact () → record ( xid xid, timestamp timestamp with
1318 time zone, roident oid )
1320 Returns the transaction ID, commit timestamp and replication origin of
1321 the latest committed transaction.
1323 9.27.10. Control Data Functions #
1325 The functions shown in Table 9.88 print information initialized during
1326 initdb, such as the catalog version. They also show information about
1327 write-ahead logging and checkpoint processing. This information is
1328 cluster-wide, not specific to any one database. These functions provide
1329 most of the same information, from the same source, as the
1330 pg_controldata application.
1332 Table 9.88. Control Data Functions
1338 pg_control_checkpoint () → record
1340 Returns information about current checkpoint state, as shown in
1343 pg_control_system () → record
1345 Returns information about current control file state, as shown in
1348 pg_control_init () → record
1350 Returns information about cluster initialization state, as shown in
1353 pg_control_recovery () → record
1355 Returns information about recovery state, as shown in Table 9.92.
1357 Table 9.89. pg_control_checkpoint Output Columns
1358 Column Name Data Type
1359 checkpoint_lsn pg_lsn
1363 prev_timeline_id integer
1364 full_page_writes boolean
1367 next_multixact_id xid
1368 next_multi_offset xid
1371 oldest_active_xid xid
1372 oldest_multi_xid xid
1373 oldest_multi_dbid oid
1374 oldest_commit_ts_xid xid
1375 newest_commit_ts_xid xid
1376 checkpoint_time timestamp with time zone
1378 Table 9.90. pg_control_system Output Columns
1379 Column Name Data Type
1380 pg_control_version integer
1381 catalog_version_no integer
1382 system_identifier bigint
1383 pg_control_last_modified timestamp with time zone
1385 Table 9.91. pg_control_init Output Columns
1386 Column Name Data Type
1387 max_data_alignment integer
1388 database_block_size integer
1389 blocks_per_segment integer
1390 wal_block_size integer
1391 bytes_per_wal_segment integer
1392 max_identifier_length integer
1393 max_index_columns integer
1394 max_toast_chunk_size integer
1395 large_object_chunk_size integer
1396 float8_pass_by_value boolean
1397 data_page_checksum_version integer
1398 default_char_signedness boolean
1400 Table 9.92. pg_control_recovery Output Columns
1401 Column Name Data Type
1402 min_recovery_end_lsn pg_lsn
1403 min_recovery_end_timeline integer
1404 backup_start_lsn pg_lsn
1405 backup_end_lsn pg_lsn
1406 end_of_backup_record_required boolean
1408 9.27.11. Version Information Functions #
1410 The functions shown in Table 9.93 print version information.
1412 Table 9.93. Version Information Functions
1420 Returns a string describing the PostgreSQL server's version. You can
1421 also get this information from server_version, or for a
1422 machine-readable version use server_version_num. Software developers
1423 should use server_version_num (available since 8.2) or PQserverVersion
1424 instead of parsing the text version.
1426 unicode_version () → text
1428 Returns a string representing the version of Unicode used by
1431 icu_unicode_version () → text
1433 Returns a string representing the version of Unicode used by ICU, if
1434 the server was built with ICU support; otherwise returns NULL
1436 9.27.12. WAL Summarization Information Functions #
1438 The functions shown in Table 9.94 print information about the status of
1439 WAL summarization. See summarize_wal.
1441 Table 9.94. WAL Summarization Information Functions
1447 pg_available_wal_summaries () → setof record ( tli bigint, start_lsn
1448 pg_lsn, end_lsn pg_lsn )
1450 Returns information about the WAL summary files present in the data
1451 directory, under pg_wal/summaries. One row will be returned per WAL
1452 summary file. Each file summarizes WAL on the indicated TLI within the
1453 indicated LSN range. This function might be useful to determine whether
1454 enough WAL summaries are present on the server to take an incremental
1455 backup based on some prior backup whose start LSN is known.
1457 pg_wal_summary_contents ( tli bigint, start_lsn pg_lsn, end_lsn pg_lsn
1458 ) → setof record ( relfilenode oid, reltablespace oid, reldatabase oid,
1459 relforknumber smallint, relblocknumber bigint, is_limit_block boolean )
1461 Returns one information about the contents of a single WAL summary file
1462 identified by TLI and starting and ending LSNs. Each row with
1463 is_limit_block false indicates that the block identified by the
1464 remaining output columns was modified by at least one WAL record within
1465 the range of records summarized by this file. Each row with
1466 is_limit_block true indicates either that (a) the relation fork was
1467 truncated to the length given by relblocknumber within the relevant
1468 range of WAL records or (b) that the relation fork was created or
1469 dropped within the relevant range of WAL records; in such cases,
1470 relblocknumber will be zero.
1472 pg_get_wal_summarizer_state () → record ( summarized_tli bigint,
1473 summarized_lsn pg_lsn, pending_lsn pg_lsn, summarizer_pid int )
1475 Returns information about the progress of the WAL summarizer. If the
1476 WAL summarizer has never run since the instance was started, then
1477 summarized_tli and summarized_lsn will be 0 and 0/0 respectively;
1478 otherwise, they will be the TLI and ending LSN of the last WAL summary
1479 file written to disk. If the WAL summarizer is currently running,
1480 pending_lsn will be the ending LSN of the last record that it has
1481 consumed, which must always be greater than or equal to summarized_lsn;
1482 if the WAL summarizer is not running, it will be equal to
1483 summarized_lsn. summarizer_pid is the PID of the WAL summarizer
1484 process, if it is running, and otherwise NULL.
1486 As a special exception, the WAL summarizer will refuse to generate WAL
1487 summary files if run on WAL generated under wal_level=minimal, since
1488 such summaries would be unsafe to use as the basis for an incremental
1489 backup. In this case, the fields above will continue to advance as if
1490 summaries were being generated, but nothing will be written to disk.
1491 Once the summarizer reaches WAL generated while wal_level was set to
1492 replica or higher, it will resume writing summaries to disk.